A few things you need to consider when you use views in SQL Server - Part 1. More joins
View in SQL Server
But in terms of performance, you need to consider several factors.
Preparation
I use StackOverflow database
You can download from here(Thanks to Brent): https://www.brentozar.com/archive/2015/10/how-to-download-the-stack-overflow-database-via-bittorrent/
Creating indexes
1 2 3 4 5 6 7 8 9 10 | USE StackOverflow GO CREATE INDEX IX_Posts_OwnerUserId ON dbo.Posts(OwnerUserId); CREATE INDEX IX_Comments_PostID ON dbo.Comments(PostID); CREATE INDEX IX_Votes_PostID ON dbo.Votes(PostID); CREATE INDEX IX_Comments_UserId ON dbo.Comments(UserId); |
Creating a view
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | USE StackOverflow GO CREATE OR ALTER VIEW dbo.vw_PostInformation AS SELECT p.Id AS PostId, p.Title AS PostTitle, p.AnswerCount AS PostAnswerCount, p.Body AS PostBody , p.ClosedDate AS PostClosedDate, p.CreationDate AS PostCreationDate , p.LastEditDate AS PostLastEditDate, p.ViewCount AS PostViewCount , p.OwnerUserId AS PostOwnerUserId, u.DisplayName AS UserDisplayName, u.CreationDate AS UserCreationDate , c.Id AS CommentID, c.CreationDate AS CommentCreationDate, c.Score AS CommentScore, c.Text AS CommentText , v.BountyAmount AS VoteBountyAmount, v.VoteTypeId, v.CreationDate AS VoteCreationDate FROM dbo.Posts p JOIN dbo.Users u ON p.OwnerUserId = u.Id JOIN dbo.Comments c ON p.Id = c.PostId JOIN dbo.Votes v ON p.Id = v.PostId ; |
1 2 | SELECT * FROM dbo.vw_PostInformation WHERE PostID = 33 |
When you need only a few columns of data?
You may select lots of information using the view.
But if you select only a few columns from a few tables, then it becomes a different story.
For e.g. if you only select data from "Posts" table and "Users" table.
Executions
Queries
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 | -- 01. With view SELECT v.PostId, v.PostBody, v.PostCreationDate, v.UserDisplayName, v.UserCreationDate FROM dbo.vw_PostInformation AS v WHERE PostID = 33 GROUP BY v.PostId, v.PostBody, v.PostCreationDate, v.UserDisplayName, v.UserCreationDate -- 02. Without View SELECT p.Id AS PostId, p.Body AS PostBody, p.CreationDate AS PostCreationDate , u.DisplayName AS UserDisplayName, u.CreationDate AS UserCreationDate FROM dbo.Posts p JOIN dbo.Users u ON p.OwnerUserId = u.Id WHERE P.Id = 33 ; |
Result
Looks like the same.
But, when you use a view, you need to use "GROUP BY" for this case in order to have unique values otherwise you will get lots of duplicate rows.
Execution plan comarison
Let's take a look at the execution plans.
View uses Index seek(Luckily not scans, at least) for "Comments" and "Votes" table which we don't need for this query. Of course, using view is more expensive.
I/O comparison
Now, let's take a look at I/O using "SET STATISTICS IO ON".
Queries
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | SET STATISTICS IO ON; -- 01. With view PRINT '01. With View' SELECT v.PostId, v.PostBody, v.PostCreationDate, v.UserDisplayName, v.UserCreationDate FROM dbo.vw_PostInformation AS v WHERE PostID = 33 GROUP BY v.PostId, v.PostBody, v.PostCreationDate, v.UserDisplayName, v.UserCreationDate -- 02. Without View PRINT '02. Without View' SELECT p.Id AS PostId, p.Body AS PostBody, p.CreationDate AS PostCreationDate , u.DisplayName AS UserDisplayName, u.CreationDate AS UserCreationDate FROM dbo.Posts p JOIN dbo.Users u ON p.OwnerUserId = u.Id WHERE P.Id = 33 ; SET STATISTICS IO OFF; |
Result
01. With View (1 row affected) Table 'Votes'. Scan count 4, logical reads 20, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. Table 'Comments'. Scan count 1, logical reads 3, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. Table 'Users'. Scan count 0, logical reads 3, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. Table 'Posts'. Scan count 0, logical reads 4, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. (1 row affected) 02. Without View (1 row affected) Table 'Users'. Scan count 0, logical reads 3, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. Table 'Posts'. Scan count 0, logical reads 4, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. (1 row affected)
As you can see, it reads from "Votes" and "Comments" tables when using a view even though you didn't use any data from those tables.
Therefore, using a view can read additional pages because of the structure.
If you want to run your own game server, it means you want to see it achieve success.Gaming
ReplyDelete