Tuesday, November 6, 2018

Harvesting SQL Server optimizer stats detail from Query Plan XML: Part II SQL Server 2016 SP2++

Earlier this year I wrote one of my most popular blog posts to date, with a query to help harvest optimizer stats detail from plan XML when trace flag 8666 is enabled.  In that blog post I hinted it would be more straightforward to harvest this type of information from plan XML after SQL Server 2016 SP2, when the default cardinality estimator includes optimizer stats details in plan XML by default and trace flag 8666 is no longer needed.

That blog post for the legacy CE is here...
Harvesting SQL Server optimizer stats detail from Query Plan XML: Part I Trace Flag 8666
https://sql-sasquatch.blogspot.com/2018/06/harvesting-sql-server-trace-flag-8666.html

Finally got around to typing up the simpler query which can be used after SQL Server 2016 SP2 with the default CE.

Faster, more efficient.  Put the plan_id and plan XML for the desired set into a temp table, and have at it :-)

This allows for lots of fun possibilities - tracking updates to stats vs "good" and "bad" plans according to the query store, tying that information to duration of executions or to CPU time, etc. 


SELECT plan_id, CONVERT(XML, query_plan) planXML
INTO ##plans
FROM sys.query_store_plan;

;with XMLNAMESPACES(default 'http://schemas.microsoft.com/sqlserver/2004/07/showplan')
 SELECT plan_id, dbName, schemaName, tableName, statName, LastUpdate, SamplingPercent
 FROM ##plans
 CROSS APPLY planXML.nodes(N'/ShowPlanXML/BatchSequence/Batch/Statements/StmtSimple/QueryPlan/OptimizerStatsUsage') qp(qpnode)  
 CROSS APPLY qpnode.nodes(N'StatisticsInfo') qp2(statsinfo)
 CROSS APPLY (SELECT qp2.statsinfo.value(N'@LastUpdate', N'varchar(max)')) LastUpdate(LastUpdate) 
 CROSS APPLY (SELECT qp2.statsinfo.value(N'@ModificationCount', N'varchar(max)')) ModCount(ModificationCount)
 CROSS APPLY (SELECT qp2.statsinfo.value(N'@SamplingPercent', N'varchar(max)')) SP(SamplingPercent)
 CROSS APPLY (SELECT qp2.statsinfo.value(N'@Statistics', N'varchar(max)')) statName(statName)
 CROSS APPLY (SELECT qp2.statsinfo.value(N'@Table', N'varchar(max)')) tableName(tableName)
 CROSS APPLY (SELECT qp2.statsinfo.value(N'@Schema', N'varchar(max)')) schemaName(schemaName)
 CROSS APPLY (SELECT qp2.statsinfo.value(N'@Database', N'varchar(max)')) dbName(dbName)
 OPTION (MAXDOP 1);



Let me know if you devise a clever use for this 😀😀😀

Here's one application of this strategy - creating UPDATE STATISTICS... WITH STATS_STREAM statements based on a query plan to make plan investigation portable without moving all data and without a full 'dbcc clonedatabase'...

Fun with SQL Server Query Store, Query Plan 'StatisticsInfo' XML nodes, and STATS_STREAM
https://sql-sasquatch.blogspot.com/2018/12/fun-with-sql-server-query-store-query.html