Does generating an Estimated Plan cause that plan to be loaded into the plan cache?
No.
What? Still here? You want more? Proof? Fine. Let’s first run this bit of code (but please, not on your production server):
DBCC FREEPROCCACHE();
That will remove all plans from cache. Now, let’s take this query and generate an Estimated Plan (CTL-L from your keyboard or by clicking on the “Display Estimated Execution Plan” button on the toolbar):
SELECT * FROM Production.ProductModel AS pm;
This will generate a trivial plan showing a scan against the Production.ProductModel table. Now, let’s run another query:
SELECT deqs.plan_handle FROM sys.dm_exec_query_stats AS deqs CROSS APPLY sys.dm_exec_sql_text(deqs.sql_handle) AS dest WHERE dest.text = 'SELECT * FROM Production.ProductModel AS pm;';
That’s just an easy way to see if a plan_handle exists. If a plan was stored in cache for this query, I should see a result. I don’t. Now, you might say that this is because it’s a trivial plan. So, let’s complicate the query a little, add some JOINs and a WHERE clause:
SELECT * FROM Production.Product AS p JOIN Production.ProductModel AS pm ON pm.ProductModelID = p.ProductModelID JOIN Production.ProductInventory AS pi ON pi.ProductID = p.ProductID JOIN Production.Location AS l ON l.LocationID = pi.LocationID WHERE p.ProductID = 750;
Not the most complicated query around, but, it will go through full optimization because it is not a query that will generate a trivial plan. Let’s generate an Estimated Plan again. Now we’ll modify our query against the cache just a little:
SELECT deqs.plan_handle FROM sys.dm_exec_query_stats AS deqs CROSS APPLY sys.dm_exec_sql_text(deqs.sql_handle) AS dest WHERE dest.text = 'SELECT * FROM Production.Product AS p JOIN Production.ProductModel AS pm ON pm.ProductModelID = p.ProductModelID JOIN Production.ProductInventory AS pi ON pi.ProductID = p.ProductID JOIN Production.Location AS l ON l.LocationID = pi.LocationID WHERE p.ProductID = 750;'
You won’t see any rows returned. Now, if I execute the query and then re-run the query against the cache, then I see a plan. How about stored procedures? I have a really simple one I use to teach parameter sniffing:
EXEC dbo.spAddressByCity @City = N'Mentor';
I’ll generate an Estimated Plan and then query the cache using a slightly different approach:
SELECT deps.plan_handle FROM sys.dm_exec_procedure_stats AS deps WHERE deps.object_id = OBJECT_ID('dbo.spAddressByCity');
Again, assuming I’ve cleared the cache and I haven’t executed the procedure, this returns zero rows. That’s because generating an Estimated Plan does not then load that plan into the cache. The plan gets loaded into cache when it gets executed.
I love talking about execution plans and query tuning. If you do too, we two opportunities to get together. The first is in Las Vegas at the Connections conference. Click here to register. If you bring your execution plans to Vegas, I’ll try to make some time during the session to use your plans to demonstrate to the crowd. The second opportunity will be down in San Diego, the day before their SQL Saturday event.
The post Generating Estimated Plan and the Plan Cache appeared first on Home Of The Scary DBA.