Skip to content

Commit

Permalink
Added subqueris and adhoc for ServerTopQueries
Browse files Browse the repository at this point in the history
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
  • Loading branch information
SQLozano committed Oct 19, 2022
1 parent 7b4800a commit a804769
Show file tree
Hide file tree
Showing 6 changed files with 127 additions and 29 deletions.
10 changes: 7 additions & 3 deletions ServerTopObjects/2-dbo.ServerTopObjectsStore.Table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand Down Expand Up @@ -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
Expand Down
19 changes: 19 additions & 0 deletions ServerTopObjects/3-dbo.vServerTopObjectsIndex.View.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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]
Expand All @@ -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
6 changes: 5 additions & 1 deletion ServerTopObjects/4-dbo.vServerTopObjectsStore.View.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand Down Expand Up @@ -68,6 +71,7 @@ SELECT
,[stoi].[Percentages]
,[stos].[DatabaseName]
,[stos].[ObjectID]
,[stos].[ObjectQueryIDs]
,[stos].[SchemaName]
,[stos].[ObjectName]
,[stos].[ExecutionTypeDesc]
Expand Down
89 changes: 68 additions & 21 deletions ServerTopObjects/5-dbo.ServerTopObjects.Procedure.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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]
--
Expand All @@ -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]
Expand All @@ -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
Expand Down Expand Up @@ -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


Expand Down Expand Up @@ -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
Expand All @@ -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''
Expand All @@ -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
(
Expand Down Expand Up @@ -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]
Expand Down Expand Up @@ -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
Expand Down Expand Up @@ -518,7 +559,8 @@ BEGIN
DECLARE @SqlCmd2User NVARCHAR(MAX)
SET @SqlCmd2User = 'SELECT
[DatabaseName]
,[ObjectID]
,[ObjectID]
,[ObjectQueries]
,[SchemaName]
,[ObjectName]
,[ExecutionTypeDesc]
Expand Down Expand Up @@ -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)
Expand All @@ -604,6 +650,7 @@ BEGIN
{@ReportID}
,[DatabaseName]
,[ObjectID]
,[ObjectQueries]
,[SchemaName]
,[ObjectName]
,[ExecutionTypeDesc]
Expand Down
22 changes: 18 additions & 4 deletions ServerTopObjects/README.md
Original file line number Diff line number Diff line change
@@ -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
Expand All @@ -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
Expand All @@ -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'
Expand All @@ -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.
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
10 changes: 10 additions & 0 deletions ServerTopQueries/3-dbo.vServerTopQueriesIndex.View.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand All @@ -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]
Expand Down

0 comments on commit a804769

Please sign in to comment.