Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Do views use an optimised execution plan? Expand / Collapse
Author
Message
Posted Tuesday, April 2, 2013 7:58 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, June 11, 2013 3:02 AM
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.
Post #1437901
Posted Tuesday, April 2, 2013 9:03 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 4:58 PM
Points: 42,466, Visits: 35,532
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 2008, MVP
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

Post #1437951
Posted Tuesday, April 2, 2013 9:27 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, June 11, 2013 3:02 AM
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.
Post #1437966
Posted Tuesday, April 2, 2013 9:53 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 4:58 PM
Points: 42,466, Visits: 35,532
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 2008, MVP
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

Post #1437978
Posted Tuesday, April 2, 2013 9:58 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, June 11, 2013 3:02 AM
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.
Post #1437982
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse