I’ve always felt responsible for making such a big deal about the differences between estimated and actual plans. I implied in the first edition of the execution plans book (get the new, vastly improved, 3rd edition in digital form for free here, or you can pay for the print version) that these things were so radically different that the estimated plan was useless. This is false. All plans are estimated plans. However, actual plans have some added runtime metrics. It’s not that we’re going to get a completely different execution plan when we look at an actual plan, it’s just going to have those very valuable runtime metrics. The problem with getting those metrics is, you have to execute the query. However, this is no longer true in SQL Server 2019 (CTP 2.4 and greater) thanks to sys.dm_exec_query_plan_stats
Lightweight Statistics
It all starts with a new database scoped configuration LAST_QUERY_PLAN_STATS, or, if you like, you can turn it on at the server level using a trace flag, 2451. I prefer the more granular control, especially because, while we will be adding an extremely lightweight additional load to the server, we’re adding additional load to the server. I’d rather pick and choose which databases it gets applied to in order to minimize that load as much as is reasonable, while still absolutely taking advantage of this new functionality. In my testing (little so far), I didn’t see this affect the server at all, however, being conservative on things like this is generally a good approach:
ALTER DATABASE SCOPED CONFIGURATION SET LAST_QUERY_PLAN_STATS = ON;
sys.dm_exec_query_plan_stats
Once you’ve enabled the collection through the trace flag or the database configuration, you’ll begin to see data collected in the DMV. Querying it can be quite simple. Here I combine it with sys.dm_exec_procedure_stats:
SELECT deqps.query_plan
FROM sys.dm_exec_procedure_stats AS deps
CROSS APPLY sys.dm_exec_query_plan_stats(deps.plan_handle) AS deqps
WHERE deps.object_id = OBJECT_ID('dbo.AddressByCity');
The result set is a single execution plan in XML format (no cast involved, which, possibly means that plans that exceed the XML nesting limit won’t be shown here?) that you can click on:
That, dear friends, is an actual execution plan, the last one run on the system. Because you see the row counts, you know this is an actual plan. I can get this plan, with the runtime metrics, without having to execute the query. That’s pretty huge.
Conclusion
Please let me reiterate. All plans are estimated plans. You can get an estimated plan with runtime metrics. This is what we call an “actual” plan. Just remember that these are the same as estimated plans. However, what makes them so very attractive are the runtime metrics. Now, in SQL Server 2019, we can get these runtime metrics without having to execute a query. That’s a win!
[…] Grant Fritchey shows off an improvement in SQL Server 2019: […]
It is worth noting that executing this statement clears the procedure cache in the current database, which means that all queries have to recompile.
You mean changing the trace flag, not running the DMV.
I mean executing “ALTER DATABASE SCOPED CONFIGURATION SET LAST_QUERY_PLAN_STATS = ON;”
How come your book links are all broken or cause the web page to spin or just refresh?
https://www.simple-talk.com/books/sql-books/sql-server-execution-plans-second-edition-by-grant-fritchey/eBOOK_SQLServerExecutionPlans_2Ed_G_Fritchey.pdf
That’s the old book. They must have finally taken down the link. The new version is here: https://www.red-gate.com/simple-talk/books/sql-server-execution-plans-third-edition-by-grant-fritchey/
[…] that are tied to (but not exactly part of) the plan cache, in the Query Store, and in memory if the LAST_QUERY_PLAN_STATS database scoped configuration is enabled. If the submitter of the query requested the so-called […]
Please also let us know where these ACTUAL last query plan stats are saved . In Plan cache or out of it in memory ? Also please mention will it be visible into Query Store
It’s in a new space in the memory. It’s not in the Query Store.