SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Do views use an optimised execution plan?


Do views use an optimised execution plan?

Author
Message
invisibleduncan
invisibleduncan
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 13
Do views use an optimised execution plan? I always thought they didn't, and that this was one of the arguments for using them sparingly. However, a colleague has mentioned that he thinks they do use an optimised execution plan, although he thinks they get optimised the first time you run the view, and that you need to have Auto Update Statistics set to ON for the database.

I've tried searching for an answer, but unfortunately if you include "View" in a search about execution plans, all you get are ways of viewing execution plans.

Any knowledge gratefully received. :-)
GilaMonster
GilaMonster
SSC Guru
SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)

Group: General Forum Members
Points: 86844 Visits: 45257
Views don't have stored execution plans, because they're just saved SQL statements and are replaced by their definition early in the parsing phase of a query. They're not executed in their entirety like procedures or functions are.

When you query a view, from inside a procedure or ad-hoc query, the resulting query is optimised and its plan stored depending on the normal rules of caching and reuse.

p.s. All queries use an optimised execution plan, I think you mean 'cached execution plan'

Auto update statistics has no effect whatsoever on how plans are cached in a database.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


invisibleduncan
invisibleduncan
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 13
So although it could be argued that I was correct, any query that uses the view would create a cached execution plan in the same way that it would if it was querying from a table? In other words, my colleague was right in saying that using a query isn't more expensive performance-wise than using the underlying tables directly?

I always like an answer that means we were both right...ish!

Thanks for the help. Satisfied
GilaMonster
GilaMonster
SSC Guru
SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)

Group: General Forum Members
Points: 86844 Visits: 45257
invisibleduncan (4/2/2013)
So although it could be argued that I was correct, any query that uses the view would create a cached execution plan in the same way that it would if it was querying from a table?


Yes, because by the time that the query reaches the optimiser, there's no reference to the view remaining, during the parsing and binding, the names of views will be replaced by their definitions (unless we're talking about indexed views)

For example:

CREATE VIEW SomeView AS
SELECT Col1, Col2 FROM SomeTable WHERE Col3 IS NOT NULL
GO



Now we have a query that uses that view

SELECT Col1, SUM(Col2) FROM SomeView GROUP BY Col1



So during the parsing/binding, the view name is replaced by its definition, resulting in

SELECT Col1, SUM(Col2) FROM (SELECT Col1, Col2 FROM SomeTable WHERE Col3 IS NOT NULL) sv GROUP BY Col1



Which is then simplified and optimised from there and the resulting execution plan cached as per the usual rules for caching queries.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


invisibleduncan
invisibleduncan
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 13
That's brilliant. It makes perfect sense when you put it like that.

Thanks for the extra detail - it's much appreciated. :-)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search