Wednesday, December 5, 2018

Fun with SQL Server Query Store, Query Plan 'StatisticsInfo' XML nodes, and STATS_STREAM

Note: The stored procedure in this post works with SQL Server 2016 SP2++ and on planXML for plans NOT using the Legacy CE.  There will be a future post with a version using trace flag 8666 style planXML, which can be used prior to SQL Server 2016 SP2 or with the Legacy CE.

~~~~~

DBCC CLONEDATABASE is a good thing.

But sometimes its too broadly scoped to be useful, especially between organizations.

What if I need to troubleshoot a single query from (a) known, shared schema(s) when there are 20,000 + statistics and some may contain sensitive data in the range_hi key values?

Below is a tool that can help, provided the system is SQL Server 2016 SP2 or higher, the Query Store is enabled and captured the relevant plan, and the Legacy CE was NOT used to compile the plan.  This stored procedure in that case takes the plan_id and retrieves from the Query Store and SHOW_STATISTICS commands what is needed to generate UPDATE STATISTICS statements including stats_stream, rowcount, and pagecount.

The basic mining of optimizer stats from Query Store for 2016 SP2 ++ can be seen here...

Harvesting SQL Server optimizer stats detail from Query Plan XML: Part II SQL Server 2016 SP2++
https://sql-sasquatch.blogspot.com/2018/11/harvesting-sql-server-optimizer-stats.html


CREATE OR ALTER PROCEDURE sasquatch__xfer_one_plan_stats @plan_id INT
AS
/* stored procedure based on work explained in the following blog post
https://sql-sasquatch.blogspot.com/2018/11/harvesting-sql-server-optimizer-stats.html

supply a plan_id from the Query Store in @plan_id, and if SQL Server version is 2016 SP2 or higher
AND if the Legacy CE was NOT used UPDATE STATISTICS commands for each of the stats used 
to compile the plan will be generated
*/

DECLARE @startdb NVARCHAR(256),
        @db      NVARCHAR(256),
        @schema  NVARCHAR(256),
        @table   NVARCHAR(256),
        @stats   NVARCHAR(256),
        @cmd     NVARCHAR(MAX);
        
SET @startdb = DB_NAME();
DROP TABLE IF EXISTS #plan;
CREATE TABLE #plan(planXML XML);

INSERT INTO #plan
SELECT CONVERT(XML, query_plan) planXML
FROM sys.query_store_plan
WHERE plan_id = @plan_id;

;WITH XMLNAMESPACES(default 'http://schemas.microsoft.com/sqlserver/2004/07/showplan')
 SELECT dbName, schemaName, tableName, statName, CONVERT(VARBINARY(MAX), NULL) [stats_stream],
        CONVERT(BIGINT, NULL) [rowcount], CONVERT(BIGINT, NULL) [pagecount]
 INTO #QO_stats
 FROM #plan
 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'@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);

 CREATE TABLE #one_stat ([stats_stream] VARBINARY(MAX), [rowcount] BIGINT, [pagecount] BIGINT);

 WHILE EXISTS (SELECT TOP 1 1 FROM #QO_stats WHERE [stats_stream] IS NULL)
 BEGIN
      SELECT TOP 1 @db = dbName, @schema = schemaName, @table = tableName, @stats = statName
      FROM #QO_stats
      WHERE [stats_stream] IS NULL
      ORDER BY dbName, schemaName, tableName, statName;

      SET @cmd = N'USE ' + @db + N' DBCC SHOW_STATISTICS(''' + @schema + N'.' + @table + N''', ' + @stats 
            + N') WITH STATS_STREAM, NO_INFOMSGS'

      INSERT INTO #one_stat
      EXEC (@cmd);

      UPDATE #QO_stats
      SET [stats_stream] = os.[stats_stream], [rowcount] = os.[rowcount], [pagecount] = os.[pagecount] 
      FROM #one_stat os
      WHERE @db =   #QO_stats.dbName
      AND @schema = #QO_stats.schemaName
      AND @table =  #QO_stats.tableName 
      AND @stats =  #QO_stats.statName;

      TRUNCATE TABLE #one_stat;

 END

SELECT N'USE ' + qo.dbName + N' UPDATE STATISTICS ' + qo.schemaName + N'.' + qo.tableName + N'(' + qo.statName + N') WITH ' +
CASE WHEN qo.[pagecount] IS NULL THEN '' ELSE N'PAGECOUNT = ' + CONVERT(NVARCHAR(20), qo.[pagecount]) + N', ' END +
CASE WHEN qo.[rowcount] IS NULL THEN '' ELSE N'ROWCOUNT = ' + CONVERT(NVARCHAR(20), qo.[rowcount]) + N', ' END + 
N'STATS_STREAM = ' + CONVERT(NVARCHAR(MAX), qo.[stats_stream], 1) 
FROM #QO_stats qo;

EXEC (N'USE ' + @startDB);

/* 20181205 */

No comments:

Post a Comment