From a804769af5752fdbca6ce27904ae90801091880e Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Pablo=20Lozano=20Fern=C3=A1ndez?= Date: Wed, 19 Oct 2022 11:02:05 +0200 Subject: [PATCH] Added subqueris and adhoc for ServerTopQueries Added the possibility to capture subqueries (also ordered by the same measurement used to generate the report), and aggregate all ad hoc queries under a "virtual" object --- .../2-dbo.ServerTopObjectsStore.Table.sql | 10 ++- .../3-dbo.vServerTopObjectsIndex.View.sql | 19 ++++ .../4-dbo.vServerTopObjectsStore.View.sql | 6 +- .../5-dbo.ServerTopObjects.Procedure.sql | 89 ++++++++++++++----- ServerTopObjects/README.md | 22 ++++- .../3-dbo.vServerTopQueriesIndex.View.sql | 10 +++ 6 files changed, 127 insertions(+), 29 deletions(-) diff --git a/ServerTopObjects/2-dbo.ServerTopObjectsStore.Table.sql b/ServerTopObjects/2-dbo.ServerTopObjectsStore.Table.sql index d321c80..46c4cd7 100644 --- a/ServerTopObjects/2-dbo.ServerTopObjectsStore.Table.sql +++ b/ServerTopObjects/2-dbo.ServerTopObjectsStore.Table.sql @@ -10,13 +10,16 @@ -- Name of the databse the information of the following columns has been extracted from -- -- [ObjectID] BIGINT NOT NULL --- Identifier of the object associated to the corresponding [QueryID] (if any) +-- Identifier of the object +-- +-- [ObjectQueryIDs] XML NULL +-- Identifier of the queries part of the object associated to the corresponding [ObjectID] -- -- [SchemaName] SYSNAME NULL --- Name of the schema of the object associated to the corresponding [QueryID] (if any) +-- Name of the schema of the object associated to the corresponding [ObjectID] -- -- [ObjectName] SYSNAME NULL --- Name of the object associated to the corresponding [QueryID] (if any) +-- Name of the object associated to the corresponding [ObjectID] -- -- [ExecutionTypeDesc] NVARCHAR(120) NOT NULL -- Description of the execution type (Regular, Aborted, Exception) @@ -65,6 +68,7 @@ CREATE TABLE [dbo].[ServerTopObjectsStore] [ReportID] BIGINT NOT NULL ,[DatabaseName] SYSNAME NOT NULL ,[ObjectID] BIGINT NOT NULL + ,[ObjectQueryIDs] XML NULL ,[SchemaName] SYSNAME NOT NULL ,[ObjectName] SYSNAME NOT NULL ,[ExecutionTypeDesc] NVARCHAR(120) NOT NULL diff --git a/ServerTopObjects/3-dbo.vServerTopObjectsIndex.View.sql b/ServerTopObjects/3-dbo.vServerTopObjectsIndex.View.sql index d36193a..c77ec98 100644 --- a/ServerTopObjects/3-dbo.vServerTopObjectsIndex.View.sql +++ b/ServerTopObjects/3-dbo.vServerTopObjectsIndex.View.sql @@ -32,10 +32,27 @@ -- Flag to determine whether the values are "percentages" -- When enabled, the [Measurement] values will go from 0 to 100000 (equivalent to 0% to 100%) -- +-- [AggregateAll] BIT NOT NULL +-- Flag to determine whether all query executions are aggregated +-- +-- [AggregateNonRegular] BIT NOT NULL +-- Flag to determine whether all query executions that didn't have a "regular" exit are aggregated together +-- +-- [IncludeAdhocQueryIDs] BIT NOT NULL +-- Flag to determine the Adhoc Queries are considered for the report +-- +-- [IncludeObjectQueryIDs] BIT NOT NULL +-- Flag to determine whether the individual queries of the Object (or the totality of the Adhoc queries) are included in the report +-- -- -- Date: 2022.10.18 -- Auth: Pablo Lozano (@sqlozano) -- Desc: Created based on [dbo].[vServerTopQueriesIndex] +-- +-- Date: 2022.10.19 +-- Auth: Pablo Lozano (@sqlozano) +-- Changes: Added missing description for the columns: [AggregateAll], [AggregateNonRegular] +-- Added columns for new parameters: [IncludeAdhocQueryIDs], [IncludeObjectQueryIDs] ---------------------------------------------------------------------------------- CREATE OR ALTER VIEW [dbo].[vServerTopObjectsIndex] @@ -52,6 +69,8 @@ SELECT ,q.n.value('Percentages[1]', 'BIT') AS [Percentages] ,q.n.value('AggregateAll[1]', 'BIT') AS [AggregateAll] ,q.n.value('AggregateNonRegular[1]','BIT') AS [AggregateNonRegular] + ,q.n.value('IncludeAdhocQueryIDs[1]','BIT') AS [IncludeAdhocQueryIDs] + ,q.n.value('IncludeObjectQueryIDs[1]','BIT') AS [IncludeObjectQueryIDs] FROM [dbo].[ServerTopObjectsIndex] [stoi] CROSS APPLY [stoi].[Parameters].nodes('/Root/ServerTopObjectsParameters') AS q(n) GO \ No newline at end of file diff --git a/ServerTopObjects/4-dbo.vServerTopObjectsStore.View.sql b/ServerTopObjects/4-dbo.vServerTopObjectsStore.View.sql index a8a41f0..b90c0a8 100644 --- a/ServerTopObjects/4-dbo.vServerTopObjectsStore.View.sql +++ b/ServerTopObjects/4-dbo.vServerTopObjectsStore.View.sql @@ -12,11 +12,14 @@ -- [ObjectID] BIGINT NOT NULL -- Identifier of the object -- +-- [ObjectQueryIDs] XML NULL +-- Identifier of the queries part of the object associated to the corresponding [ObjectID] +-- -- [SchemaName] SYSNAME NULL -- Name of the object's schema -- -- [ObjectName] SYSNAME NULL --- Name of the object (if any) +-- Name of the object -- -- [ExecutionTypeDesc] NVARCHAR(120) NOT NULL -- Description of the execution type (Regular, Aborted, Exception) @@ -68,6 +71,7 @@ SELECT ,[stoi].[Percentages] ,[stos].[DatabaseName] ,[stos].[ObjectID] + ,[stos].[ObjectQueryIDs] ,[stos].[SchemaName] ,[stos].[ObjectName] ,[stos].[ExecutionTypeDesc] diff --git a/ServerTopObjects/5-dbo.ServerTopObjects.Procedure.sql b/ServerTopObjects/5-dbo.ServerTopObjects.Procedure.sql index 180325d..7b3d558 100644 --- a/ServerTopObjects/5-dbo.ServerTopObjects.Procedure.sql +++ b/ServerTopObjects/5-dbo.ServerTopObjects.Procedure.sql @@ -52,6 +52,12 @@ -- [Default: 0] -- Only one of @AggregateAll and @AggregateNonRegular are allowed -- +-- @IncludeAdhocQueries BIT -- Flag to include all Adhoc queries aggregated under a single "virtual" object +-- [Default: 0] +-- +-- @IncludeObjectQueryIDs BIT -- Flag to include the QueryID of the subqueries of the object in the report +-- [Default: 1] +-- -- @VerboseMode BIT -- Flag to determine whether the T-SQL commands that compose this report will be returned to the user. -- [Default: 0] -- @@ -64,6 +70,10 @@ -- Date: 2022.10.18 -- Auth: Pablo Lozano (@sqlozano) -- Desc: Based on [dbo].[ServerTopQueries] +-- +-- Date: 2022.10.19 +-- Auth: Pablo Lozano (@sqlozano) +-- Changes: Added new parameters: @IncludeAdhocQueries, @IncludeObjectQueryIDs to include QueryIDs to be returned ---------------------------------------------------------------------------------- CREATE OR ALTER PROCEDURE [dbo].[ServerTopObjects] @@ -79,6 +89,8 @@ CREATE OR ALTER PROCEDURE [dbo].[ServerTopObjects] ,@Percentages BIT = 0 ,@AggregateAll BIT = 1 ,@AggregateNonRegular BIT = 0 + ,@IncludeAdhocQueries BIT = 0 + ,@IncludeObjectQueryIDs BIT = 0 ,@VerboseMode BIT = 0 ,@TestMode BIT = 0 ,@ReportID BIGINT = NULL OUTPUT @@ -151,6 +163,19 @@ END IF (@Percentages IS NULL) SET @Percentages = 0 + + +IF (@AggregateAll IS NULL) + SET @AggregateAll = 1 + +IF (@AggregateNonRegular IS NULL) + SET @AggregateNonRegular = 0 + +IF (@IncludeAdhocQueries IS NULL) + SET @IncludeAdhocQueries = 0 + +IF (@IncludeObjectQueryIDs IS NULL) + SET @IncludeObjectQueryIDs = 0 -- Check variables and set defaults - END @@ -196,6 +221,7 @@ CREATE TABLE #ServerTopObjectsStore ( [DatabaseName] SYSNAME NOT NULL ,[ObjectID] BIGINT NOT NULL + ,[ObjectQueries] XML NULL ,[SchemaName] SYSNAME NULL ,[ObjectName] SYSNAME NULL ,[ExecutionTypeDesc] NVARCHAR(120) NOT NULL @@ -220,8 +246,8 @@ SET @SqlCommand2PopulateTempTableTemplate = 'USE [{@DatabaseName}] SELECT [qsq].[query_id] ,[object_id] = ISNULL([obs].[object_id], 0) -,[SchemaName] = ISNULL(SCHEMA_NAME([obs].[schema_id]), '''') -,[ProcedureName] = ISNULL(OBJECT_NAME([obs].[object_id]), '''') +,[SchemaName] = ISNULL(SCHEMA_NAME([obs].[schema_id]), ''ADHOC'') +,[ProcedureName] = ISNULL(OBJECT_NAME([obs].[object_id]), ''ADHOC'') ,CASE WHEN {@AggregateAll} = 1 THEN ''ALL'' WHEN {@AggregateNonRegular} = 1 AND [qsrs].[execution_type_desc] != ''Regular'' THEN ''NonRegular'' @@ -243,7 +269,7 @@ INNER JOIN [{@DatabaseName}].[sys].[query_store_plan] [qsp] ON [qsrs].[plan_id] = [qsp].[plan_id] INNER JOIN [{@DatabaseName}].[sys].[query_store_query] [qsq] ON [qsp].[query_id] = [qsq].[query_id] -INNER JOIN [{@DatabaseName}].[sys].[objects] [obs] +{@IncludeAdhocQueries} JOIN [{@DatabaseName}].[sys].[objects] [obs] ON [qsq].[object_id] = [obs].[object_id] WHERE ( @@ -283,6 +309,7 @@ SELECT {@Top} ''{@DatabaseName}'' ,[st2].[object_id] +,{@IncludeObjectQueryIDs}(SELECT [st1].[query_id] FROM [st1] WHERE [st1].[object_id] = [st2].[object_id] {@Order} FOR XML PATH(''ObjectQueryIDs'')) AS XML ,[st2].[SchemaName] ,[st2].[ProcedureName] ,[st2].[ExecutionTypeDesc] @@ -321,6 +348,20 @@ FROM [st2] SET @SqlCommand2PopulateTempTableTemplate = REPLACE(@SqlCommand2PopulateTempTableTemplate, '{@AggregateNonRegular}', CAST(@AggregateNonRegular AS NVARCHAR(1))) -- Based on @AggregateNonRegular, aggregate all executions based on Regular / NonRegular in the analysis - END + -- Based on @IncludeAdhocQueries, return adhoc query IDs under a "virtual" Object - START + IF (@IncludeAdhocQueries = 0) + SET @SqlCommand2PopulateTempTableTemplate = REPLACE(@SqlCommand2PopulateTempTableTemplate, '{@IncludeAdhocQueries}', 'INNER') + IF (@IncludeAdhocQueries = 1) + SET @SqlCommand2PopulateTempTableTemplate = REPLACE(@SqlCommand2PopulateTempTableTemplate, '{@IncludeAdhocQueries}', 'LEFT') + -- Based on @IncludeAdhocQueries, return adhoc query IDs under a "virtual" Object - END + + -- Based on @IncludeObjectQueryIDs, return the query IDs part of the Object captured - START + IF (@IncludeObjectQueryIDs = 0) + SET @SqlCommand2PopulateTempTableTemplate = REPLACE(@SqlCommand2PopulateTempTableTemplate, '{@IncludeObjectQueryIDs}', 'NULL --') + IF (@IncludeObjectQueryIDs = 1) + SET @SqlCommand2PopulateTempTableTemplate = REPLACE(@SqlCommand2PopulateTempTableTemplate, '{@IncludeObjectQueryIDs}', '') + -- Based on @IncludeObjectQueryIDs, return the query IDs part of the Object captured - END + -- Based on @Top, return only the @Top queries or all - START IF (@Top > 0) BEGIN @@ -518,7 +559,8 @@ BEGIN DECLARE @SqlCmd2User NVARCHAR(MAX) SET @SqlCmd2User = 'SELECT [DatabaseName] - ,[ObjectID] + ,[ObjectID] + ,[ObjectQueries] ,[SchemaName] ,[ObjectName] ,[ExecutionTypeDesc] @@ -571,26 +613,30 @@ BEGIN ''{@DatabaseName}'', ( SELECT - ''{@StartTime}'' AS [StartTime], - ''{@EndTime}'' AS [EndTime], - {@Top} AS [Top], - ''{@Measurement}'' AS [Measurement], - {@Percentages} AS [Percentages], - {@AggregateAll} AS [AggregateAll], - {@AggregateNonRegular} AS [AggregateNonRegular] + ''{@StartTime}'' AS [StartTime], + ''{@EndTime}'' AS [EndTime], + {@Top} AS [Top], + ''{@Measurement}'' AS [Measurement], + {@Percentages} AS [Percentages], + {@AggregateAll} AS [AggregateAll], + {@AggregateNonRegular} AS [AggregateNonRegular], + {@IncludeAdhocQueries} AS [IncludeAdhocQueries], + {@IncludeObjectQueryIDs} AS [IncludeObjectQueryIDs] FOR XML PATH(''ServerTopObjectsParameters''), ROOT(''Root'') ) AS [Parameters]' - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@ReportIndex}', @ReportIndex) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@ServerIdentifier}', @ServerIdentifier) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@DatabaseName}', ISNULL(@DatabaseName,'*')) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@StartTime}', CAST(@StartTime AS NVARCHAR(34))) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@EndTime}', CAST(@EndTime AS NVARCHAR(34))) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@Top}', @Top) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@Measurement}', @Measurement) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@Percentages}', @Percentages) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@AggregateAll}', @AggregateAll) - SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@AggregateNonRegular}', @AggregateNonRegular) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@ReportIndex}', @ReportIndex) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@ServerIdentifier}', @ServerIdentifier) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@DatabaseName}', ISNULL(@DatabaseName,'*')) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@StartTime}', CAST(@StartTime AS NVARCHAR(34))) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@EndTime}', CAST(@EndTime AS NVARCHAR(34))) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@Top}', @Top) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@Measurement}', @Measurement) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@Percentages}', @Percentages) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@AggregateAll}', @AggregateAll) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@AggregateNonRegular}', @AggregateNonRegular) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@IncludeAdhocQueries}', @IncludeAdhocQueries) + SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@IncludeObjectQueryIDs}', @IncludeObjectQueryIDs) IF (@VerboseMode = 1) PRINT (@SqlCmdIndex) IF (@TestMode = 0) EXEC (@SqlCmdIndex) @@ -604,6 +650,7 @@ BEGIN {@ReportID} ,[DatabaseName] ,[ObjectID] + ,[ObjectQueries] ,[SchemaName] ,[ObjectName] ,[ExecutionTypeDesc] diff --git a/ServerTopObjects/README.md b/ServerTopObjects/README.md index d58b647..705359d 100644 --- a/ServerTopObjects/README.md +++ b/ServerTopObjects/README.md @@ -1,9 +1,11 @@ # ServerTopObjects This tool provides uses the runtime stats for each database on the server to get a list of the TOP XX objects on each database, ordered by any of the measurements Query Store keeps track off (totals). \ +Can optionally include ad hoc queries aggregated under a "virtual" object +\ (SQL 2016 does not support @Measurement = 'log_bytes_used' / 'tempdb_space_used') \ -Due to the wait Dynamic SQL and EXEC / EXECUTE / sp_executesql commands are executed, these cannot be captured as part of the object that invoked them +Due to the wait Dynamic SQL and EXEC / EXECUTE / sp_executesql commands are executed, these cannot be captured as part of the object that invoked them and will fall under the "ad hoc" virtual object ## Use cases and examples ### Objects with a high CPU consumption (results in microseconds) Get a list of objects (top 10 per database), aggregating all exit results of the objects @@ -13,6 +15,15 @@ EXECUTE [dbo].[ServerTopObjects] ,@Top = 10 ,@AggregateAll = 1 ``` +### Objects with a high CPU consumption (results in microseconds) and their corresponding subqueries (subqueries ordered by cpu_time too) +Get a list of objects (top 10 per database), aggregating all exit results of the objects +``` +EXECUTE [dbo].[ServerTopObjects] + @Measurement = 'cpu_time' + ,@Top = 10 + ,@AggregateAll = 1 + ,@IncludeObjectQueryIDs = 1 +``` ### Objects with a high CPU consumption (results in percentage) Get a list of objects (top 10 per database), aggregating all exit results of the objects The measurements, rather than be measured in their corresponding units (microseconds, 8 KB pages, or log bytes), will be returned in a 0 to 100000 range @@ -23,8 +34,8 @@ EXECUTE [dbo].[ServerTopObjects] ,@Top = 10 ,@AggregateAll = 1 ``` -### Objects with highest TempDB usage for a given database -Store a list with the top 50 objects with the highest TempDB usage for the database TargetDB, +### Objects / Ad hoc queries with highest TempDB usage for a given database +Store a list with the top 50 objects (or aggregation of all adhoc queries) with the highest TempDB usage for the database TargetDB, ``` EXECUTE [dbo].[ServerTopObjects] @DatabaseName = 'TargetDB' @@ -33,8 +44,11 @@ EXECUTE [dbo].[ServerTopObjects] ,@Measurement = 'tempdb_space_used' ,@Top = 50 ,@AggregateAll = 1 + ,@IncludeAdhocQueries = 0 ``` ## Suggested uses ### High CPU analysis -Execute it to capture highest CPU consumer objects after a certain threshold has been reach to analyze what was the cause being a period of high activity on the server even when it occurred out of office hours. \ No newline at end of file +Execute it to capture highest CPU consumer objects after a certain threshold has been reach to analyze what was the cause being a period of high activity on the server even when it occurred out of office hours. +### Compare adhoc & objects +Compare the CPU / duration usage of ad hoc queries when converting such queries into SPs to refactor the code and identify the heaviest to focus on \ No newline at end of file diff --git a/ServerTopQueries/3-dbo.vServerTopQueriesIndex.View.sql b/ServerTopQueries/3-dbo.vServerTopQueriesIndex.View.sql index b51f102..40236b0 100644 --- a/ServerTopQueries/3-dbo.vServerTopQueriesIndex.View.sql +++ b/ServerTopQueries/3-dbo.vServerTopQueriesIndex.View.sql @@ -41,6 +41,12 @@ -- [ExcludeInternal] BIT NOT NULL -- Flag to exclude internal queries (UPDATE STATISTICS, INDEX REBUILD....) -- +-- [AggregateAll] BIT NOT NULL +-- Flag to determine whether all query executions are aggregated +-- +-- [AggregateNonRegular] BIT NOT NULL +-- Flag to determine whether all query executions that didn't have a "regular" exit are aggregated together +-- -- -- Date: 2020.10.22 -- Auth: Pablo Lozano (@sqlozano) @@ -56,6 +62,10 @@ -- Date: 2021.10.15 -- Auth: Pablo Lozano (@sqlozano) -- Changes: Added parameter: @Percentages +-- +-- Date: 2022.10.19 +-- Auth: Pablo Lozano (@sqlozano) +-- Changes: Added missing description for the columns: [AggregateAll], [AggregateNonRegular] ---------------------------------------------------------------------------------- CREATE OR ALTER VIEW [dbo].[vServerTopQueriesIndex]