├── Installers ├── PivotedWaitStats_Installer.ps1 ├── PivotedWaitStats_Test.sql ├── PlanMiner_Installer.ps1 ├── QDSCacheCleanup_Installer.ps1 ├── QDSCacheCleanup_Test.sql ├── QDSToolBox_Installer.ps1 ├── QueryReport_Installer.ps1 ├── QueryReport_Test.sql ├── QueryVariation_Installer.ps1 ├── QueryVariation_Test.sql ├── QueryWaits_Installer.ps1 ├── QueryWaits_Test.sql ├── README.md ├── ServerTopObjects_Installer.ps1 ├── ServerTopObjects_Test.sql ├── ServerTopQueries_Installer.ps1 ├── ServerTopQueries_Test.sql ├── StatisticsUsed_Installer.ps1 ├── WaitsVariation_Installer.ps1 └── WaitsVariation_Test.sql ├── LICENSE ├── PivotedWaitStats ├── 0-schema.sql ├── 1-dbo.query_store_wait_stats_pivoted.View.sql └── README.md ├── PlanMiner ├── 00-schema.sql ├── 01-dbo.PlanMiner_PlanList.Table.sql ├── 02-dbo.vPlanMiner_PlanList.View.sql ├── 03-dbo.PlanMiner_Statements.Table.sql ├── 04-dbo.vPlanMiner_Statements.View.sql ├── 05-dbo.PlanMiner_IndexOperations.Table.sql ├── 06-dbo.PlanMiner_MissingIndexes.Table.sql ├── 07-dbo.PlanMiner_UnmatchedIndexes.Table.sql ├── 08-dbo.PlanMiner_Cursors.Table.sql ├── 09-dbo.PlanMiner_Statistics.Table.sql ├── 10-dbo.PlanMiner_Nodes.Table.sql ├── 11-dbo.PlanMiner_Columns.Table.sql ├── 20-dbo.PlanMiner.Procedure.sql └── README.md ├── QDSCacheCleanup ├── 0-schema.sql ├── 1-dbo.QDSCacheCleanupIndex.Table.sql ├── 2-dbo.QDSCacheCleanupDetails.Table.sql ├── 3-dbo.QDSCacheCleanup.Procedure.sql ├── 4-dbo.vQDSCacheCleanupIndex.View.sql ├── 5-dbo.vQDSCacheCleanupDetails.View.sql └── README.md ├── QueryReport ├── 0-schema.sql ├── 1-dbo.QueryReport.sql └── README.md ├── QueryVariation ├── 0-schema.sql ├── 1-dbo.QDSMetricArchive.Table.sql ├── 2-dbo.QueryVariationIndex.Table.sql ├── 3-dbo.QueryVariationStore.Table.sql ├── 4-dbo.QueryVariation.Procedure.sql ├── 5-dbo.vQueryVariationIndex.View.sql ├── 6-dbo.vQueryVariationStore.View.sql └── README.md ├── QueryWaits ├── 0-schema.sql ├── 1-dbo.QueryWaitsIndex.Table.sql ├── 2-dbo.QueryWaitsStore.Table.sql ├── 3-dbo.QueryWaits.Procedure.sql ├── 4-dbo.vQueryWaitsIndex.View.sql ├── 5-dbo.vQueryWaitsStore.View.sql └── README.md ├── README.md ├── ServerTopObjects ├── 0-schema.sql ├── 1-dbo.ServerTopObjectsIndex.Table.sql ├── 2-dbo.ServerTopObjectsStore.Table.sql ├── 3-dbo.vServerTopObjectsIndex.View.sql ├── 4-dbo.vServerTopObjectsStore.View.sql ├── 5-dbo.ServerTopObjects.Procedure.sql └── README.md ├── ServerTopQueries ├── 0-schema.sql ├── 1-dbo.ServerTopQueriesIndex.Table.sql ├── 2-dbo.ServerTopQueriesStore.Table.sql ├── 3-dbo.vServerTopQueriesIndex.View.sql ├── 4-dbo.vServerTopQueriesStore.View.sql ├── 5-dbo.ServerTopQueries.Procedure.sql └── README.md ├── StatisticsUsed ├── 0-schema.sql ├── 1-dbo.StatisticsSamplePercent.Function.sql ├── 2-dbo.StatisticsUsed.Procedure.sql └── README.md ├── WaitsVariation ├── 0-schema.sql ├── 1-dbo.WaitsVariationIndex.Table.sql ├── 2-dbo.WaitsVariationStore.Table.sql ├── 3-dbo.vWaitsVariationIndexView.sql ├── 4-dbo.vWaitsVariationStore.View.sql ├── 5-dbo.WaitsVariation.Procedure.sql ├── 6-dbo.WaitsVariationFromStore.Procedure.sql └── README.md └── qdstoolbox.svg /Installers/PivotedWaitStats_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Verify SQL version 15 | if($Login){ 16 | $SQLVersion = Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query "SELECT CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) AS [VersionNumber]" 17 | } 18 | else { 19 | $SQLVersion = Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query "SELECT CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) AS [VersionNumber]" 20 | } 21 | if($SQLVersion.VersionNumber -lt 14){ 22 | Write-Output "The view [dbo].[query_store_wait_stats_pivoted] cannot be deployed on a SQL version prior to 2017" 23 | return 24 | } 25 | 26 | # Deploy all SQL script found in \PivotedWaitStats 27 | $SQLScripts = (Get-ChildItem -Path '..\PivotedWaitStats' -Filter "*.sql") | Sort 28 | foreach($Script in $SQLScripts){ 29 | # Replace default schema name [dbo] with [$TargetSchema] 30 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 31 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 32 | 33 | # Deploy updated script 34 | if($Login){ 35 | # Login / Password authentication 36 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 37 | } 38 | else { 39 | # Active Directory authentication 40 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 41 | } 42 | } -------------------------------------------------------------------------------- /Installers/PivotedWaitStats_Test.sql: -------------------------------------------------------------------------------- 1 | SELECT TOP(0) FROM [dbo].[query_store_wait_stats_pivoted] -------------------------------------------------------------------------------- /Installers/PlanMiner_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Deploy all SQL script found in \PlanMiner 15 | $SQLScripts = (Get-ChildItem -Path '..\PlanMiner' -Filter "*.sql") | Sort 16 | foreach($Script in $SQLScripts){ 17 | # Replace default schema name [dbo] with [$TargetSchema] 18 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 19 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 20 | 21 | # Deploy updated script 22 | if($Login){ 23 | # Login / Password authentication 24 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 25 | } 26 | else { 27 | # Active Directory authentication 28 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 29 | } 30 | } -------------------------------------------------------------------------------- /Installers/QDSCacheCleanup_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 10 | $EncryptionParameter = @{Encrypt = "Optional"} 11 | } 12 | 13 | # Deploy all SQL script found in \QDSCacheCleanup 14 | $SQLScripts = (Get-ChildItem -Path '..\QDSCacheCleanup' -Filter "*.sql") | Sort 15 | foreach($Script in $SQLScripts){ 16 | # Replace default schema name [dbo] with [$TargetSchema] 17 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 18 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 19 | 20 | # Deploy updated script 21 | if($Login){ 22 | # Login / Password authentication 23 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 24 | } 25 | else { 26 | # Active Directory authentication 27 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 28 | } 29 | } -------------------------------------------------------------------------------- /Installers/QDSCacheCleanup_Test.sql: -------------------------------------------------------------------------------- 1 | EXECUTE [dbo].[QDSCacheCleanup] 2 | @DatabaseName = 'QDSToolBox' 3 | ,@CleanAdhocStale = 1 4 | ,@CleanStale = 1 5 | ,@Retention = 24 6 | ,@MinExecutionCount = 2 7 | ,@CleanOrphan = 1 8 | ,@CleanInternal = 1 9 | ,@ReportAsTable = 1 10 | ,@ReportDetailsAsTable = 1 11 | ,@TestMode = 1 12 | GO 13 | 14 | EXECUTE [dbo].[QDSCacheCleanup] 15 | @DatabaseName = 'QDSToolBox' 16 | ,@CleanAdhocStale = 1 17 | ,@CleanStale = 1 18 | ,@Retention = 24 19 | ,@MinExecutionCount = 2 20 | ,@CleanOrphan = 1 21 | ,@CleanInternal = 1 22 | ,@ReportAsText = 1 23 | ,@TestMode = 1 24 | GO 25 | 26 | DECLARE @ReportID INT 27 | EXECUTE [dbo].[QDSCacheCleanup] 28 | @DatabaseName = 'QDSToolBox' 29 | ,@CleanAdhocStale = 1 30 | ,@CleanStale = 1 31 | ,@Retention = 24 32 | ,@MinExecutionCount = 2 33 | ,@CleanOrphan = 1 34 | ,@CleanInternal = 1 35 | ,@RetainForcedMetrics = 1 36 | ,@ReportIndexOutputTable = '[dbo].[QDSCacheCleanupIndex]' 37 | ,@ReportDetailsOutputTable = '[dbo].[QDSCacheCleanupDetails]' 38 | ,@TestMode = 1 39 | ,@ReportID = @ReportID OUTPUT 40 | 41 | SELECT * FROM [dbo].[QDSCacheCleanupIndex] WHERE [ReportID] = @ReportID 42 | SELECT * FROM [dbo].[QDSCacheCleanupDetails] WHERE [ReportID] = @ReportID 43 | 44 | SELECT * FROM [dbo].[vQDSCacheCleanupIndex] WHERE [ReportID] = @ReportID 45 | SELECT * FROM [dbo].[vQDSCacheCleanupDetails] WHERE [ReportID] = @ReportID 46 | GO -------------------------------------------------------------------------------- /Installers/QDSToolBox_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | 9 | .\PivotedWaitStats_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 10 | .\PlanMiner_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 11 | .\QDSCacheCleanup_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 12 | .\QueryVariation_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 13 | .\QueryWaits_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 14 | .\ServerTopObject_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 15 | .\ServerTopQueries_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 16 | .\StatisticsUsed_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 17 | .\WaitsVariation_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password 18 | .\QueryReport_Installer.ps1 -TargetInstance $TargetInstance -TargetDatabase $TargetDatabase -TargetSchema $TargetSchema -Login $Login -Password $Password -------------------------------------------------------------------------------- /Installers/QueryReport_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Verify SQL version 15 | if($Login){ 16 | $SQLVersion = Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query "SELECT CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) AS [VersionNumber]" 17 | } 18 | else { 19 | $SQLVersion = Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query "SELECT CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) AS [VersionNumber]" 20 | } 21 | if($SQLVersion.VersionNumber -lt 14){ 22 | Write-Output "The component [QueryWaits] cannot be deployed on a SQL version prior to 2017" 23 | return 24 | } 25 | 26 | # Deploy all SQL script found in \QueryWaits 27 | $SQLScripts = (Get-ChildItem -Path '..\QueryReport' -Filter "*.sql") | Sort 28 | foreach($Script in $SQLScripts){ 29 | # Replace default schema name [dbo] with [$TargetSchema] 30 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 31 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 32 | 33 | # Deploy updated script 34 | if($Login){ 35 | # Login / Password authentication 36 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 37 | } 38 | else { 39 | # Active Directory authentication 40 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 41 | } 42 | } -------------------------------------------------------------------------------- /Installers/QueryReport_Test.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Enter values that are expected to return some data: 3 | @ObjectName a non-encrypted object 4 | @StartTime & @EndTime covering a time period when the @ObjectName was executed (as small as possible to reduce impact of the test) 5 | */ 6 | DECLARE @TargetDatabase SYSNAME = 'DatabaseName' 7 | DECLARE @ObjectName SYSNAME = 'Schema.Object' 8 | DECLARE @StartTime DATETIME2 = '2021-08-01 00:00' 9 | DECLARE @EndTime DATETIME2 = '2021-08-02 00:00' 10 | 11 | -- Testing the extraction of the details (no stats) 12 | EXECUTE [dbo].[QueryReport] 13 | @DatabaseName = @TargetDatabase 14 | ,@ObjectName = @ObjectName 15 | ,@StartTime = @StartTime 16 | ,@EndTime = @EndTime 17 | ,@IntervalReports = 0 18 | ,@AggregatedReports = 0 19 | ,@PlanAggregation = 0 20 | ,@QueryAggregation = 0 21 | ,@ObjectAggregation = 0 22 | ,@PlanDetails = 1 23 | ,@QueryDetails = 1 24 | ,@ObjectDetails = 1 25 | ,@Averages = 0 26 | ,@Totals = 0 27 | ,@RuntimeStats = 0 28 | ,@WaitStats = 0 29 | -- Testing the extraction of runtime stats 30 | EXECUTE [dbo].[QueryReport] 31 | @DatabaseName = @TargetDatabase 32 | ,@ObjectName = @ObjectName 33 | ,@StartTime = @StartTime 34 | ,@EndTime = @EndTime 35 | ,@IntervalReports = 1 36 | ,@AggregatedReports = 1 37 | ,@PlanAggregation = 1 38 | ,@QueryAggregation = 1 39 | ,@ObjectAggregation = 1 40 | ,@PlanDetails = 0 41 | ,@QueryDetails = 0 42 | ,@ObjectDetails = 0 43 | ,@Averages = 1 44 | ,@Totals = 1 45 | ,@RuntimeStats = 1 46 | ,@WaitStats = 0 47 | -- Testing the extraction of wait stats 48 | EXECUTE [dbo].[QueryReport] 49 | @DatabaseName = @TargetDatabase 50 | ,@ObjectName = @ObjectName 51 | ,@StartTime = @StartTime 52 | ,@EndTime = @EndTime 53 | ,@IntervalReports = 1 54 | ,@AggregatedReports = 1 55 | ,@PlanAggregation = 1 56 | ,@QueryAggregation = 1 57 | ,@ObjectAggregation = 1 58 | ,@PlanDetails = 0 59 | ,@QueryDetails = 0 60 | ,@ObjectDetails = 0 61 | ,@Averages = 1 62 | ,@Totals = 1 63 | ,@RuntimeStats = 0 64 | ,@WaitStats = 1 65 | -- Testing the extraction of both runtime and wait stats 66 | EXECUTE [dbo].[QueryReport] 67 | @DatabaseName = @TargetDatabase 68 | ,@ObjectName = @ObjectName 69 | ,@StartTime = @StartTime 70 | ,@EndTime = @EndTime 71 | ,@IntervalReports = 1 72 | ,@AggregatedReports = 1 73 | ,@PlanAggregation = 1 74 | ,@QueryAggregation = 1 75 | ,@ObjectAggregation = 1 76 | ,@PlanDetails = 0 77 | ,@QueryDetails = 0 78 | ,@ObjectDetails = 0 79 | ,@Averages = 1 80 | ,@Totals = 1 81 | ,@RuntimeStats = 1 82 | ,@WaitStats = 1 -------------------------------------------------------------------------------- /Installers/QueryVariation_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Deploy all SQL script found in \QueryVariation 15 | $SQLScripts = (Get-ChildItem -Path '..\QueryVariation' -Filter "*.sql") | Sort 16 | foreach($Script in $SQLScripts){ 17 | # Replace default schema name [dbo] with [$TargetSchema] 18 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 19 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 20 | 21 | # Deploy updated script 22 | if($Login){ 23 | # Login / Password authentication 24 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 25 | } 26 | else { 27 | # Active Directory authentication 28 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 29 | } 30 | } -------------------------------------------------------------------------------- /Installers/QueryVariation_Test.sql: -------------------------------------------------------------------------------- 1 | SET NOCOUNT ON 2 | DECLARE @Version INT = CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) 3 | 4 | DECLARE [Executions] CURSOR LOCAL READ_ONLY FAST_FORWARD 5 | FOR 6 | SELECT [Measurement], [Metric] FROM [dbo].[QDSMetricArchive] 7 | 8 | DECLARE @Measurement NVARCHAR(32) 9 | DECLARE @Metric NVARCHAR(16) 10 | DECLARE @ReportID INT 11 | DECLARE @Reports TABLE 12 | ( 13 | [ReportID] INT 14 | ) 15 | 16 | OPEN [Executions] 17 | FETCH NEXT FROM [Executions] INTO @Measurement, @Metric 18 | 19 | WHILE(@@FETCH_STATUS = 0) 20 | BEGIN 21 | IF( 22 | (@Version >= 14) 23 | OR 24 | ((@Version = 13) AND @Measurement NOT IN ('Log','TempDB')) 25 | ) 26 | BEGIN 27 | EXECUTE [dbo].[QueryVariation] 28 | @DatabaseName = 'QDSToolBox' 29 | ,@Measurement = @Measurement 30 | ,@Metric = @Metric 31 | ,@VariationType = 'R' 32 | ,@ResultsRowCount = 1 33 | ,@RecentStartTime = '2021-03-01' 34 | ,@RecentEndTime = '2021-03-06' 35 | ,@HistoryStartTime = '2021-03-06' 36 | ,@HistoryEndTime = '2021-03-07' 37 | ,@MinExecCount = 1 38 | ,@MinPlanCount = 1 39 | ,@MaxPlanCount = 10 40 | ,@IncludeQueryText = 0 41 | ,@ExcludeAdhoc = 0 42 | ,@ExcludeInternal = 0 43 | 44 | EXECUTE [dbo].[QueryVariation] 45 | @DatabaseName = 'QDSToolBox' 46 | ,@ReportIndex = '[dbo].[QueryVariationIndex]' 47 | ,@ReportTable = '[dbo].[QueryVariationStore]' 48 | ,@Measurement = @Measurement 49 | ,@Metric = @Metric 50 | ,@VariationType = 'R' 51 | ,@ResultsRowCount = 1 52 | ,@RecentStartTime = '2021-03-01' 53 | ,@RecentEndTime = '2021-03-06' 54 | ,@HistoryStartTime = '2021-03-06' 55 | ,@HistoryEndTime = '2021-03-07' 56 | ,@MinExecCount = 1 57 | ,@MinPlanCount = 1 58 | ,@MaxPlanCount = 10 59 | ,@IncludeQueryText = 0 60 | ,@ExcludeAdhoc = 0 61 | ,@ExcludeInternal = 0 62 | ,@ReportID = @ReportID OUTPUT 63 | END 64 | INSERT INTO @Reports VALUES (@ReportID) 65 | FETCH NEXT FROM [Executions] INTO @Measurement, @Metric 66 | END 67 | 68 | CLOSE [Executions] 69 | DEALLOCATE [Executions] 70 | 71 | DELETE [i] 72 | FROM [dbo].[QueryVariationIndex] [i] 73 | INNER JOIN @Reports [r] 74 | ON [i].[ReportID] = [r].[ReportID] 75 | 76 | DELETE [s] 77 | FROM [dbo].[QueryVariationStore] [s] 78 | INNER JOIN @Reports [r] 79 | ON [s].[ReportID] = [r].[ReportID] -------------------------------------------------------------------------------- /Installers/QueryWaits_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Verify SQL version 15 | if($Login){ 16 | $SQLVersion = Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query "SELECT CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) AS [VersionNumber]" 17 | } 18 | else { 19 | $SQLVersion = Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query "SELECT CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) AS [VersionNumber]" 20 | } 21 | if($SQLVersion.VersionNumber -lt 14){ 22 | Write-Output "The component [QueryWaits] cannot be deployed on a SQL version prior to 2017" 23 | return 24 | } 25 | 26 | # Deploy all SQL script found in \QueryWaits 27 | $SQLScripts = (Get-ChildItem -Path '..\QueryWaits' -Filter "*.sql") | Sort 28 | foreach($Script in $SQLScripts){ 29 | # Replace default schema name [dbo] with [$TargetSchema] 30 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 31 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 32 | 33 | # Deploy updated script 34 | if($Login){ 35 | # Login / Password authentication 36 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 37 | } 38 | else { 39 | # Active Directory authentication 40 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 41 | } 42 | } -------------------------------------------------------------------------------- /Installers/QueryWaits_Test.sql: -------------------------------------------------------------------------------- 1 | EXECUTE [dbo].[QueryWaits] 2 | @DatabaseName = 'QDSToolBox' 3 | ,@ReportIndex = NULL 4 | ,@ReportTable = NULL 5 | ,@StartTime = '2021-03-01' 6 | ,@EndTime = '2021-03-08' 7 | ,@ObjectName = '[dbo].[QueryWaits]' 8 | ,@PlanID = NULL 9 | ,@QueryID = NULL 10 | ,@IncludeQueryText = 1 11 | 12 | EXECUTE [dbo].[QueryWaits] 13 | @DatabaseName = 'QDSToolBox' 14 | ,@ReportIndex = NULL 15 | ,@ReportTable = NULL 16 | ,@StartTime = '2021-03-01' 17 | ,@EndTime = '2021-03-08' 18 | ,@ObjectName = NULL 19 | ,@PlanID = 1 20 | ,@QueryID = NULL 21 | ,@IncludeQueryText = 1 22 | 23 | EXECUTE [dbo].[QueryWaits] 24 | @DatabaseName = 'QDSToolBox' 25 | ,@ReportIndex = NULL 26 | ,@ReportTable = NULL 27 | ,@StartTime = '2021-03-01' 28 | ,@EndTime = '2021-03-08' 29 | ,@ObjectName = NULL 30 | ,@PlanID = NULL 31 | ,@QueryID = 1 32 | ,@IncludeQueryText = 1 33 | GO 34 | 35 | SET NOCOUNT ON 36 | DECLARE @ReportID INT 37 | EXECUTE [dbo].[QueryWaits] 38 | @DatabaseName = 'QDSToolBox' 39 | ,@ReportIndex = '[dbo].[QueryWaitsIndex]' 40 | ,@ReportTable = '[dbo].[QueryWaitsStore]' 41 | ,@StartTime = '2021-03-01' 42 | ,@EndTime = '2021-03-08' 43 | ,@ObjectName = '[dbo].[QueryWaits]' 44 | ,@PlanID = NULL 45 | ,@QueryID = NULL 46 | ,@IncludeQueryText = 1 47 | ,@ReportID = @ReportID OUTPUT 48 | DELETE FROM [dbo].[QueryWaitsIndex] WHERE [ReportID] = @ReportID 49 | DELETE FROM [dbo].[QueryWaitsStore] WHERE [ReportID] = @ReportID 50 | 51 | EXECUTE [dbo].[QueryWaits] 52 | @DatabaseName = 'QDSToolBox' 53 | ,@ReportIndex = '[dbo].[QueryWaitsIndex]' 54 | ,@ReportTable = '[dbo].[QueryWaitsStore]' 55 | ,@StartTime = '2021-03-01' 56 | ,@EndTime = '2021-03-08' 57 | ,@ObjectName = NULL 58 | ,@PlanID = 1 59 | ,@QueryID = NULL 60 | ,@IncludeQueryText = 1 61 | ,@ReportID = @ReportID OUTPUT 62 | DELETE FROM [dbo].[QueryWaitsIndex] WHERE [ReportID] = @ReportID 63 | DELETE FROM [dbo].[QueryWaitsStore] WHERE [ReportID] = @ReportID 64 | 65 | EXECUTE [dbo].[QueryWaits] 66 | @DatabaseName = 'QDSToolBox' 67 | ,@ReportIndex = '[dbo].[QueryWaitsIndex]' 68 | ,@ReportTable = '[dbo].[QueryWaitsStore]' 69 | ,@StartTime = '2021-03-01' 70 | ,@EndTime = '2021-03-08' 71 | ,@ObjectName = NULL 72 | ,@PlanID = NULL 73 | ,@QueryID = 1 74 | ,@IncludeQueryText = 1 75 | ,@ReportID = @ReportID OUTPUT 76 | DELETE FROM [dbo].[QueryWaitsIndex] WHERE [ReportID] = @ReportID 77 | DELETE FROM [dbo].[QueryWaitsStore] WHERE [ReportID] = @ReportID -------------------------------------------------------------------------------- /Installers/README.md: -------------------------------------------------------------------------------- 1 | # Installers 2 | The installers require the SqlServer PS module to be installed 3 | ``` 4 | Install-Module SqlServer 5 | Import-Module SqlServer 6 | ``` 7 | ## Parameters 8 | ``` 9 | Param( 10 | [Parameter(mandatory=$true)][string]$TargetInstance, 11 | [Parameter(mandatory=$true)][string]$TargetDatabase, 12 | [string]$TargetSchema = "dbo", 13 | [string]$Login, 14 | [string]$Password 15 | ) 16 | ``` 17 | $TargetSchema allows the QDSToolBox object to be deployed into a different schema than [dbo] (hardcoded in the SQL scripts) 18 | \ 19 | By default, it will use the current user's Windows Credentials to connect to the database, but this can be modified by using SQL credentials ($Login and $Password) 20 | 21 | ## Sample deployment 22 | ``` 23 | .\QDSToolbox_Installer.ps1 -TargetInstance "Machine\Instance" -TargetDatabase "AdminDB" -TargetSchema "QDS" 24 | ``` 25 | 26 | --- 27 | 28 | # Testing scripts 29 | The accompannying _Test.sql scripts will check the correct execution of the QDSToolBox components 30 | \ 31 | These scripts are meant to help testing new changes in the scripts -------------------------------------------------------------------------------- /Installers/ServerTopObjects_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Deploy all SQL script found in \ServerTopObjects 15 | $SQLScripts = (Get-ChildItem -Path '..\ServerTopObjects' -Filter "*.sql") | Sort 16 | foreach($Script in $SQLScripts){ 17 | # Replace default schema name [dbo] with [$TargetSchema] 18 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 19 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 20 | 21 | # Deploy updated script 22 | if($Login){ 23 | # Login / Password authentication 24 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 25 | } 26 | else { 27 | # Active Directory authentication 28 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 29 | } 30 | } -------------------------------------------------------------------------------- /Installers/ServerTopObjects_Test.sql: -------------------------------------------------------------------------------- 1 | DECLARE @Version INT = CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) 2 | 3 | 4 | DECLARE @Measurement NVARCHAR(32) 5 | DECLARE @MeasurementList TABLE 6 | ( 7 | [Measurement] NVARCHAR(32) 8 | ) 9 | INSERT INTO @MeasurementList VALUES ('duration') 10 | INSERT INTO @MeasurementList VALUES ('cpu_time') 11 | INSERT INTO @MeasurementList VALUES ('logical_io_reads') 12 | INSERT INTO @MeasurementList VALUES ('logical_io_writes') 13 | INSERT INTO @MeasurementList VALUES ('physical_io_reads') 14 | INSERT INTO @MeasurementList VALUES ('clr_time') 15 | INSERT INTO @MeasurementList VALUES ('query_used_memory') 16 | INSERT INTO @MeasurementList VALUES ('log_bytes_used') 17 | INSERT INTO @MeasurementList VALUES ('tempdb_space_used') 18 | 19 | DECLARE @ReportID INT 20 | DECLARE @ReportList TABLE 21 | ( 22 | [ReportID] INT 23 | ) 24 | 25 | DECLARE [Measurement_Cursor] CURSOR LOCAL READ_ONLY FAST_FORWARD 26 | FOR 27 | SELECT [Measurement] FROM @MeasurementList 28 | 29 | OPEN [Measurement_Cursor] 30 | FETCH NEXT FROM [Measurement_Cursor] INTO @Measurement 31 | 32 | WHILE(@@FETCH_STATUS = 0) 33 | BEGIN 34 | IF((@Version >= 13) AND @Measurement NOT IN ('log_bytes_used','tempdb_space_used')) 35 | 36 | BEGIN 37 | EXECUTE [dbo].[ServerTopObjects] 38 | @DatabaseName = 'QDSToolBox' 39 | ,@ReportIndex = NULL 40 | ,@ReportTable = NULL 41 | ,@StartTime = '2021-03-01' 42 | ,@EndTime = '2021-03-08' 43 | ,@Top = 1 44 | ,@Measurement = @Measurement 45 | ,@IncludeQueryText = 1 46 | ,@ExcludeAdhoc = 0 47 | ,@ExcludeInternal = 0 48 | 49 | EXECUTE [dbo].[ServerTopObjects] 50 | @DatabaseName = 'QDSToolBox' 51 | ,@ReportIndex = '[dbo].[ServerTopObjectsIndex]' 52 | ,@ReportTable = '[dbo].[ServerTopObjectsStore]' 53 | ,@StartTime = '2021-03-01' 54 | ,@EndTime = '2021-03-08' 55 | ,@Top = 1 56 | ,@Measurement = @Measurement 57 | ,@IncludeQueryText = 1 58 | ,@ExcludeAdhoc = 0 59 | ,@ExcludeInternal = 0 60 | ,@ReportID = @ReportID OUTPUT 61 | END 62 | INSERT INTO @ReportList VALUES (@ReportID) 63 | FETCH NEXT FROM [Measurement_Cursor] INTO @Measurement 64 | END 65 | 66 | CLOSE [Measurement_Cursor] 67 | DEALLOCATE [Measurement_Cursor] 68 | 69 | DELETE [i] 70 | FROM [dbo].[ServerTopObjectsIndex] [i] 71 | INNER JOIN @ReportList [r] 72 | ON [i].[ReportID] = [r].[ReportID] 73 | 74 | DELETE [s] 75 | FROM [dbo].[ServerTopObjectsStore] [s] 76 | INNER JOIN @ReportList [r] 77 | ON [s].[ReportID] = [r].[ReportID] -------------------------------------------------------------------------------- /Installers/ServerTopQueries_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Deploy all SQL script found in \ServerTopQueries 15 | $SQLScripts = (Get-ChildItem -Path '..\ServerTopQueries' -Filter "*.sql") | Sort 16 | foreach($Script in $SQLScripts){ 17 | # Replace default schema name [dbo] with [$TargetSchema] 18 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 19 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 20 | 21 | # Deploy updated script 22 | if($Login){ 23 | # Login / Password authentication 24 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 25 | } 26 | else { 27 | # Active Directory authentication 28 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 29 | } 30 | } -------------------------------------------------------------------------------- /Installers/ServerTopQueries_Test.sql: -------------------------------------------------------------------------------- 1 | DECLARE @Version INT = CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) 2 | 3 | 4 | DECLARE @Measurement NVARCHAR(32) 5 | DECLARE @MeasurementList TABLE 6 | ( 7 | [Measurement] NVARCHAR(32) 8 | ) 9 | INSERT INTO @MeasurementList VALUES ('duration') 10 | INSERT INTO @MeasurementList VALUES ('cpu_time') 11 | INSERT INTO @MeasurementList VALUES ('logical_io_reads') 12 | INSERT INTO @MeasurementList VALUES ('logical_io_writes') 13 | INSERT INTO @MeasurementList VALUES ('physical_io_reads') 14 | INSERT INTO @MeasurementList VALUES ('clr_time') 15 | INSERT INTO @MeasurementList VALUES ('query_used_memory') 16 | INSERT INTO @MeasurementList VALUES ('log_bytes_used') 17 | INSERT INTO @MeasurementList VALUES ('tempdb_space_used') 18 | 19 | DECLARE @ReportID INT 20 | DECLARE @ReportList TABLE 21 | ( 22 | [ReportID] INT 23 | ) 24 | 25 | DECLARE [Measurement_Cursor] CURSOR LOCAL READ_ONLY FAST_FORWARD 26 | FOR 27 | SELECT [Measurement] FROM @MeasurementList 28 | 29 | OPEN [Measurement_Cursor] 30 | FETCH NEXT FROM [Measurement_Cursor] INTO @Measurement 31 | 32 | WHILE(@@FETCH_STATUS = 0) 33 | BEGIN 34 | IF((@Version >= 13) AND @Measurement NOT IN ('log_bytes_used','tempdb_space_used')) 35 | 36 | BEGIN 37 | EXECUTE [dbo].[ServerTopQueries] 38 | @DatabaseName = 'QDSToolBox' 39 | ,@ReportIndex = NULL 40 | ,@ReportTable = NULL 41 | ,@StartTime = '2021-03-01' 42 | ,@EndTime = '2021-03-08' 43 | ,@Top = 1 44 | ,@Measurement = @Measurement 45 | ,@IncludeQueryText = 1 46 | ,@ExcludeAdhoc = 0 47 | ,@ExcludeInternal = 0 48 | 49 | EXECUTE [dbo].[ServerTopQueries] 50 | @DatabaseName = 'QDSToolBox' 51 | ,@ReportIndex = '[dbo].[ServerTopQueriesIndex]' 52 | ,@ReportTable = '[dbo].[ServerTopQueriesStore]' 53 | ,@StartTime = '2021-03-01' 54 | ,@EndTime = '2021-03-08' 55 | ,@Top = 1 56 | ,@Measurement = @Measurement 57 | ,@IncludeQueryText = 1 58 | ,@ExcludeAdhoc = 0 59 | ,@ExcludeInternal = 0 60 | ,@ReportID = @ReportID OUTPUT 61 | END 62 | INSERT INTO @ReportList VALUES (@ReportID) 63 | FETCH NEXT FROM [Measurement_Cursor] INTO @Measurement 64 | END 65 | 66 | CLOSE [Measurement_Cursor] 67 | DEALLOCATE [Measurement_Cursor] 68 | 69 | DELETE [i] 70 | FROM [dbo].[ServerTopQueriesIndex] [i] 71 | INNER JOIN @ReportList [r] 72 | ON [i].[ReportID] = [r].[ReportID] 73 | 74 | DELETE [s] 75 | FROM [dbo].[ServerTopQueriesStore] [s] 76 | INNER JOIN @ReportList [r] 77 | ON [s].[ReportID] = [r].[ReportID] -------------------------------------------------------------------------------- /Installers/StatisticsUsed_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Deploy all SQL script found in \StatisticsUsed 15 | $SQLScripts = (Get-ChildItem -Path '..\StatisticsUsed' -Filter "*.sql") | Sort 16 | foreach($Script in $SQLScripts){ 17 | # Replace default schema name [dbo] with [$TargetSchema] 18 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 19 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 20 | 21 | # Deploy updated script 22 | if($Login){ 23 | # Login / Password authentication 24 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 25 | } 26 | else { 27 | # Active Directory authentication 28 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 29 | } 30 | } -------------------------------------------------------------------------------- /Installers/WaitsVariation_Installer.ps1: -------------------------------------------------------------------------------- 1 | Param( 2 | [Parameter(mandatory=$true)][string]$TargetInstance, 3 | [Parameter(mandatory=$true)][string]$TargetDatabase, 4 | [string]$TargetSchema = "dbo", 5 | [string]$Login, 6 | [string]$Password 7 | ) 8 | Import-Module SqlServer 9 | # For versions >= 22 of the SqlServer PS module, the default encryption changed so it must be manually set Encrypt 10 | if( (Get-Module -Name "sqlserver").Version.Major -ge 22){ 11 | $EncryptionParameter = @{Encrypt = "Optional"} 12 | } 13 | 14 | # Verify SQL version 15 | if($Login){ 16 | $SQLVersion = Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query "SELECT CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) AS [VersionNumber]" 17 | } 18 | else { 19 | $SQLVersion = Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query "SELECT CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) AS [VersionNumber]" 20 | } 21 | if($SQLVersion.VersionNumber -lt 14){ 22 | Write-Output "The component [WaitsVariation] cannot be deployed on a SQL version prior to 2017" 23 | return 24 | } 25 | 26 | # Deploy all SQL script found in \WaitsVariation 27 | $SQLScripts = (Get-ChildItem -Path '..\WaitsVariation' -Filter "*.sql") | Sort 28 | foreach($Script in $SQLScripts){ 29 | # Replace default schema name [dbo] with [$TargetSchema] 30 | $ScriptContents = Get-Content -Path $Script.FullName -Raw 31 | $ScriptContents = ($ScriptContents.Replace("[dbo]","[$($TargetSchema)]")) 32 | 33 | # Deploy updated script 34 | if($Login){ 35 | # Login / Password authentication 36 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Username $Login -Password $Password -Query $ScriptContents @EncryptionParameter 37 | } 38 | else { 39 | # Active Directory authentication 40 | Invoke-SqlCmd -ServerInstance $TargetInstance -Database $TargetDatabase -Query $ScriptContents @EncryptionParameter 41 | } 42 | } -------------------------------------------------------------------------------- /Installers/WaitsVariation_Test.sql: -------------------------------------------------------------------------------- 1 | SET NOCOUNT ON 2 | DECLARE @Version INT = CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) 3 | 4 | DECLARE @Measurement NVARCHAR(32) 5 | DECLARE @MeasurementList TABLE 6 | ( 7 | [Measurement] NVARCHAR(32) 8 | ) 9 | INSERT INTO @MeasurementList VALUES ('Total') 10 | INSERT INTO @MeasurementList VALUES ('Unknown') 11 | INSERT INTO @MeasurementList VALUES ('CPU') 12 | INSERT INTO @MeasurementList VALUES ('WorkerThread') 13 | INSERT INTO @MeasurementList VALUES ('Lock') 14 | INSERT INTO @MeasurementList VALUES ('Latch') 15 | INSERT INTO @MeasurementList VALUES ('BufferLatch') 16 | INSERT INTO @MeasurementList VALUES ('BufferIO') 17 | INSERT INTO @MeasurementList VALUES ('Compilation') 18 | INSERT INTO @MeasurementList VALUES ('SQLCLR') 19 | INSERT INTO @MeasurementList VALUES ('Mirroring') 20 | INSERT INTO @MeasurementList VALUES ('Transaction') 21 | INSERT INTO @MeasurementList VALUES ('Idle') 22 | INSERT INTO @MeasurementList VALUES ('Preemptive') 23 | INSERT INTO @MeasurementList VALUES ('ServiceBroker') 24 | INSERT INTO @MeasurementList VALUES ('TranLogIO') 25 | INSERT INTO @MeasurementList VALUES ('NetworkIO') 26 | INSERT INTO @MeasurementList VALUES ('Parallelism') 27 | INSERT INTO @MeasurementList VALUES ('Memory') 28 | INSERT INTO @MeasurementList VALUES ('UserWait') 29 | INSERT INTO @MeasurementList VALUES ('Tracing') 30 | INSERT INTO @MeasurementList VALUES ('FullTextSearch') 31 | INSERT INTO @MeasurementList VALUES ('OtherDiskIO') 32 | INSERT INTO @MeasurementList VALUES ('Replication') 33 | INSERT INTO @MeasurementList VALUES ('LogRateGovernor') 34 | 35 | DECLARE @ReportID INT 36 | DECLARE @ReportList TABLE 37 | ( 38 | [ReportID] INT 39 | ) 40 | 41 | DECLARE [Measurement_Cursor] CURSOR LOCAL READ_ONLY FAST_FORWARD 42 | FOR 43 | SELECT [Measurement] FROM @MeasurementList 44 | 45 | OPEN [Measurement_Cursor] 46 | FETCH NEXT FROM [Measurement_Cursor] INTO @Measurement 47 | 48 | WHILE(@@FETCH_STATUS = 0) 49 | BEGIN 50 | EXECUTE [dbo].[WaitsVariation] 51 | @DatabaseName = 'QDSToolBox' 52 | ,@ReportIndex = NULL 53 | ,@ReportTable = NULL 54 | ,@WaitType = @Measurement 55 | ,@Metric = 'Total' 56 | ,@VariationType = 'I' 57 | ,@ResultsRowCount = 1 58 | ,@RecentStartTime = '2021-03-07 19:00' 59 | ,@RecentEndTime = '2021-03-08' 60 | ,@HistoryStartTime = '2021-03-01' 61 | ,@HistoryEndTime = '2021-03-07 19:00' 62 | ,@IncludeQueryText = 1 63 | ,@ExcludeAdhoc = 0 64 | ,@ExcludeInternal = 0 65 | ,@VerboseMode = 1 66 | 67 | EXECUTE [dbo].[WaitsVariation] 68 | @DatabaseName = 'QDSToolBox' 69 | ,@ReportIndex = NULL 70 | ,@ReportTable = NULL 71 | ,@WaitType = @Measurement 72 | ,@Metric = 'Avg' 73 | ,@VariationType = NULL 74 | ,@ResultsRowCount = 1 75 | ,@RecentStartTime = '2021-03-07' 76 | ,@RecentEndTime = '2021-03-08' 77 | ,@HistoryStartTime = '2021-03-01' 78 | ,@HistoryEndTime = '2021-03-07' 79 | ,@IncludeQueryText = 1 80 | ,@ExcludeAdhoc = 0 81 | ,@ExcludeInternal = 0 82 | 83 | EXECUTE [dbo].[WaitsVariation] 84 | @DatabaseName = 'QDSToolBox' 85 | ,@ReportIndex = '[dbo].[WaitsVariationIndex]' 86 | ,@ReportTable = '[dbo].[WaitsVariationStore]' 87 | ,@WaitType = @Measurement 88 | ,@Metric = 'Total' 89 | ,@VariationType = NULL 90 | ,@ResultsRowCount = 1 91 | ,@RecentStartTime = '2021-03-07' 92 | ,@RecentEndTime = '2021-03-08' 93 | ,@HistoryStartTime = '2021-03-01' 94 | ,@HistoryEndTime = '2021-03-07' 95 | ,@IncludeQueryText = 1 96 | ,@ExcludeAdhoc = 0 97 | ,@ExcludeInternal = 0 98 | ,@ReportID = @ReportID OUTPUT 99 | INSERT INTO @ReportList VALUES (@ReportID) 100 | 101 | EXECUTE [dbo].[WaitsVariation] 102 | @DatabaseName = 'QDSToolBox' 103 | ,@ReportIndex = '[dbo].[WaitsVariationIndex]' 104 | ,@ReportTable = '[dbo].[WaitsVariationStore]' 105 | ,@WaitType = @Measurement 106 | ,@Metric = 'Avg' 107 | ,@VariationType = NULL 108 | ,@ResultsRowCount = 1 109 | ,@RecentStartTime = '2021-03-07' 110 | ,@RecentEndTime = '2021-03-08' 111 | ,@HistoryStartTime = '2021-03-01' 112 | ,@HistoryEndTime = '2021-03-07' 113 | ,@IncludeQueryText = 1 114 | ,@ExcludeAdhoc = 0 115 | ,@ExcludeInternal = 0 116 | ,@ReportID = @ReportID OUTPUT 117 | INSERT INTO @ReportList VALUES (@ReportID) 118 | 119 | FETCH NEXT FROM [Measurement_Cursor] INTO @Measurement 120 | END 121 | 122 | CLOSE [Measurement_Cursor] 123 | DEALLOCATE [Measurement_Cursor] 124 | 125 | DELETE [i] 126 | FROM [dbo].[WaitsVariationIndex] [i] 127 | INNER JOIN @ReportList [r] 128 | ON [i].[ReportID] = [r].[ReportID] 129 | 130 | DELETE [s] 131 | FROM [dbo].[WaitsVariationStore] [s] 132 | INNER JOIN @ReportList [r] 133 | ON [s].[ReportID] = [r].[ReportID] -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | APPENDIX: How to apply the Apache License to your work. 179 | 180 | To apply the Apache License to your work, attach the following 181 | boilerplate notice, with the fields enclosed by brackets "[]" 182 | replaced with your own identifying information. (Don't include 183 | the brackets!) The text should be enclosed in the appropriate 184 | comment syntax for the file format. We also recommend that a 185 | file or class name and description of purpose be included on the 186 | same "printed page" as the copyright notice for easier 187 | identification within third-party archives. 188 | 189 | Copyright [20] [ChannelAdvisor] 190 | 191 | Licensed under the Apache License, Version 2.0 (the "License"); 192 | you may not use this file except in compliance with the License. 193 | You may obtain a copy of the License at 194 | 195 | http://www.apache.org/licenses/LICENSE-2.0 196 | 197 | Unless required by applicable law or agreed to in writing, software 198 | distributed under the License is distributed on an "AS IS" BASIS, 199 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 200 | See the License for the specific language governing permissions and 201 | limitations under the License. 202 | -------------------------------------------------------------------------------- /PivotedWaitStats/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /PivotedWaitStats/1-dbo.query_store_wait_stats_pivoted.View.sql: -------------------------------------------------------------------------------- 1 | SET ANSI_NULLS ON 2 | GO 3 | 4 | SET QUOTED_IDENTIFIER ON 5 | GO 6 | 7 | ---------------------------------------------------------------------------------- 8 | -- View Name: [dbo].[query_store_wait_stats_pivoted] 9 | -- 10 | -- Desc: This view pivots the contents of the sys.query_store_wait_stats into columns, adding the average wait stats metric to it 11 | -- 12 | -- 13 | -- Date: 2020.10.22 14 | -- Auth: Pablo Lozano (@sqlozano) 15 | -- 16 | -- Date: 2021.02.28 17 | -- Auth: Pablo Lozano (@sqlozano) 18 | -- Changes: This view is not compatible with SQL 2016 (no wait stats captured before SQL 2017), so this script will raise an error 19 | ---------------------------------------------------------------------------------- 20 | 21 | -- Get the Version # to ensure it runs SQL2016 or higher 22 | DECLARE @Version INT = CAST(SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0,CHARINDEX('.',CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),0)) AS INT) 23 | IF (@Version < 14) 24 | BEGIN 25 | RAISERROR('[dbo].[query_store_wait_stats_pivoted] requires SQL 2017 or higher',16,1) 26 | END 27 | ELSE 28 | BEGIN 29 | DECLARE @CreateView NVARCHAR(MAX) = 30 | 'CREATE OR ALTER VIEW [dbo].[query_store_wait_stats_pivoted] 31 | AS 32 | SELECT 33 | [runtime_stats_interval_id] 34 | ,[plan_id] 35 | ,[count_executions] 36 | ,ISNULL([Unknown],0) AS [Total_Unknown] 37 | ,ISNULL(ROUND(CONVERT(float,[Unknown]*1.00/[count_executions]),2) , 0) AS [Average_Unknown] 38 | ,ISNULL([CPU],0) AS [Total_CPU] 39 | ,ISNULL(ROUND(CONVERT(float,[CPU]*1.00/[count_executions]),2) , 0) AS [Average_CPU] 40 | ,ISNULL([Worker Thread],0) AS [Total_WorkerThread] 41 | ,ISNULL(ROUND(CONVERT(float,[Worker Thread]*1.00/[count_executions]),2) , 0) AS [Average_WorkerThread] 42 | ,ISNULL([Lock],0) AS [Total_Lock] 43 | ,ISNULL(ROUND(CONVERT(float,[Lock]*1.00/[count_executions]),2) , 0) AS [Average_Lock] 44 | ,ISNULL([Latch],0) AS [Total_Latch] 45 | ,ISNULL(ROUND(CONVERT(float,[Latch]*1.00/[count_executions]),2) , 0) AS [Average_Latch] 46 | ,ISNULL([Buffer Latch],0) AS [Total_BufferLatch] 47 | ,ISNULL(ROUND(CONVERT(float,[Buffer Latch]*1.00/[count_executions]),2) , 0) AS [Average_BufferLatch] 48 | ,ISNULL([Buffer IO],0) AS [Total_BufferIO] 49 | ,ISNULL(ROUND(CONVERT(float,[Buffer IO]*1.00/[count_executions]),2) , 0) AS [Average_BufferIO] 50 | ,ISNULL([Compilation],0) AS [Total_Compilation] 51 | ,ISNULL(ROUND(CONVERT(float,[Compilation]*1.00/[count_executions]),2) , 0) AS [Average_Compilation] 52 | ,ISNULL([SQL CLR],0) AS [Total_SQLCLR] 53 | ,ISNULL(ROUND(CONVERT(float,[SQL CLR]*1.00/[count_executions]),2) , 0) AS [Average_SQLCLR] 54 | ,ISNULL([Mirroring],0) AS [Total_Mirroring] 55 | ,ISNULL(ROUND(CONVERT(float,[Mirroring]*1.00/[count_executions]),2) , 0) AS [Average_Mirroring] 56 | ,ISNULL([Transaction],0) AS [Total_Transaction] 57 | ,ISNULL(ROUND(CONVERT(float,[Transaction]*1.00/[count_executions]),2) , 0) AS [Average_Transaction] 58 | ,ISNULL([Idle],0) AS [Total_Idle] 59 | ,ISNULL(ROUND(CONVERT(float,[Idle]*1.00/[count_executions]),2) , 0) AS [Average_Idle] 60 | ,ISNULL([Preemptive],0) AS [Total_Preemptive] 61 | ,ISNULL(ROUND(CONVERT(float,[Preemptive]*1.00/[count_executions]),2) , 0) AS [Average_Preemptive] 62 | ,ISNULL([Service Broker],0) AS [Total_ServiceBroker] 63 | ,ISNULL(ROUND(CONVERT(float,[Service Broker]*1.00/[count_executions]),2) , 0) AS [Average_ServiceBroker] 64 | ,ISNULL([Tran Log IO],0) AS [Total_TranLogIO] 65 | ,ISNULL(ROUND(CONVERT(float,[Tran Log IO]*1.00/[count_executions]),2) , 0) AS [Average_TranLogIO] 66 | ,ISNULL([Network IO],0) AS [Total_NetworkIO] 67 | ,ISNULL(ROUND(CONVERT(float,[Network IO]*1.00/[count_executions]),2) , 0) AS [Average_NetworkIO] 68 | ,ISNULL([Parallelism],0) AS [Total_Parallelism] 69 | ,ISNULL(ROUND(CONVERT(float,[Parallelism]*1.00/[count_executions]),2) , 0) AS [Average_Parallelism] 70 | ,ISNULL([Memory],0) AS [Total_Memory] 71 | ,ISNULL(ROUND(CONVERT(float,[Memory]*1.00/[count_executions]),2) , 0) AS [Average_Memory] 72 | ,ISNULL([User Wait],0) AS [Total_UserWait] 73 | ,ISNULL(ROUND(CONVERT(float,[User Wait]*1.00/[count_executions]),2) , 0) AS [Average_UserWait] 74 | ,ISNULL([Tracing],0) AS [Total_Tracing] 75 | ,ISNULL(ROUND(CONVERT(float,[Tracing]*1.00/[count_executions]),2) , 0) AS [Average_Tracing] 76 | ,ISNULL([Full Text Search],0) AS [Total_FullTextSearch] 77 | ,ISNULL(ROUND(CONVERT(float,[Full Text Search]*1.00/[count_executions]),2) , 0) AS [Average_FullTextSearch] 78 | ,ISNULL([Other Disk IO],0) AS [Total_OtherDiskIO] 79 | ,ISNULL(ROUND(CONVERT(float,[Other Disk IO]*1.00/[count_executions]),2) , 0) AS [Average_OtherDiskIO] 80 | ,ISNULL([Replication],0) AS [Total_Replication] 81 | ,ISNULL(ROUND(CONVERT(float,[Replication]*1.00/[count_executions]),2) , 0) AS [Average_Replication] 82 | ,ISNULL([Log Rate Governor],0) AS [Total_LogRateGovernor] 83 | ,ISNULL(ROUND(CONVERT(float,[Log Rate Governor]*1.00/[count_executions]),2) , 0) AS [Average_LogRateGovernor] 84 | FROM 85 | ( 86 | SELECT 87 | [qsws].[runtime_stats_interval_id] 88 | ,[qsws].[plan_id] 89 | ,[qsrs].[count_executions] 90 | ,[qsws].[wait_category_desc] 91 | ,[qsws].[total_query_wait_time_ms] 92 | FROM [sys].[query_store_wait_stats] [qsws] 93 | INNER JOIN [sys].[query_store_runtime_stats] [qsrs] 94 | ON [qsws].[runtime_stats_interval_id] = [qsrs].[runtime_stats_interval_id] 95 | AND [qsws].[plan_id] = [qsrs].[plan_id] 96 | ) as [SourceTable] 97 | PIVOT ( 98 | SUM([total_query_wait_time_ms]) 99 | FOR [wait_category_desc] IN 100 | ( 101 | [Unknown] 102 | ,[CPU] 103 | ,[Worker Thread] 104 | ,[Lock] 105 | ,[Latch] 106 | ,[Buffer Latch] 107 | ,[Buffer IO] 108 | ,[Compilation] 109 | ,[SQL CLR] 110 | ,[Mirroring] 111 | ,[Transaction] 112 | ,[Idle] 113 | ,[Preemptive] 114 | ,[Service Broker] 115 | ,[Tran Log IO] 116 | ,[Network IO] 117 | ,[Parallelism] 118 | ,[Memory] 119 | ,[User Wait] 120 | ,[Tracing] 121 | ,[Full Text Search] 122 | ,[Other Disk IO] 123 | ,[Replication] 124 | ,[Log Rate Governor] 125 | ) 126 | ) 127 | AS [PivotTable]' 128 | 129 | EXECUTE (@CreateView) 130 | END -------------------------------------------------------------------------------- /PivotedWaitStats/README.md: -------------------------------------------------------------------------------- 1 | # PivotedWaitStats 2 | The design of the sys.query_store_wait_stats differs from sys.query_store_runtime_stats , by having on row for each wait type, per plan, per runtime stats interval. This reduces the space requirements since most plans will have no wait times, or only a few types of them, but makes it difficult to compare it with the runtime stats.\ 3 | This view pivots the different rows into Total & Average columns for each wait type. 4 | \ 5 | (Supported in SQL 2017+: for SQL 2016 the view will not be created) -------------------------------------------------------------------------------- /PlanMiner/00-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /PlanMiner/01-dbo.PlanMiner_PlanList.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_PlanList] 3 | -- 4 | -- Desc: This table contains the list plans mined, and the details on where it was mined from 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [MiningType] NVARCHAR(16) NULL 11 | -- Description on where the plan was mined from: 12 | -- QueryStore 13 | -- Cache 14 | -- File 15 | -- 16 | -- [InstanceIdentifier] SYSNAME NULL 17 | -- Identifier of the instance, so if this data is centralized reports originated on each server can be properly identified 18 | -- 19 | -- [DatabaseName] SYSNAME NULL 20 | -- Name of the database this plan's information has been mined out 21 | -- 22 | -- [PlanID] BIGINT NULL 23 | -- Identifier of the plan this information has been mined out 24 | -- 25 | -- [PlanHandle] VARBINARY(64) NULL 26 | -- Handle of the plan mined 27 | -- 28 | -- [CompressedPlan] VARBINARY(MAX) NULL 29 | -- Plan mined, in a compressed format 30 | -- 31 | -- Notes: 32 | -- 33 | -- 34 | -- Date: 2021.05.08 35 | -- Auth: Pablo Lozano (@sqlozano) 36 | -- 37 | ---------------------------------------------------------------------------------- 38 | 39 | DROP TABLE IF EXISTS [dbo].[PlanMiner_PlanList] 40 | CREATE TABLE [dbo].[PlanMiner_PlanList] 41 | ( 42 | [PlanMinerID] BIGINT IDENTITY(1,1) 43 | ,[MiningType] NVARCHAR(16) NULL 44 | ,[InstanceIdentifier] SYSNAME NULL 45 | ,[DatabaseName] SYSNAME NULL 46 | ,[PlanID] BIGINT NULL 47 | ,[PlanHandle] VARBINARY(64) NULL 48 | ,[PlanFile] NVARCHAR(MAX) NULL 49 | ,[CompressedPlan] VARBINARY(MAX) NULL 50 | ) 51 | CREATE CLUSTERED INDEX [CIX_PlanMiner_Columns] ON [dbo].[PlanMiner_PlanList] 52 | ( 53 | [PlanMinerID] ASC 54 | ) -------------------------------------------------------------------------------- /PlanMiner/02-dbo.vPlanMiner_PlanList.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vPlanMiner_PlanList] 3 | -- 4 | -- Desc: This view is build on top of [dbo].[PlanMiner_PlanList] to extract the index of the execution plans processed by [dbo].[PlanMiner] 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [MiningType] NVARCHAR(16) NULL 11 | -- Description on where the plan was mined from: 12 | -- QueryStore 13 | -- Cache 14 | -- File 15 | -- 16 | -- [InstanceIdentifier] SYSNAME NULL 17 | -- Identifier of the instance, so if this data is centralized reports originated on each server can be properly identified 18 | -- 19 | -- [DatabaseName] SYSNAME NULL 20 | -- Name of the database this plan's information has been mined out 21 | -- 22 | -- [PlanID] BIGINT NULL 23 | -- Identifier of the plan this information has been mined out 24 | -- 25 | -- [PlanHandle] VARBINARY(64) NULL 26 | -- Handle of the plan mined 27 | -- 28 | -- [ExecutionPlan] XML NULL 29 | -- Plan mined, decompressed and presented in XML format 30 | -- 31 | -- Notes: 32 | -- 33 | -- 34 | -- Date: 2021.05.08 35 | -- Auth: Pablo Lozano (@sqlozano) 36 | -- 37 | ---------------------------------------------------------------------------------- 38 | CREATE OR ALTER VIEW [dbo].[vPlanMiner_PlanList] 39 | AS 40 | SELECT 41 | [PlanMinerID] 42 | ,[MiningType] 43 | ,[InstanceIdentifier] 44 | ,[DatabaseName] 45 | ,[PlanID] 46 | ,[PlanHandle] 47 | ,[PlanFile] 48 | ,TRY_CONVERT(XML, DECOMPRESS([CompressedPlan])) AS [ExecutionPlan] 49 | FROM [dbo].[PlanMiner_PlanList] -------------------------------------------------------------------------------- /PlanMiner/03-dbo.PlanMiner_Statements.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_Statements] 3 | -- 4 | -- Desc: This table contains information regarding the statements included in the mined plan 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [StatementID] INT NOT NULL 11 | -- Unique identifier of the statement within the execution plan 12 | -- 13 | -- [StatementCategory] NVARCHAR(128) NULL 14 | -- Type of category (Simple, Conditional, Cursor...) 15 | -- 16 | -- [StatementType] NVARCHAR(128) NULL 17 | -- Type of statement (CREATE TABLE, SELECT, ASSIGN...) 18 | -- 19 | -- [CompressedText] VARBINARY(MAX) NULL 20 | -- Actual statement (compressed) 21 | -- 22 | -- Notes: 23 | -- 24 | -- 25 | -- Date: 2021.05.08 26 | -- Auth: Pablo Lozano (@sqlozano) 27 | -- 28 | ---------------------------------------------------------------------------------- 29 | 30 | DROP TABLE IF EXISTS [dbo].[PlanMiner_Statements] 31 | CREATE TABLE [dbo].[PlanMiner_Statements] 32 | ( 33 | [PlanMinerID] BIGINT NOT NULL 34 | ,[StatementID] INT NOT NULL 35 | ,[StatementCategory] NVARCHAR(128) NOT NULL 36 | ,[StatementType] NVARCHAR(128) NOT NULL 37 | ,[CompressedText] VARBINARY(MAX) NULL 38 | ) 39 | CREATE CLUSTERED INDEX [CIX_PlanMiner_Statements] ON [dbo].[PlanMiner_Statements] 40 | ( 41 | [PlanMinerID] ASC 42 | ,[StatementID] ASC 43 | ) -------------------------------------------------------------------------------- /PlanMiner/04-dbo.vPlanMiner_Statements.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vPlanMiner_Statements] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[vPlanMiner_Statements] to extract the statements' text uncompressed 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [StatementID] INT NOT NULL 11 | -- Unique identifier of the statement within the execution plan 12 | -- 13 | -- [StatementCategory] NVARCHAR(128) NULL 14 | -- Type of category (Simple, Conditional, Cursor...) 15 | -- 16 | -- [StatementType] NVARCHAR(128) NULL 17 | -- Type of statement (CREATE TABLE, SELECT, ASSIGN...) 18 | -- 19 | -- [StatementText] NVARCHAR(MAX) NULL 20 | -- Actual statement (compressed) 21 | -- 22 | -- Notes: 23 | -- 24 | -- 25 | -- Date: 2021.05.08 26 | -- Auth: Pablo Lozano (@sqlozano) 27 | -- 28 | ---------------------------------------------------------------------------------- 29 | CREATE OR ALTER VIEW [dbo].[vPlanMiner_Statements] 30 | AS 31 | SELECT 32 | [PlanMinerID] 33 | ,[StatementID] 34 | ,[StatementCategory] 35 | ,[StatementType] 36 | ,CAST(DECOMPRESS([CompressedText]) AS NVARCHAR(MAX)) AS [StatementText] 37 | FROM [dbo].[PlanMiner_Statements] -------------------------------------------------------------------------------- /PlanMiner/05-dbo.PlanMiner_IndexOperations.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_IndexOperations] 3 | -- 4 | -- Desc: This table contains information about the index operations (scan, seek, update, delete...) performed in 5 | -- an operation (node) in the execution plan mined out 6 | -- 7 | -- Columns: 8 | -- [PlanMinerID] BIGINT NOT NULL 9 | -- Unique identifier of the mined plan 10 | -- 11 | -- [StatementID] INT NOT NULL 12 | -- Identifier of the statement the index operation is performed on 13 | -- 14 | -- [NodeID] INT NOT NULL 15 | -- Identifier of the operation (node) this index operation takes place 16 | -- 17 | -- [DatabaseNamePlan] NVARCHAR(128) NULL 18 | -- Name of the database the index belongs to 19 | -- 20 | -- [SchemaName] NVARCHAR(128) NULL 21 | -- Name of the schema the index belongs to 22 | -- 23 | -- [TableName] NVARCHAR(128) NULL 24 | -- Name of the table the index belongs to 25 | -- 26 | -- [IndexName] NVARCHAR(128) NULL 27 | -- Name of the index used in this operation (node) 28 | -- 29 | -- [IndexKind] NVARCHAR(128) NULL 30 | -- Type of index 31 | -- 32 | -- [Lookup] BIT NULL 33 | -- Flag to define whether the operation involves a Key Lookup 34 | -- 35 | -- [Ordered] BIT NULL 36 | -- Flag to define whether the index ordering 37 | -- 38 | -- [LogicalOp] NVARCHAR(128) NULL 39 | -- Local operation performed in the operation (node) 40 | -- 41 | -- [ForcedIndex] BIT NULL 42 | -- Flag to determine whether this index was forced 43 | -- 44 | -- [ForceSeek] BIT NULL 45 | -- Flag to determine whether this index operation is a forced seek one 46 | -- 47 | -- [ForceScan] BIT NULL 48 | -- Flag to determine whether this index operation is a forced scan one 49 | -- 50 | -- [NoExpandHint] BIT NULL 51 | -- Flag to determine whether the NOEXPAND hint was used 52 | -- 53 | -- [Storage] NVARCHAR(128) NULL 54 | -- 55 | -- Notes: 56 | -- When using table variables or temp tables, [SchemaName] and [TableName] will contain NULL values 57 | -- 58 | -- Date: 2021.05.08 59 | -- Auth: Pablo Lozano (@sqlozano) 60 | -- 61 | -- Date: 2022.06.14 62 | -- Auth: Pablo Lozano (@sqlozano) 63 | -- Added flag for KeyLoopup operations 64 | ---------------------------------------------------------------------------------- 65 | 66 | DROP TABLE IF EXISTS [dbo].[PlanMiner_IndexOperations] 67 | CREATE TABLE [dbo].[PlanMiner_IndexOperations] 68 | ( 69 | [PlanMinerID] BIGINT NOT NULL 70 | ,[StatementID] INT NOT NULL 71 | ,[NodeID] INT NOT NULL 72 | ,[DatabaseNamePlan] NVARCHAR(128) NULL 73 | ,[SchemaName] NVARCHAR(128) NULL 74 | ,[TableName] NVARCHAR(128) NULL 75 | ,[IndexName] NVARCHAR(128) NULL 76 | ,[IndexKind] NVARCHAR(128) NULL 77 | ,[LogicalOp] NVARCHAR(128) NOT NULL 78 | ,[Lookup] BIT NULL 79 | ,[Ordered] BIT NULL 80 | ,[ForcedIndex] BIT NULL 81 | ,[ForceSeek] BIT NULL 82 | ,[ForceScan] BIT NULL 83 | ,[NoExpandHint] BIT NULL 84 | ,[Storage] NVARCHAR(128) NULL 85 | ) 86 | ALTER TABLE [dbo].[PlanMiner_IndexOperations] ADD CONSTRAINT [PK_PlanMiner_IndexOperations] PRIMARY KEY CLUSTERED 87 | ( 88 | [PlanMinerID] ASC 89 | ,[StatementID] ASC 90 | ,[NodeID] ASC 91 | ,[LogicalOp] ASC 92 | ) -------------------------------------------------------------------------------- /PlanMiner/06-dbo.PlanMiner_MissingIndexes.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_MissingIndexes] 3 | -- 4 | -- Desc: This table contains all the details of the indexes the SQL engine consideres could improve its performance 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [StatementID] INT NOT NULL 11 | -- Identifier of the statement the missing index was identified for 12 | -- 13 | -- [MissingIndexID] INT NOT NULL 14 | -- Identifier of the missing index (generated by SQL Engine itself) 15 | -- 16 | -- [Impact] FLOAT NULL 17 | -- Estimated impact of the missing index 18 | -- 19 | -- [DatabaseNamePlan] NVARCHAR(128) NULL 20 | -- Name of the database where the index should be created 21 | -- 22 | -- [SchemaName] NVARCHAR(128) NULL 23 | -- Name of the schema where the index should be created 24 | -- 25 | -- [TableName] NVARCHAR(128) NULL 26 | -- Name of the table where the index should be created 27 | -- 28 | -- [Usage] NVARCHAR(128) NULL 29 | -- 30 | -- 31 | -- [ColumnName] NVARCHAR(128) NULL 32 | -- Name of the column to be included in the index 33 | -- 34 | -- Notes: 35 | -- When using table variables or temp tables, [SchemaName] and [TableName] will contain NULL values 36 | -- 37 | -- Date: 2021.05.08 38 | -- Auth: Pablo Lozano (@sqlozano) 39 | -- 40 | ---------------------------------------------------------------------------------- 41 | 42 | DROP TABLE IF EXISTS [dbo].[PlanMiner_MissingIndexes] 43 | CREATE TABLE [dbo].[PlanMiner_MissingIndexes] 44 | ( 45 | [PlanMinerID] BIGINT NOT NULL 46 | ,[StatementID] INT NOT NULL 47 | ,[MissingIndexID] INT NOT NULL 48 | ,[Impact] FLOAT NULL 49 | ,[DatabaseNamePlan] NVARCHAR(128) NULL 50 | ,[SchemaName] NVARCHAR(128) NULL 51 | ,[TableName] NVARCHAR(128) NULL 52 | ,[Usage] NVARCHAR(128) NULL 53 | ,[ColumnName] NVARCHAR(128) NULL 54 | ) 55 | CREATE CLUSTERED INDEX [CIX_PlanMiner_MissingIndexes] ON [dbo].[PlanMiner_MissingIndexes] 56 | ( 57 | [PlanMinerID] ASC 58 | ,[StatementID] ASC 59 | ,[MissingIndexID] ASC 60 | ) 61 | -------------------------------------------------------------------------------- /PlanMiner/07-dbo.PlanMiner_UnmatchedIndexes.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_UnmatchedIndexes] 3 | -- 4 | -- Desc: This table contains information about the filtered indexes not used due to the parameters in the WHERE clause 5 | -- not matching those in the indexes 6 | -- 7 | -- Columns: 8 | -- [PlanMinerID] BIGINT NOT NULL 9 | -- Unique identifier of the mined plan 10 | -- 11 | -- [StatementID] INT NOT NULL 12 | -- Identifier of the statement the unmatched index was identified for 13 | -- 14 | -- [DatabaseNamePlan] NVARCHAR(128) NULL 15 | -- Name of the database where the unmatched index is found 16 | -- 17 | -- [SchemaName] NVARCHAR(128) NULL 18 | -- Name of the schema where the unmatched index is found 19 | -- 20 | -- [TableName] NVARCHAR(128) NULL 21 | -- Name of the table where the unmatched index is found 22 | -- 23 | -- [UnmatchedIndexName] NVARCHAR(128) NULL 24 | -- Name of the index not used due to it not matching the specific parameters used in the WHERE clause 25 | -- 26 | -- Date: 2021.05.08 27 | -- Auth: Pablo Lozano (@sqlozano) 28 | -- 29 | ---------------------------------------------------------------------------------- 30 | 31 | DROP TABLE IF EXISTS [dbo].[PlanMiner_UnmatchedIndexes] 32 | CREATE TABLE [dbo].[PlanMiner_UnmatchedIndexes] 33 | ( 34 | [PlanMinerID] BIGINT NOT NULL 35 | ,[StatementID] INT NOT NULL 36 | ,[DatabaseNamePlan] NVARCHAR(128) NULL 37 | ,[SchemaName] NVARCHAR(128) NULL 38 | ,[TableName] NVARCHAR(128) NULL 39 | ,[UnmatchedIndexName] NVARCHAR(128) NULL 40 | ) 41 | CREATE CLUSTERED INDEX [CIX_PlanMiner_UnmatchedIndexes] ON [dbo].[PlanMiner_UnmatchedIndexes] 42 | ( 43 | [PlanMinerID] ASC 44 | ,[StatementID] ASC 45 | ) 46 | -------------------------------------------------------------------------------- /PlanMiner/08-dbo.PlanMiner_Cursors.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_Columns] 3 | -- 4 | -- Desc: This table contains information about the cursor found in the execution plan 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [StatementID] INT NOT NULL 11 | -- Identifier of the statement within the plan the cursor is used in 12 | -- 13 | -- [CursorName] NVARCHAR(128) NULL 14 | -- Name of the cursor 15 | --- 16 | -- [CursorActualType] NVARCHAR(128) NULL 17 | -- Type of cursor generated 18 | -- 19 | -- [CursorRequestedType] NVARCHAR(128) NULL 20 | -- Type of cursor requested by the query 21 | -- 22 | -- [CursorConcurrency] NVARCHAR(128) NULL 23 | -- Concurrency of the cursor 24 | -- 25 | -- [ForwardOnly] BIT NULL 26 | -- Flag to indicate whether the cursor was FORWARD_ONLY 27 | -- 28 | -- Date: 2021.05.08 29 | -- Auth: Pablo Lozano (@sqlozano) 30 | -- 31 | -- Date: 2021.11.16 32 | -- Auth: Pablo Lozano (@sqlozano) 33 | -- Note: Added [StatementID] column missing in the table definition 34 | -- https://github.com/channeladvisor/qdstoolbox/issues/23 35 | ---------------------------------------------------------------------------------- 36 | 37 | DROP TABLE IF EXISTS [dbo].[PlanMiner_Cursors] 38 | CREATE TABLE [dbo].[PlanMiner_Cursors] 39 | ( 40 | [PlanMinerID] BIGINT NOT NULL 41 | ,[StatementID] INT NOT NULL 42 | ,[CursorName] NVARCHAR(128) NULL 43 | ,[CursorActualType] NVARCHAR(128) NULL 44 | ,[CursorRequestedType] NVARCHAR(128) NULL 45 | ,[CursorConcurrency] NVARCHAR(128) NULL 46 | ,[ForwardOnly] BIT NULL 47 | ) 48 | ALTER TABLE [dbo].[PlanMiner_Cursors] ADD CONSTRAINT [PK_PlanMiner_Cursors] PRIMARY KEY CLUSTERED 49 | ( 50 | [PlanMinerID] ASC 51 | ) -------------------------------------------------------------------------------- /PlanMiner/09-dbo.PlanMiner_Statistics.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_Statistics] 3 | -- 4 | -- Desc: This table contains the list of statistics used by the SQL Engine to elaborate this execution plan 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [StatementID] INT NOT NULL 11 | -- Identifier of the statement that required the analysis of this statistics 12 | -- 13 | -- [DatabaseNamePlan] NVARCHAR(128) NULL 14 | -- Name of the database the used statistics column belongs to (when applicable) 15 | -- 16 | -- [SchemaName] NVARCHAR(128) NULL 17 | -- Name of the schema the used statistics column belongs to (when applicable) 18 | -- 19 | -- [TableName] NVARCHAR(128) NULL 20 | -- Name of the table the used statistics column belongs to (when applicable) 21 | -- 22 | -- [ColumnName] NVARCHAR(128) NULL 23 | -- Name of the column statistics used for the calculations 24 | -- 25 | -- [ModificationCount] BIGINT NULL 26 | -- Number of modified rows since the statistics were last updated 27 | -- 28 | -- [SamplingPercent] FLOAT NULL 29 | -- Percent of rows used for the sampling of the statistics in their last update 30 | -- 31 | -- [LastUpdate] DATETIME2(7) NULL 32 | -- Last time an update of the statistcs tooks place 33 | -- 34 | -- Notes: 35 | -- When using table variables, [SchemaName] and [TableName] will contain NULL values 36 | -- 37 | -- Date: 2021.05.08 38 | -- Auth: Pablo Lozano (@sqlozano) 39 | -- 40 | ---------------------------------------------------------------------------------- 41 | 42 | DROP TABLE IF EXISTS [dbo].[PlanMiner_Statistics] 43 | CREATE TABLE [dbo].[PlanMiner_Statistics] 44 | ( 45 | [PlanMinerID] BIGINT NOT NULL 46 | ,[StatementID] INT NOT NULL 47 | ,[DatabaseNamePlan] NVARCHAR(128) NULL 48 | ,[SchemaName] NVARCHAR(128) NULL 49 | ,[TableName] NVARCHAR(128) NULL 50 | ,[StatisticName] NVARCHAR(128) NULL 51 | ,[ModificationCount] BIGINT NULL 52 | ,[SamplingPercent] FLOAT NULL 53 | ,[LastUpdate] DATETIME2(7) NULL 54 | ) 55 | CREATE CLUSTERED INDEX [CIX_PlanMiner_Statistics] ON [dbo].[PlanMiner_Statistics] 56 | ( 57 | [PlanMinerID] ASC 58 | ) 59 | CREATE NONCLUSTERED INDEX [NCIX_PlanMiner_Statistics] ON [dbo].[PlanMiner_Statistics] 60 | ( 61 | [PlanMinerID] ASC 62 | ,[StatementID] ASC 63 | ,[DatabaseNamePlan] ASC 64 | ,[SchemaName] ASC 65 | ,[TableName] ASC 66 | ) -------------------------------------------------------------------------------- /PlanMiner/10-dbo.PlanMiner_Nodes.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_Nodes] 3 | -- 4 | -- Desc: This table contains the details of each node (operation) of the execution plan 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [StatementID] INT NOT NULL 11 | -- Unique identifier of the statement the nodes are members of 12 | -- 13 | -- [NodeID] INT NOT NULL 14 | -- Identifier of the node of the execution plan whose details are described 15 | -- 16 | -- [Depth] INT NOT NULL 17 | -- Depth of the node in the complete plan 18 | -- 19 | -- [CursorOperationType] NVARCHAR(16) NOT NULL 20 | -- Type of cursor operation being executed (when applicable) 21 | -- 22 | -- [PhysicalOp] NVARCHAR(128) NOT NULL 23 | -- Physical operation performed in the node 24 | -- 25 | -- [LogicalOp] NVARCHAR(128) NOT NULL 26 | -- Logical operation performed in the node 27 | -- 28 | -- [EstimateRows] FLOAT NOT NULL 29 | -- Estimated rows accessed in the node (read/write) 30 | -- 31 | -- [EstimatedRowsRead] FLOAT NULL 32 | -- Estimated rows read in the node (when applicable) 33 | -- 34 | -- [EstimateIO] FLOAT NOT NULL 35 | -- Estimated IO cost of the node's activity 36 | -- 37 | -- [EstimateCPU] FLOAT NOT NULL 38 | -- Estimated CPU cost of the node's activity 39 | -- 40 | -- [AvgRowSize] FLOAT NOT NULL 41 | -- Average size of the row accessed in the node's activity (when applicable) 42 | -- 43 | -- [EstimatedTotalSubtreeCost] FLOAT NOT NULL 44 | -- Estimated total cost of this node's subtree 45 | -- 46 | -- [TableCardinality] FLOAT NULL 47 | -- Cardinality of the table accessed in this node's activity (when applicable) 48 | -- 49 | -- [Parallel] BIT NULL 50 | -- Flag to indicate whether this node's activity was performed in parallel 51 | -- 52 | -- [EstimateRebinds] FLOAT NOT NULL 53 | -- Estimated rebinds to be executed in this node's activity (when applicable) 54 | -- 55 | -- [EstimateRewinds] FLOAT NOT NULL 56 | -- Estimated rewinds to be executed in this node's activity (when applicable) 57 | -- 58 | -- [EstimatedExecutionMode] NVARCHAR(128) NOT NULL 59 | -- Estimated execution mode used for this node's activity 60 | -- 61 | -- 62 | -- Date: 2021.05.08 63 | -- Auth: Pablo Lozano (@sqlozano) 64 | -- 65 | ---------------------------------------------------------------------------------- 66 | 67 | DROP TABLE IF EXISTS [dbo].[PlanMiner_Nodes] 68 | CREATE TABLE [dbo].[PlanMiner_Nodes] 69 | ( 70 | [PlanMinerID] BIGINT NOT NULL 71 | ,[StatementID] INT NOT NULL 72 | ,[NodeID] INT NOT NULL 73 | ,[Depth] INT NOT NULL 74 | ,[CursorOperationType] NVARCHAR(128) NOT NULL 75 | ,[PhysicalOp] NVARCHAR(128) NOT NULL 76 | ,[LogicalOp] NVARCHAR(128) NOT NULL 77 | ,[EstimateRows] FLOAT NOT NULL 78 | ,[EstimatedRowsRead] FLOAT NULL 79 | ,[EstimateIO] FLOAT NOT NULL 80 | ,[EstimateCPU] FLOAT NOT NULL 81 | ,[AvgRowSize] FLOAT NOT NULL 82 | ,[EstimatedTotalSubtreeCost] FLOAT NOT NULL 83 | ,[TableCardinality] FLOAT NULL 84 | ,[Parallel] FLOAT NOT NULL 85 | ,[EstimateRebinds] FLOAT NOT NULL 86 | ,[EstimateRewinds] FLOAT NOT NULL 87 | ,[EstimatedExecutionMode] NVARCHAR(128) NOT NULL 88 | ) 89 | ALTER TABLE [dbo].[PlanMiner_Nodes] ADD CONSTRAINT [PK_PlanMiner_Nodes] PRIMARY KEY CLUSTERED 90 | ( 91 | [PlanMinerID] ASC 92 | ,[StatementID] ASC 93 | ,[NodeID] ASC 94 | ,[CursorOperationType] ASC 95 | ) -------------------------------------------------------------------------------- /PlanMiner/11-dbo.PlanMiner_Columns.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[PlanMiner_Columns] 3 | -- 4 | -- Desc: This table contains the list of columns accessed with a certain execution plan on each of its operations (nodes) 5 | -- 6 | -- Columns: 7 | -- [PlanMinerID] BIGINT NOT NULL 8 | -- Unique identifier of the mined plan 9 | -- 10 | -- [StatementID] INT NOT NULL 11 | -- Identifier of the statement that accessed the columns 12 | -- 13 | -- [NodeID] INT NOT NULL 14 | -- Node of the execution plan the columns are accessed in 15 | -- 16 | -- [DatabaseNamePlan] NVARCHAR(128) NULL 17 | -- Name of the database the accessed column belongs to (when applicable) 18 | -- 19 | -- [SchemaName] NVARCHAR(128) NULL 20 | -- Name of the schema the accessed column belongs to (when applicable) 21 | -- 22 | -- [TableName] NVARCHAR(128) NULL 23 | -- Name of the table the accessed column belongs to (when applicable) 24 | -- 25 | -- [ColumnName] NVARCHAR(128) NULL 26 | -- Name of the column accessed 27 | -- 28 | -- Notes: 29 | -- When using table variables, [SchemaName] and [TableName] will contain NULL values 30 | -- 31 | -- Date: 2021.05.08 32 | -- Auth: Pablo Lozano (@sqlozano) 33 | -- 34 | ---------------------------------------------------------------------------------- 35 | 36 | DROP TABLE IF EXISTS [dbo].[PlanMiner_Columns] 37 | CREATE TABLE [dbo].[PlanMiner_Columns] 38 | ( 39 | [PlanMinerID] BIGINT NOT NULL 40 | ,[StatementID] INT NOT NULL 41 | ,[NodeID] INT NOT NULL 42 | ,[DatabaseNamePlan] NVARCHAR(128) NULL 43 | ,[SchemaName] NVARCHAR(128) NULL 44 | ,[TableName] NVARCHAR(128) NULL 45 | ,[ColumnName] NVARCHAR(128) NOT NULL 46 | ) 47 | CREATE CLUSTERED INDEX [CIX_PlanMiner_Columns] ON [dbo].[PlanMiner_Columns] 48 | ( 49 | [PlanMinerID] ASC 50 | ,[StatementID] ASC 51 | ,[NodeID] ASC 52 | ) -------------------------------------------------------------------------------- /PlanMiner/README.md: -------------------------------------------------------------------------------- 1 | # PlanMiner 2 | This tool extracts certaub details out of execution plans obtained from: 3 | - Query Store (plans listed in the [sys].[query_store_plan] table). 4 | - The SQL cache (plans returned by [sys].[dm_exec_query_plan] based on they plan_handle). 5 | - A file containing the execution plan (in XML format). 6 | 7 | These details include: 8 | - Statements included in the execution plan (all details are associated to a particular statement). 9 | - Cursors involved in the execution plan. 10 | - Missing indexes: reports all of them, instead of only the one with the most impact as the SSMS GUI does when opening the execution plan. 11 | - Unmatched indexes: filtered indexes that weren't used due to the WHERE clauses not being aligned with them. 12 | - Nodes of the execution plan: as graphically represented in the SSMS view, for a table representation of the execution plan flow. 13 | - Index operations: Indexes used and the operation performed on them, including any hints and forced indexes. 14 | - Columns accessed: any columns accessed on the node of the execution plan for either read or write operations. 15 | - Statistics used by the SQL Engine to generate the execution plan. 16 | 17 | 18 | --- 19 | ## Use cases and examples 20 | ### Execution plan from cache 21 | ``` 22 | DECLARE @PlanMinerID BIGINT 23 | EXECUTE [dbo].[PlanMiner] 24 | @InstanceIdentifier = 'LocalServer01' 25 | ,@PlanHandle = 0x0500060079E8D66530DEE7A80102000001000000000000000000000000000000000000000000000000000000 26 | ,@PlanMinerID = @PlanMinerID OUTPUT 27 | ``` 28 | 29 | ### Execution plan from Query Store 30 | ``` 31 | DECLARE @PlanMinerID BIGINT 32 | EXECUTE [dbo].[PlanMiner] 33 | @InstanceIdentifier = 'LocalServer01 34 | ,@DatabaseName = 'TargetDB' 35 | ,@PlanID = 368 36 | ,@PlanMinerID = @PlanMinerID OUTPUT 37 | ``` 38 | 39 | ### Execution plan from file 40 | ``` 41 | DECLARE @PlanMinerID BIGINT 42 | EXECUTE [dbo].[PlanMiner] 43 | @PlanFile = 'C:\Temp\Plan01.xml' 44 | ,@PlanMinerID = @PlanMinerID OUTPUT 45 | ``` 46 | 47 | ### Access extracted data 48 | ``` 49 | SELECT * FROM [dbo].[vPlanMiner_PlanList] WHERE [PlanMinerID] = @PlanMinerID 50 | SELECT * FROM [dbo].[vPlanMiner_Statements] WHERE [PlanMinerID] = @PlanMinerID 51 | SELECT * FROM [dbo].[PlanMiner_MissingIndexes] WHERE [PlanMinerID] = @PlanMinerID 52 | SELECT * FROM [dbo].[PlanMiner_UnmatchedIndexes] WHERE [PlanMinerID] = @PlanMinerID 53 | SELECT * FROM [dbo].[PlanMiner_Nodes] WHERE [PlanMinerID] = @PlanMinerID 54 | SELECT * FROM [dbo].[PlanMiner_Cursors] WHERE [PlanMinerID] = @PlanMinerID 55 | SELECT * FROM [dbo].[PlanMiner_IndexOperations] WHERE [PlanMinerID] = @PlanMinerID 56 | SELECT * FROM [dbo].[PlanMiner_Columns] WHERE [PlanMinerID] = @PlanMinerID 57 | SELECT * FROM [dbo].[PlanMiner_Statistics] WHERE [PlanMinerID] = @PlanMinerID 58 | ``` 59 | 60 | 61 | --- 62 | ## Suggested uses 63 | ### Identification of object usage 64 | Provided Query Store is enabled and capturing all metrics, analyzing all the plans in Query Store can be used to identify what objects (tables, indexes, columns...) are used, and what queries would be the impacted if they are modified. 65 | ### Statistics usage 66 | Understanding which statistics were used for the generation of a plan can help decide what would be the frecuency and sample rate of next UPDATE STATS command to prevent SQL server from using a less-than-optimal execution plan due to the SQL server not having sufficiently accurate information on the data. 67 | ### Impact of execution plan nodes 68 | Having the estimate CPU & I/O on each of the execution plan's nodes can highlight operations that have a heavy impact on the query, such as Key Lookups having a high I/O impact that could be prevented by implementing one of the identified missing indexes. -------------------------------------------------------------------------------- /QDSCacheCleanup/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /QDSCacheCleanup/1-dbo.QDSCacheCleanupIndex.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[QDSCacheCleanupIndex] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[QDSCacheCleanup] to store its entry parameters 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [QueryType] NVARCHAR(16) NOT NULL 20 | -- Type of query for which the following metrics are referred 21 | -- 22 | -- [QueryCount] BIGINT NULL 23 | -- Number of queries of the [QueryType] found to be deleted 24 | -- 25 | -- [PlanCount] BIGINT NULL 26 | -- Number of plans belonging to queries of the [QueryType] found to be deleted 27 | -- 28 | -- [QueryTextKBs] BIGINT NULL 29 | -- Size of the query texts belonging to queries of the [QueryType] found to be deleted 30 | -- 31 | -- [PlanXMLKBs] BIGINT NULL 32 | -- Size of the execution plans belonging to queries of the [QueryType] found to be deleted 33 | -- 34 | -- [RunStatsKBs] BIGINT NULL 35 | -- Size of the query runtime stats generated for the plans belonging to queries of the [QueryType] found to be deleted 36 | -- 37 | -- [WaitStatsKBs] BIGINT NULL 38 | -- Size of the query wait stats generated for the plans belonging to queries of the [QueryType] found to be deleted 39 | -- 40 | -- [CleanupParameters] XML NULL 41 | -- List of parameters used to invoke the execution of [dbo].[QDSCacheCleanup] 42 | -- 43 | -- [TestMode] BIT NOT NULL 44 | -- Flag to enable/disable the Test mode, which generates the report but doesn't clean any Query Store data 45 | -- 46 | -- Date: 2020.10.22 47 | -- Auth: Pablo Lozano (@sqlozano) 48 | -- 49 | -- Date: 2021.05.08 50 | -- Auth: Pablo Lozano (@sqlozano) 51 | -- Changed script logic to drop & recreate table 52 | ---------------------------------------------------------------------------------- 53 | 54 | DROP TABLE IF EXISTS [dbo].[QDSCacheCleanupIndex] 55 | CREATE TABLE [dbo].[QDSCacheCleanupIndex] 56 | ( 57 | [ReportID] BIGINT NOT NULL 58 | ,[ReportDate] DATETIME2 NOT NULL 59 | ,[ServerIdentifier] SYSNAME NOT NULL 60 | ,[DatabaseName] SYSNAME NOT NULL 61 | ,[QueryType] NVARCHAR(16) NOT NULL 62 | ,[QueryCount] BIGINT NULL 63 | ,[PlanCount] BIGINT NULL 64 | ,[QueryTextKBs] BIGINT NULL 65 | ,[PlanXMLKBs] BIGINT NULL 66 | ,[RunStatsKBs] BIGINT NULL 67 | ,[WaitStatsKBs] BIGINT NULL 68 | ,[CleanupParameters] XML NULL 69 | ,[TestMode] BIT NOT NULL 70 | ) 71 | ALTER TABLE [dbo].[QDSCacheCleanupIndex] 72 | ADD CONSTRAINT [PK_QDSCacheCleanupIndex] PRIMARY KEY CLUSTERED 73 | ( 74 | [ReportID] ASC 75 | ,[QueryType] ASC 76 | ) -------------------------------------------------------------------------------- /QDSCacheCleanup/2-dbo.QDSCacheCleanupDetails.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[QDSCacheCleanupDetails] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[QDSCacheCleanup] to the details of the queries deleted 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [QueryType] NVARCHAR(16) NOT NULL 11 | -- Type of query for which the following metrics are referred 12 | -- 13 | -- [ObjectName] NVARCHAR(260) NULL 14 | -- Name of the object (if any) which the [QueryID] is part of 15 | -- 16 | -- [QueryID] BIGINT NOT NULL 17 | -- Identifier of the query deleted 18 | -- 19 | -- [LastExecutionTime] DATETIMEOFFSET(7) NULL 20 | -- Last time (UTC time) the [QueryID] was executed 21 | -- 22 | -- [ExecutionCount] BIGINT NULL 23 | -- Number of executions of the [QueryID] 24 | -- 25 | -- [QueryText] VARBINARY(MAX) NULL 26 | -- Query Text corresponding to [QueryID] (compressed) 27 | -- 28 | -- Date: 2020.10.22 29 | -- Auth: Pablo Lozano (@sqlozano) 30 | -- 31 | -- Date: 2021.05.08 32 | -- Auth: Pablo Lozano (@sqlozano) 33 | -- Changed script logic to drop & recreate table 34 | ---------------------------------------------------------------------------------- 35 | 36 | DROP TABLE IF EXISTS [dbo].[QDSCacheCleanupDetails] 37 | CREATE TABLE [dbo].[QDSCacheCleanupDetails] 38 | ( 39 | [ReportID] BIGINT NOT NULL 40 | ,[QueryType] NVARCHAR(16) NOT NULL 41 | ,[ObjectName] NVARCHAR(260) NULL 42 | ,[QueryID] BIGINT NOT NULL 43 | ,[LastExecutionTime] DATETIMEOFFSET(7) NULL 44 | ,[ExecutionCount] BIGINT NULL 45 | ,[QueryText] VARBINARY(MAX) NULL 46 | ) 47 | ALTER TABLE [dbo].[QDSCacheCleanupDetails] 48 | ADD CONSTRAINT [PK_QDSCacheCleanupDetails] PRIMARY KEY CLUSTERED 49 | ( 50 | [ReportID] ASC 51 | ,[QueryType] ASC 52 | ,[QueryID] ASC 53 | ) -------------------------------------------------------------------------------- /QDSCacheCleanup/4-dbo.vQDSCacheCleanupIndex.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vQDSCacheCleanupIndex] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[QDSCacheCleanupIndex] to extract the entry parameters used by the executions of [dbo].[QDSCacheCleanup] 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [QueryType] NVARCHAR(16) NOT NULL 20 | -- Type of query for which the following metrics are referred 21 | -- 22 | -- [QueryCount] BIGINT NULL 23 | -- Number of queries of the [QueryType] found to be deleted 24 | -- 25 | -- [PlanCount] BIGINT NULL 26 | -- Number of plans belonging to queries of the [QueryType] found to be deleted 27 | -- 28 | -- [QueryTextKBs] BIGINT NULL 29 | -- Size of the query texts belonging to queries of the [QueryType] found to be deleted 30 | -- 31 | -- [PlanXMLKBs] BIGINT NULL 32 | -- Size of the execution plans belonging to queries of the [QueryType] found to be deleted 33 | -- 34 | -- [RunStatsKBs] BIGINT NULL 35 | -- Size of the query runtime stats generated for the plans belonging to queries of the [QueryType] found to be deleted 36 | -- 37 | -- [WaitStatsKBs] BIGINT NULL 38 | -- Size of the query wait stats generated for the plans belonging to queries of the [QueryType] found to be deleted 39 | -- 40 | -- [CleanupParameters] XML NULL 41 | -- List of parameters used to invoke the execution of [dbo].[QDSCacheCleanup] 42 | -- 43 | -- [TestMode] BIT NOT NULL 44 | -- Flag to enable/disable the Test mode, which generates the report but doesn't clean any Query Store data 45 | -- 46 | -- [CleanAdhocStale] BIT NOT NULL 47 | -- Flag to clean queries that: 48 | -- Are ad-hoc queries (don't belong any object) 49 | -- Haven't been executed at least @MinExecutionCount times 50 | -- Haven't been executed in the last @Retention hours 51 | -- 52 | -- [CleanStale] BIT NOT NULL 53 | -- Flag to clean queries that: 54 | -- Queries belonging an object and ad-hoc ones (don't belong any object) 55 | -- Haven't been executed at least @MinExecutionCount times 56 | -- Haven't been executed in the last @Retention hours 57 | -- 58 | -- [Retention] BIT NOT NULL 59 | -- Hours since the last execution of the query 60 | -- 61 | -- [MinExecutionCount] BIT NOT NULL 62 | -- Minimum number of executions NOT delete the query. If @MinExecutionCount = 0, ALL queries will be flagged for deletion 63 | -- 64 | -- [CleanOrphan] BIT NOT NULL 65 | -- Flag to clean queries associated with deleted objects 66 | -- 67 | -- [CleanInternal] BIT NOT NULL 68 | -- Flag to clean queries identified as internal ones by QDS (UPDATE STATISTICS, INDEX REBUILD....) 69 | -- 70 | -- [RetainForcedMetrics] BIT NOT NULL 71 | -- Flag to retain metrics for queries having forced plans (provided they are not orphan queries) 72 | -- 73 | -- [CleanStatsOnly] BIT NOT NULL 74 | -- Flag to clean only the statistics of the queries flagged to be deleted, but not the queries, execution plans or query texts themselves 75 | -- 76 | -- Date: 2020.10.22 77 | -- Auth: Pablo Lozano (@sqlozano) 78 | -- 79 | -- Date: 2021.11.28 80 | -- Auth: Pablo Lozano (@sqlozano) 81 | -- Changes: New column to represent parameter @RetainForcedMetrics 82 | -- https://github.com/channeladvisor/qdstoolbox/issues/25 83 | ---------------------------------------------------------------------------------- 84 | 85 | CREATE OR ALTER VIEW [dbo].[vQDSCacheCleanupIndex] 86 | AS 87 | SELECT 88 | [ReportID] 89 | ,[ReportDate] 90 | ,[ServerIdentifier] 91 | ,[DatabaseName] 92 | ,[QueryType] 93 | ,[QueryCount] 94 | ,[PlanCount] 95 | ,[QueryTextKBs] 96 | ,[PlanXMLKBs] 97 | ,[RunStatsKBs] 98 | ,[WaitStatsKBs] 99 | ,[TestMode] 100 | ,[CleanupParameters].value('(/Root/CleanupParameters/CleanAdhocStale)[1]','BIT') AS [CleanAdhocStale] 101 | ,[CleanupParameters].value('(/Root/CleanupParameters/CleanStale)[1]','BIT') AS [CleanStale] 102 | ,[CleanupParameters].value('(/Root/CleanupParameters/Retention)[1]','BIT') AS [Retention] 103 | ,[CleanupParameters].value('(/Root/CleanupParameters/MinExecutionCount)[1]','BIT') AS [MinExecutionCount] 104 | ,[CleanupParameters].value('(/Root/CleanupParameters/CleanOrphan)[1]','BIT') AS [CleanOrphan] 105 | ,[CleanupParameters].value('(/Root/CleanupParameters/CleanInternal)[1]','BIT') AS [CleanInternal] 106 | ,[CleanupParameters].value('(/Root/CleanupParameters/RetainForcedMetrics)[1]','BIT') AS [RetainForcedMetrics] 107 | ,[CleanupParameters].value('(/Root/CleanupParameters/CleanStatsOnly)[1]','BIT') AS [CleanStatsOnly] 108 | FROM [dbo].[QDSCacheCleanupIndex] -------------------------------------------------------------------------------- /QDSCacheCleanup/5-dbo.vQDSCacheCleanupDetails.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vQDSCacheCleanupDetails] 3 | -- 4 | -- Desc: This view is built on top of [QDSCacheCleanupDetails] to extract the details of the queries flagged for deletion by the execution of [dbo].[QDSCacheCleanup] 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [QueryType] NVARCHAR(16) NOT NULL 11 | -- Type of query for which the following metrics are referred 12 | -- 13 | -- [ObjectName] NVARCHAR(260) NULL 14 | -- Name of the object (if any) which the [QueryID] is part of 15 | -- 16 | -- [QueryID] BIGINT NOT NULL 17 | -- Identifier of the query deleted 18 | -- 19 | -- [LastExecutionTime] DATETIMEOFFSET(7) NULL 20 | -- Last time (UTC time) the [QueryID] was executed 21 | -- 22 | -- [ExecutionCount] BIGINT NULL 23 | -- Number of executions of the [QueryID] 24 | -- 25 | -- [QueryText] NVARCHAR(MAX) NULL 26 | -- Query Text corresponding to [QueryID] 27 | -- 28 | -- Date: 2020.10.22 29 | -- Auth: Pablo Lozano (@sqlozano) 30 | -- 31 | ---------------------------------------------------------------------------------- 32 | 33 | CREATE OR ALTER VIEW [dbo].[vQDSCacheCleanupDetails] 34 | AS 35 | SELECT 36 | [ReportID] 37 | ,[QueryType] 38 | ,[ObjectName] 39 | ,[QueryID] 40 | ,[LastExecutionTime] 41 | ,[ExecutionCount] 42 | ,CAST(DECOMPRESS([QueryText]) AS NVARCHAR(MAX)) AS [QueryText] 43 | FROM [dbo].[QDSCacheCleanupDetails] -------------------------------------------------------------------------------- /QDSCacheCleanup/README.md: -------------------------------------------------------------------------------- 1 | # QDSCacheClean 2 | Query Store includes two cleanup processes: 3 | - Date-based, that ensure no data older than XX days is kept to reduce the size of Query Store (adjustable) 4 | - Size-based, which kicks in once a database's Query Store size reaches 90% of its maximum size. It scans the metrics stored and deletes any information (starting with the lest CPU-heavy), and deletes the stored information until the QDS space utilization drops below 80% (if possible) 5 | 6 | There are some problems: 7 | - Queries with a forced plan are not dropped. 8 | - Dropped object don't have their metrics not removed until either of the two predefined cleanup processes kicks in and targets them. 9 | - The size-based cleanup has a big impact on high performance environments (up to 60% of CPU allocated to this process on a 8 cores box), and could potentially be triggered every time the data is flushed to disk. 10 | 11 | 12 | This tool uses the SPs sp_query_store_remove_query, sp_query_store_remove_plan and sp_query_store_reset_exec_stats to delete stored data for specific queries and or plans, which can be adapted using multiple parameters to perform different types of cleanups, as for example: 13 | 14 | - Delete plans/queries and/or not used in the last XX hours. 15 | - Delete plans/queries not part of an object (stored procedure/function/trigger...) not used in the last XX hours. 16 | - Delete information regarding internal queries (such as statistics update, index maintenance operations) 17 | - Delete information regarding queries that formed part of a no longer existing object (orphan queries) 18 | 19 | In addition to the cleanup operation, the tool can be used to analyze the impact of its execution, by running it on Test Mode and logging the information of the clean cache operation (either as a test, or as an actual execution) into persisted tables for analysis.\ 20 | \ 21 | It can be executed in a Test mode to only return the impact executing it would have. both in Test mode or when executed to perform the actual QDS cache clean operations, the operations's can return an output in different formats: 22 | - Returned in a readable format (as text). 23 | - Returned in the form of 1/2 tables (depending on whether the summary of the report of a detailed report is requested). 24 | - Stored into 1/2 SQL tables (depending on whether the summary of the report of a detailed report is requested). 25 | - Not returned at all. 26 | 27 | The impact of this cleanup alternative has a much smaller impact on the SQL instance: when executed on the same 8 cores box that had seen a 60% of CPU utilization, this cleanup was executed against 4 databases in parallel (compared to the serial execution of the built-in cleanup), with no noticeable impact on the instance. 28 | 29 | --- 30 | ## Use cases and examples 31 | Analyze the impact executing the report would have, results returned in two tables (with different degrees of details) back to the user: 32 | ``` 33 | EXECUTE [dbo].[QDSCacheCleanup] 34 | @DatabaseName = 'TargetDB' 35 | ,@ReportAsTable = 1 36 | ,@ReportDetailsAsTable = 1 37 | ,@TestMode = 1 38 | ``` 39 | 40 | Deletes the stats for all existing queries but not the actual plans, queries, or texts 41 | ``` 42 | EXECUTE [dbo].[QDSCacheCleanup] 43 | @DatabaseName = 'TargetDB' 44 | ,@Retention = 0 45 | ,@CleanStatsOnly = 1 46 | ``` 47 | 48 | Delete internal and adhoc queries along with their execution stats 49 | ``` 50 | EXECUTE [dbo].[QDSCacheCleanup] 51 | @DatabaseName = 'TargetDB' 52 | ,@CleanAdhocStale = 1 53 | ,@Retention = 1 54 | ,@CleanInternal = 1 55 | ``` 56 | 57 | Perform a default-valued cleanup and record the results 58 | ``` 59 | EXECUTE [dbo].[QDSCacheCleanup] 60 | @DatabaseName = 'TargetDB' 61 | ,@ReportIndexOutputTable = 'dbo.QDSCacheCleanupIndex' 62 | ,@ReportDetailsOutputTable = 'dbo.QDSCacheCleanupDetails' 63 | 64 | ``` 65 | 66 | --- 67 | ## Suggested uses 68 | ### Removal of non SPs & Functions code 69 | 70 | Databases whose code is all included in functions, procedures, triggers... deleting adhoc and internal queries may reduce space requirements whilst the performance data retained can still be used for performance analysis. 71 | ### Post Code change cleanup 72 | After code changes that involve dropping objects, orphan queries will no longer be used and the space they occupy can be freed. 73 | ### Prevention of auto cleanup 74 | When the space usage is close to 90% of the total Query Store max usage, this tool can be used to try and reduce its occupation, preventing the size-based cleanup. -------------------------------------------------------------------------------- /QueryReport/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /QueryReport/README.md: -------------------------------------------------------------------------------- 1 | # QueryReport 2 | This procedure allows access to the information stored in both sys.query_store_runtime_stats and sys.query_store_wait_stats 3 | This information is extracted and aggregated at different levels: 4 | -Time interval: aggregating the data at the runtime_stats_interval_id level, or between @StartTime and @EndTime 5 | -Object/Query/Plan: since Query Store gathers statistics per plan, this information can be presented at the plan, query or object level 6 | 7 | In addition to the statistics, this procedure can be used to extrain information: 8 | -The query texts 9 | -The execution plan 10 | -The object definition 11 | Depending on the input parameters and flags provided 12 | 13 | --- 14 | ## Use cases and examples 15 | Get the runtime statistics of every query part of the [Db01].[Sche].[Obj01] between '2021-01-01 00:00' and '2021-01-07 00:00' detailed at the query level for each interval set for the [Db01] query store interval, with averages based on the # of executions of each query 16 | ``` 17 | EXECUTE [dbo].[QueryReport] 18 | @DatabaseName = 'Db01' 19 | ,@ObjectName = '[Sch01].[Obj01]' 20 | ,@StartTime = '2021-01-01 00:00' 21 | ,@EndTime = '2021-01-07 00:00' 22 | ,@IntervalReports = 1 23 | ,@QueryAggregation = 1 24 | ,@Averages = 1 25 | ,@RuntimeStats = 1 26 | ``` 27 | 28 | Get the wait statistics of the plan ID 1234 on database [Db02] aggregated for the whole interval between '2021-06-01 00:00' and '2021-06-01 06:00' obtaining both the average waits and total waits in separate reports 29 | ``` 30 | EXECUTE [dbo].[QueryReport] 31 | @DatabaseName = 'Db02' 32 | ,@PlanID = 1234 33 | ,@StartTime = '2021-06-01 00:00' 34 | ,@EndTime = '2021-06-01 06:00' 35 | ,@AggregatedReports = 1 36 | ,@PlanAggregation = 1 37 | ,@Averages = 1 38 | ,@Totals = 1 39 | ,@WaitStats = 1 40 | ``` 41 | 42 | Get both the runtime wait statistics of two query IDs (1534 and 3342) on database [Db03] aggregated for the whole interval between '2021-06-01 00:00' and '2021-06-03 00:00' obtaining average runtime & wait stats in a single combined report 43 | ``` 44 | EXECUTE [dbo].[QueryReport] 45 | @DatabaseName = 'Db03' 46 | ,@QueryIDList = '1534,3342' 47 | ,@StartTime = '2021-06-01 00:00' 48 | ,@EndTime = '2021-06-03 00:00' 49 | ,@AggregatedReports = 1 50 | ,@QueryAggregation = 1 51 | ,@Averages = 1 52 | ,@RuntimeStats = 1 53 | ,@WaitStats = 1 54 | ``` 55 | 56 | --- 57 | ## Suggested uses 58 | ### Post Code change analysis 59 | Given an SP recently modified, obtain a list of QueryID that take part of the procedure [Sch02].[Obj02] on database [DB04] 60 | ``` 61 | EXECUTE [dbo].[QDSCacheCleanup] 62 | @DatabaseName = 'DB04' 63 | ,@ObjectName = '[Sch01].[Obj02] 64 | ,@QueryDetails = 1 65 | ``` 66 | Once identified the specific QueryIDs (8001 and 9001) updated whose changes are to be monitored 67 | ``` 68 | EXECUTE [dbo].[QueryReport] 69 | @DatabaseName = 'Db04' 70 | ,@QueryIDList = '8001,9001' 71 | ,@StartTime = '2021-07-01 00:00' 72 | ,@EndTime = '2021-09-01 00:00' 73 | ,@AggregatedReports = 1 74 | ,@QueryAggregation = 1 75 | ,@Averages = 1 76 | ,@RuntimeStats = 1 77 | ,@PlanDetails = 1 78 | ``` 79 | In addition to comparing the runtime stats of both versions of the sub query, the plans used by both versions of the query will be returned for comparison of the last 2 months of data, aggregated for the two months; 80 | this results in 2 lines, one for each QueryID, indicating when the change took place and the average metrics 81 | 82 | ### Correlate WaitStats & Increased duration 83 | Since the SSMS GUI has separate sections for information extracted from sys.query_store_runtime_stats and sys.query_store_wait_stats, it is difficult to correlate increases in a query's duration with increase in waits 84 | Combining both can provide some hindsight on what kind of blocking may have caused a deviation in the query duration despite no plan regression 85 | ``` 86 | EXECUTE [dbo].[QueryReport] 87 | @DatabaseName = 'Db05' 88 | ,@PlanID = 4454 89 | ,@StartTime = '2021-07-01 00:00' 90 | ,@EndTime = '2021-08-01 00:00' 91 | ,@IntervalReports = 1 92 | ,@PlanAggregation = 1 93 | ,@Averages = 1 94 | ,@RuntimeStats = 1 95 | ,@WaitStats = 1 96 | ``` -------------------------------------------------------------------------------- /QueryVariation/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /QueryVariation/2-dbo.QueryVariationIndex.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[QueryVariationIndex] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[QueryVariation] to store its entry parameters 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [Parameters] XML NULL 20 | -- List of parameters used to invoke the execution of [dbo].[QueryVariation] 21 | -- 22 | -- Date: 2020.10.22 23 | -- Auth: Pablo Lozano (@sqlozano) 24 | -- 25 | -- Date: 2021.05.08 26 | -- Auth: Pablo Lozano (@sqlozano) 27 | -- Changed script logic to drop & recreate table 28 | ---------------------------------------------------------------------------------- 29 | 30 | DROP TABLE IF EXISTS [dbo].[QueryVariationIndex] 31 | CREATE TABLE [dbo].[QueryVariationIndex] 32 | ( 33 | [ReportID] BIGINT IDENTITY(1,1) 34 | ,[CaptureDate] DATETIME2 NOT NULL 35 | ,[ServerIdentifier] SYSNAME NOT NULL 36 | ,[DatabaseName] SYSNAME NOT NULL 37 | ,[Parameters] XML NOT NULL 38 | ) 39 | ALTER TABLE [dbo].[QueryVariationIndex] 40 | ADD CONSTRAINT [PK_QueryVariationIndex] PRIMARY KEY CLUSTERED 41 | ( 42 | [ReportID] 43 | ) WITH (DATA_COMPRESSION = PAGE) -------------------------------------------------------------------------------- /QueryVariation/3-dbo.QueryVariationStore.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[QueryVariationStore] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[QueryVariation] to store the details of the Query Variations identified 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [QueryID] BIGINT NOT NULL 11 | -- Query Identifier of the query with a query variation 12 | -- 13 | -- [ObjectID] BIGINT NOT NULL 14 | -- Object Identifier the [QueryID] is part of (if any) 15 | -- 16 | -- [SchemaName] SYSNAME NULL 17 | -- Name of the schema of the object the [QueryID] is part of (if any) 18 | -- 19 | -- [ObjectName] SYSNAME NULL 20 | -- Name of the object the [QueryID] is part of (if any) 21 | -- 22 | -- [MeasurementChange] FLOAT NOT NULL 23 | -- Amount of measurement 24 | -- 25 | -- [MeasurementRecent] FLOAT NOT NULL 26 | -- Value of the measurement in the Recent time period 27 | -- 28 | -- [MeasurementHist] FLOAT NOT NULL 29 | -- Value of the measurement in the History time period 30 | -- 31 | -- [ExecutionCountRecent] BIGINT NOT NULL 32 | -- Number of executions of the [QueryID] executed in the Recent time period 33 | -- 34 | -- [ExecutionCountHist] BIGINT NOT NULL 35 | -- Number of executions of the [QueryID] executed in the History time period 36 | -- 37 | -- [NumPlans] INT NOT NULL 38 | -- Number of different execution plans found for the [QueryID] 39 | -- 40 | -- [QuerySqlText] VARBINARY(MAX) NULL 41 | -- Query text of the [QueryID] (compressed) 42 | -- 43 | -- Date: 2020.10.22 44 | -- Auth: Pablo Lozano (@sqlozano) 45 | -- 46 | -- Date: 2021.05.08 47 | -- Auth: Pablo Lozano (@sqlozano) 48 | -- Changed script logic to drop & recreate table 49 | ---------------------------------------------------------------------------------- 50 | 51 | DROP TABLE IF EXISTS [dbo].[QueryVariationStore] 52 | CREATE TABLE [dbo].[QueryVariationStore] 53 | ( 54 | [ReportID] BIGINT NOT NULL 55 | ,[QueryID] BIGINT NOT NULL 56 | ,[ObjectID] BIGINT NOT NULL 57 | ,[SchemaName] SYSNAME NULL 58 | ,[ObjectName] SYSNAME NULL 59 | ,[MeasurementChange] FLOAT NOT NULL 60 | ,[MeasurementRecent] FLOAT NOT NULL 61 | ,[MeasurementHist] FLOAT NOT NULL 62 | ,[ExecutionCountRecent] BIGINT NOT NULL 63 | ,[ExecutionCountHist] BIGINT NOT NULL 64 | ,[NumPlans] INT NOT NULL 65 | ,[QuerySqlText] VARBINARY(MAX) NULL 66 | ) 67 | ALTER TABLE [dbo].[QueryVariationStore] 68 | ADD CONSTRAINT [PK_QueryVariationStore] PRIMARY KEY CLUSTERED 69 | ( 70 | [ReportID] ASC 71 | ,[QueryID] ASC 72 | ) -------------------------------------------------------------------------------- /QueryVariation/4-dbo.QueryVariation.Procedure.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/channeladvisor/qdstoolbox/115f671a49ca9910f6dc73ecf8de18b571ecdd7b/QueryVariation/4-dbo.QueryVariation.Procedure.sql -------------------------------------------------------------------------------- /QueryVariation/5-dbo.vQueryVariationIndex.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vQueryVariationIndex] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[QueryVariationIndex] to extract the entry parameters used by the executions of [dbo].[QueryVariation] 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [Measurement] NVARCHAR(32) 20 | -- Measurement analyzed 21 | -- 22 | -- [Metric] NVARCHAR(16) 23 | -- Metric on which to analyze the [Measurement] values on 24 | -- 25 | -- [VariationType] NVARCHAR(1) 26 | -- Defines whether queries whose metric indicates an improvement (I) or a regression (R) 27 | -- 28 | -- [ResultsRowCount] INT 29 | -- Number of rows to return 30 | -- 31 | -- [RecentStartTime] DATETIME2 32 | -- Start of the time period considered as "recent" to be compared with the "history" time period (in UTC) 33 | -- 34 | -- [RecentEndTime] DATETIME2 35 | -- End of the time period considered as "recent" to be compared with the "history" time period (in UTC) 36 | -- 37 | -- [HistoryStartTime] DATETIME2 38 | -- Start of the time period considered as "history" to be compared with the "recent" time period (in UTC) 39 | -- 40 | -- [HistoryEndTime] DATETIME2 41 | -- End of the time period considered as "history" to be compared with the "recent" time period (in UTC) 42 | -- 43 | -- [MinExecCount] INT 44 | -- Minimum number of executions in the "recent" time period to analyze the query 45 | -- 46 | -- [MinPlanCount] INT 47 | -- Minimum number of different execution plans used by the query to analyze it 48 | -- 49 | -- [MaxPlanCount] INT 50 | -- Maximum number of different execution plans used by the query to analyze it 51 | -- 52 | -- [IncludeQueryText] BIT 53 | -- Flag to define whether the text of the query is stored 54 | -- 55 | -- [ExcludeAdhoc] BIT 56 | -- Flag to define whether to ignore adhoc queries (not part of a DB object) from the analysis 57 | -- 58 | -- [ExcludeInternal] BIT 59 | -- Flag to define whether to ignore internal queries (backup, index rebuild, statistics update...) from the analysis 60 | -- 61 | -- Date: 2020.10.22 62 | -- Auth: Pablo Lozano (@sqlozano) 63 | -- 64 | ---------------------------------------------------------------------------------- 65 | 66 | CREATE OR ALTER VIEW [dbo].[vQueryVariationIndex] 67 | AS 68 | SELECT 69 | [ReportID] 70 | ,[CaptureDate] 71 | ,[ServerIdentifier] 72 | ,[DatabaseName] 73 | ,q.n.value('Measurement[1]', 'NVARCHAR(32)') AS [Measurement] 74 | ,q.n.value('Metric[1]', 'NVARCHAR(16)') AS [Metric] 75 | ,q.n.value('VariationType[1]', 'NVARCHAR(1)') AS [VariationType] 76 | ,q.n.value('ResultsRowCount[1]', 'INT') AS [ResultsRowCount] 77 | ,q.n.value('RecentStartTime[1]', 'DATETIME2') AS [RecentStartTime] 78 | ,q.n.value('RecentEndTime[1]', 'DATETIME2') AS [RecentEndTime] 79 | ,q.n.value('HistoryStartTime[1]', 'DATETIME2') AS [HistoryStartTime] 80 | ,q.n.value('HistoryEndTime[1]', 'DATETIME2') AS [HistoryEndTime] 81 | ,q.n.value('MinExecCount[1]', 'INT') AS [MinExecCount] 82 | ,q.n.value('MinPlanCount[1]', 'INT') AS [MinPlanCount] 83 | ,q.n.value('MaxPlanCount[1]', 'INT') AS [MaxPlanCount] 84 | ,q.n.value('IncludeQueryText[1]', 'BIT') AS [IncludeQueryText] 85 | ,q.n.value('ExcludeAdhoc[1]', 'BIT') AS [ExcludeAdhoc] 86 | ,q.n.value('ExcludeInternal[1]', 'BIT') AS [ExcludeInternal] 87 | FROM [dbo].[QueryVariationIndex] [qvi] 88 | CROSS APPLY [qvi].[Parameters].nodes('/Root/QueryVariationParameters') AS q(n) 89 | 90 | GO -------------------------------------------------------------------------------- /QueryVariation/6-dbo.vQueryVariationStore.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vQueryVariationIndex] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[QueryVariationIndex] to extract the entry parameters used by the executions of [dbo].[QueryVariation] 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [QueryID] BIGINT NOT NULL 11 | -- Query Identifier of the query with a query variation 12 | -- 13 | -- [ObjectID] BIGINT NOT NULL 14 | -- Object Identifier the [QueryID] is part of (if any) 15 | -- 16 | -- [SchemaName] SYSNAME NULL 17 | -- Name of the schema of the object the [QueryID] is part of (if any) 18 | -- 19 | -- [ObjectName] SYSNAME NULL 20 | -- Name of the objectthe [QueryID] is part of (if any) 21 | -- 22 | -- [Measurement] NVARCHAR(32) NOT NULL 23 | -- Measurement to analyze the variation from (CPU, Duration, Log...) 24 | -- 25 | -- [Metric] NVARCHAR(16) NOT NULL 26 | -- Metric to analyze the [Measurement] on (Avg, Total, Max...) 27 | -- 28 | -- [Unit] NVARCHAR(32) NOT NULL 29 | -- Unit the measurement & metric is specified (microseconds, %, KBs...) 30 | -- 31 | -- [MeasurementChange] FLOAT NOT NULL 32 | -- Amount of measurement 33 | -- 34 | -- [MeasurementRecent] FLOAT NOT NULL 35 | -- Value of the measurement in the Recent time period 36 | -- 37 | -- [MeasurementHist] FLOAT NOT NULL 38 | -- Value of the measurement in the History time period 39 | -- 40 | -- [ExecutionCountRecent] BIGINT NOT NULL 41 | -- Number of executions of the [QueryID] executed in the Recent time period 42 | -- 43 | -- [ExecutionCountHist] BIGINT NOT NULL 44 | -- Number of executions of the [QueryID] executed in the History time period 45 | -- 46 | -- [NumPlans] INT NOT NULL 47 | -- Number of different execution plans found for the [QueryID] 48 | -- 49 | -- [QuerySqlText] NVARCHAR(MAX) NULL 50 | -- Query text of the [QueryID] 51 | -- 52 | -- Date: 2020.10.22 53 | -- Auth: Pablo Lozano (@sqlozano) 54 | -- 55 | ---------------------------------------------------------------------------------- 56 | 57 | CREATE OR ALTER VIEW [dbo].[vQueryVariationStore] 58 | AS 59 | SELECT 60 | [qvs].[ReportID] 61 | ,[qvs].[QueryID] 62 | ,[qvs].[ObjectID] 63 | ,[qvs].[SchemaName] 64 | ,[qvs].[ObjectName] 65 | ,[ma].[Measurement] 66 | ,[ma].[Metric] 67 | ,[ma].[Unit] 68 | ,[qvs].[MeasurementChange] 69 | ,[qvs].[MeasurementRecent] 70 | ,[qvs].[MeasurementHist] 71 | ,[qvs].[ExecutionCountRecent] 72 | ,[qvs].[ExecutionCountHist] 73 | ,[qvs].[NumPlans] 74 | ,CAST(DECOMPRESS([qvs].[QuerySqlText]) AS NVARCHAR(MAX)) AS [QuerySqlText] 75 | FROM [dbo].[QueryVariationStore] [qvs] 76 | INNER JOIN [dbo].[vQueryVariationIndex] [qvi] 77 | ON [qvs].[ReportID] = [qvi].[ReportID] 78 | INNER JOIN [dbo].[QDSMetricArchive] [ma] 79 | ON [qvi].[Measurement] = [ma].[Measurement] 80 | AND [qvi].[Metric] = [ma].[Metric] -------------------------------------------------------------------------------- /QueryVariation/README.md: -------------------------------------------------------------------------------- 1 | # QueryVariation 2 | Analyzes metrics from two different periods and returns the queries whose performance has changed based on a number of parameters (CPU usage, duration, IO operations...) and the metric in use (average, total, max...), offering a report similar to that of Query Store's GUI as seen in SSMS.\ 3 | Allows for an analysis based on the number of different plans in use, filtering queries that have a minimum/maximum number of execution plans.\ 4 | \ 5 | It can be executed in a Test mode to only return the impact executing it would have. both in Test mode or when executed to generate the actual report, the operations's can return an output in different formats: 6 | - One table, containing the detailed results. 7 | - Stored into 2 SQL tables, with one containing the parameters used (both explicitly defined and default values) and another with the detailed results. 8 | - Not returned at all. 9 | 10 | (SQL 2016 does not support @Measurement = 'Log' / 'TempDB') 11 | 12 | --- 13 | ## Use cases and examples 14 | ### Avg CPU regression 15 | Queries whose average CPU has regressed and used at least 2 different execution plans, when comparing the period between (2020-01-01 00:00 -> 2020-02-01 00:00) and (2020-02-01 00:00 -> 2020-02-01 01:00)\ 16 | ``` 17 | EXECUTE [dbo].[QueryVariation] 18 | @DatabaseName = 'Target' 19 | ,@Measurement = 'cpu' 20 | ,@Metric = 'avg' 21 | ,@VariationType = 'R' 22 | ,@MinPlanCount = 2 23 | ,@RecentStartTime = '2020-02-01 00:00' 24 | ,@RecentEndTime = '2020-02-01 01:00' 25 | ,@HistoryStartTime = '2020-01-01 00:00' 26 | ,@HistoryEndTime = '2020-02-01 00:00' 27 | ``` 28 | 29 | ### Max duration improvement 30 | Queries whose maximum duration has improved, when comparing the period between (2020-01-01 00:00 -> 2020-02-01 00:00) and (2020-02-01 00:00 -> 2020-02-01 01:00)\ 31 | ``` 32 | EXECUTE [dbo].[QueryVariation] 33 | @DatabaseName = 'Target' 34 | ,@Measurement = 'duration' 35 | ,@Metric = 'max' 36 | ,@VariationType = 'I' 37 | ,@RecentStartTime = '2020-02-01 00:00' 38 | ,@RecentEndTime = '2020-02-01 01:00' 39 | ,@HistoryStartTime = '2020-01-01 00:00' 40 | ,@HistoryEndTime = '2020-02-01 00:00' 41 | ``` 42 | --- 43 | 44 | ## Suggested uses 45 | This tool can be used to extract the same reports as the "Regressed Queries" SSMS GUI can, with the added functionality of storing the reports into tables for later analysis. 46 | ### Hardware changes 47 | When performing load & performance tests, allows for measuring the impact of applying changes to the SQL instance and box (such as changing the amount of CPUs of the SQL instance, its memory usage or its disks' IO performance), by looking for changes in performance of queries excluding changes caused my a modification of the execution plans used. 48 | ### Index & statistics changes 49 | Identify queries whose performance has changed due to changes in execution plans after performing maintenance operations (index rebuild, statistics recalculation), or creating/dropping/altering existing indexes. -------------------------------------------------------------------------------- /QueryWaits/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /QueryWaits/1-dbo.QueryWaitsIndex.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[QueryWaitsIndex] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[QueryWaits] to store its entry parameters 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [ObjectID] BIGINT NOT NULL 20 | -- Identifier of the object (if any) whose wait times are being analyzed 21 | -- 22 | -- [SchemaName] NVARCHAR(128) NOT NULL 23 | -- Name of the schema of the object (if any) whose wait times are being analyzed 24 | -- 25 | -- [ObjectName] NVARCHAR(128) NOT NULL 26 | -- Name of the object (if any) whose wait times are being analyzed 27 | -- 28 | -- [QueryTextID] BIGINT NOT NULL 29 | -- Identifier of the Query Text (when only one is being analyzed) whose wait times are being analyzed 30 | -- 31 | -- [QueryText] VARBINARY(MAX) NULL 32 | -- Compressed Query Text (when only one is being analyzed) whose wait times are being analyzed 33 | -- 34 | -- [Parameters] XML NOT NULL 35 | -- List of parameters used to invoke the execution of [dbo].[QueryWaits] 36 | -- 37 | -- Date: 2020.10.22 38 | -- Auth: Pablo Lozano (@sqlozano) 39 | -- 40 | ---------------------------------------------------------------------------------- 41 | 42 | DROP TABLE IF EXISTS [dbo].[QueryWaitsIndex] 43 | CREATE TABLE [dbo].[QueryWaitsIndex] 44 | ( 45 | [ReportID] BIGINT IDENTITY(1,1) 46 | ,[CaptureDate] DATETIME2 NOT NULL 47 | ,[ServerIdentifier] SYSNAME NOT NULL 48 | ,[DatabaseName] SYSNAME NOT NULL 49 | ,[ObjectID] BIGINT NOT NULL 50 | ,[SchemaName] NVARCHAR(128) NOT NULL 51 | ,[ObjectName] NVARCHAR(128) NOT NULL 52 | ,[QueryTextID] BIGINT NOT NULL 53 | ,[QueryText] VARBINARY(MAX) NULL 54 | ,[Parameters] XML NOT NULL 55 | ) 56 | ALTER TABLE [dbo].[QueryWaitsIndex] 57 | ADD CONSTRAINT [PK_QueryWaitsIndex] PRIMARY KEY CLUSTERED 58 | ( 59 | [ReportID] 60 | ) -------------------------------------------------------------------------------- /QueryWaits/2-dbo.QueryWaitsStore.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[QueryWaitsStore] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[QueryWaits] to store the results of the report 5 | -- Description of the wait categories can be found here: 6 | -- https://docs.microsoft.com/en-us/sql/relational-databases/system-catalog-views/sys-query-store-wait-stats-transact-sql?view=sql-server-ver15#wait-categories-mapping-table 7 | -- 8 | -- Columns: 9 | -- [ReportID] BIGINT NOT NULL 10 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 11 | -- 12 | -- [PlanID] BIGINT NOT NULL 13 | -- Identifier of the execution plan analyzed (when only one) 14 | -- 15 | -- [QueryID] BIGINT NOT NULL 16 | -- Identifier of the query analyzed (when only one) 17 | -- 18 | -- [QueryTextID] BIGINT NOT NULL 19 | -- Identifier of the query text analyzed (when only one) 20 | -- 21 | -- [StartTime] DATETIME2 NOT NULL 22 | -- Start Time of the interval whose metrics are represented in the next columns 23 | -- 24 | -- [EndTime] DATETIME2 NOT NULL 25 | -- End Time of the interval whose metrics are represented in the next columns 26 | -- 27 | -- [DifferentPlansUsed] INT NOT NULL 28 | -- Number of different plans used in the interval 29 | -- 30 | -- [DifferentQueriesUsed] INT NOT NULL 31 | -- Number of different queries used in the interval 32 | -- 33 | -- [Total_Duration] BIGINT NOT NULL 34 | -- Total duration of the Object/Query/Plan in the interval 35 | -- 36 | -- [Total_CPUTime] BIGINT NOT NULL 37 | -- Total CPU time of the Object/Query/Plan in the interval 38 | -- 39 | -- [Total_CLRTime] BIGINT NOT NULL 40 | -- Total CLR time of the Object/Query/Plan in the interval 41 | -- 42 | -- [Total_Wait] BIGINT NOT NULL 43 | -- Total wait time of the Object/Query/Plan in the interval 44 | -- 45 | -- [Wait_CPU] BIGINT NOT NULL 46 | -- Total CPU wait time of the Object/Query/Plan in the interval 47 | -- 48 | -- [Wait_WorkerThread] BIGINT NOT NULL 49 | -- Total Worker Thread wait time of the Object/Query/Plan in the interval 50 | -- 51 | -- [Wait_Lock] BIGINT NOT NULL 52 | -- Total Lock wait time of the Object/Query/Plan in the interval 53 | -- 54 | -- [Wait_Latch] BIGINT NOT NULL 55 | -- Total Latch wait time of the Object/Query/Plan in the interval 56 | -- 57 | -- [Wait_BufferLatch] BIGINT NOT NULL 58 | -- Total Buffer Latch wait time of the Object/Query/Plan in the interval 59 | -- 60 | -- [Wait_BufferIO] BIGINT NOT NULL 61 | -- Total Buffer IO wait time of the Object/Query/Plan in the interval 62 | -- 63 | -- [Wait_Compilation] BIGINT NOT NULL 64 | -- Total Compilation wait time of the Object/Query/Plan in the interval 65 | -- 66 | -- [Wait_SQLCLR] BIGINT NOT NULL 67 | -- Total SQL CLR wait time of the Object/Query/Plan in the interval 68 | -- 69 | -- [Wait_Mirroring] BIGINT NOT NULL 70 | -- Total Mirroring wait time of the Object/Query/Plan in the interval 71 | -- 72 | -- [Wait_Transaction] BIGINT NOT NULL 73 | -- Total Transaction wait time of the Object/Query/Plan in the interval 74 | -- 75 | -- [Wait_Idle] BIGINT NOT NULL 76 | -- Total Idle wait time of the Object/Query/Plan in the interval 77 | -- 78 | -- [Wait_Preemptive] BIGINT NOT NULL 79 | -- Total Preemptive wait time of the Object/Query/Plan in the interval 80 | -- 81 | -- [Wait_ServiceBroker] BIGINT NOT NULL 82 | -- Total Service Broker wait time of the Object/Query/Plan in the interval 83 | -- 84 | -- [Wait_TranLogIO] BIGINT NOT NULL 85 | -- Total Transactional Log IO wait time of the Object/Query/Plan in the interval 86 | -- 87 | -- [Wait_NetworkIO] BIGINT NOT NULL 88 | -- Total Network IO wait time of the Object/Query/Plan in the interval 89 | -- 90 | -- [Wait_Parallelism] BIGINT NOT NULL 91 | -- Total Paralellism wait time of the Object/Query/Plan in the interval 92 | -- 93 | -- [Wait_Memory] BIGINT NOT NULL 94 | -- Total Memory wait time of the Object/Query/Plan in the interval 95 | -- 96 | -- [Wait_UserWait] BIGINT NOT NULL 97 | -- Total User wait time of the Object/Query/Plan in the interval 98 | -- 99 | -- [Wait_Tracing] BIGINT NOT NULL 100 | -- Total Tracing wait time of the Object/Query/Plan in the interval 101 | -- 102 | -- [Wait_FullTextSearch] BIGINT NOT NULL 103 | -- Total FullText Search wait time of the Object/Query/Plan in the interval 104 | -- 105 | -- [Wait_OtherDiskIO] BIGINT NOT NULL 106 | -- Total Other Disk IO wait time of the Object/Query/Plan in the interval 107 | -- 108 | -- [Wait_Replication] BIGINT NOT NULL 109 | -- Total Replication wait time of the Object/Query/Plan in the interval 110 | -- 111 | -- [Wait_LogRateGovernor] BIGINT NOT NULL 112 | -- Total Log Rate Governor wait time of the Object/Query/Plan in the interval 113 | -- 114 | -- 115 | -- Date: 2020.10.22 116 | -- Auth: Pablo Lozano (@sqlozano) 117 | -- 118 | ---------------------------------------------------------------------------------- 119 | 120 | DROP TABLE IF EXISTS [dbo].[QueryWaitsStore] 121 | CREATE TABLE [dbo].[QueryWaitsStore] 122 | ( 123 | [ReportID] BIGINT NOT NULL 124 | ,[PlanID] BIGINT NOT NULL 125 | ,[QueryID] BIGINT NOT NULL 126 | ,[QueryTextID] BIGINT NOT NULL 127 | ,[StartTime] DATETIME2 NOT NULL 128 | ,[EndTime] DATETIME2 NOT NULL 129 | ,[DifferentPlansUsed] INT NOT NULL 130 | ,[DifferentQueriesUsed] INT NOT NULL 131 | ,[Total_Duration] BIGINT NOT NULL 132 | ,[Total_CPUTime] BIGINT NOT NULL 133 | ,[Total_CLRTime] BIGINT NOT NULL 134 | ,[Total_Wait] BIGINT NOT NULL 135 | ,[Wait_CPU] BIGINT NOT NULL 136 | ,[Wait_WorkerThread] BIGINT NOT NULL 137 | ,[Wait_Lock] BIGINT NOT NULL 138 | ,[Wait_Latch] BIGINT NOT NULL 139 | ,[Wait_BufferLatch] BIGINT NOT NULL 140 | ,[Wait_BufferIO] BIGINT NOT NULL 141 | ,[Wait_Compilation] BIGINT NOT NULL 142 | ,[Wait_SQLCLR] BIGINT NOT NULL 143 | ,[Wait_Mirroring] BIGINT NOT NULL 144 | ,[Wait_Transaction] BIGINT NOT NULL 145 | ,[Wait_Idle] BIGINT NOT NULL 146 | ,[Wait_Preemptive] BIGINT NOT NULL 147 | ,[Wait_ServiceBroker] BIGINT NOT NULL 148 | ,[Wait_TranLogIO] BIGINT NOT NULL 149 | ,[Wait_NetworkIO] BIGINT NOT NULL 150 | ,[Wait_Parallelism] BIGINT NOT NULL 151 | ,[Wait_Memory] BIGINT NOT NULL 152 | ,[Wait_UserWait] BIGINT NOT NULL 153 | ,[Wait_Tracing] BIGINT NOT NULL 154 | ,[Wait_FullTextSearch] BIGINT NOT NULL 155 | ,[Wait_OtherDiskIO] BIGINT NOT NULL 156 | ,[Wait_Replication] BIGINT NOT NULL 157 | ,[Wait_LogRateGovernor] BIGINT NOT NULL 158 | ) 159 | ALTER TABLE [dbo].[QueryWaitsStore] 160 | ADD CONSTRAINT [PK_QueryWaitsStore] PRIMARY KEY CLUSTERED 161 | ( 162 | [ReportID] ASC 163 | ,[StartTime] ASC 164 | ,[PlanID] ASC 165 | ,[QueryID] ASC 166 | ) -------------------------------------------------------------------------------- /QueryWaits/4-dbo.vQueryWaitsIndex.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vQueryWaitsIndex] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[QueryWaitsIndex] to extract the entry parameters used by the executions of [dbo].[QueryWaits] 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [ObjectID] BIGINT NOT NULL 20 | -- Identifier of the object (if any) whose wait times are being analyzed 21 | -- 22 | -- [SchemaName] NVARCHAR(128) NOT NULL 23 | -- Name of the schema of the object (if any) whose wait times are being analyzed 24 | -- 25 | -- [ObjectName] NVARCHAR(128) NOT NULL 26 | -- Name of the object (if any) whose wait times are being analyzed 27 | -- 28 | -- [QueryTextID] BIGINT NOT NULL 29 | -- Identifier of the Query Text (when only one is being analyzed) whose wait times are being analyzed 30 | -- 31 | -- [QueryText] VARBINARY(MAX) NULL 32 | -- Query Text (when only one is being analyzed) whose wait times are being analyzed 33 | -- 34 | -- [FullObjectName] NVARCHAR(256) NOT NULL 35 | -- Name of the Object (used as an entry parameter) 36 | -- 37 | -- [PlanID] BIGINT NOT NULL 38 | -- Identifier of the execution plan (used as an entry parameter) 39 | -- 40 | -- [QueryID] BIGINT NOT NULL 41 | -- Identifier of the query (used as an entry parameter) 42 | -- 43 | -- [StartTime] DATETIME2 NOT NULL 44 | -- Start time of the interval (in UTC) 45 | -- 46 | -- [EndTime] DATETIME2 NOT NULL 47 | -- Start time of the interval (in UTC) 48 | -- 49 | -- [IncludeQueryText] BIT NOT NULL 50 | -- Flag to include the query text in the report 51 | -- 52 | -- Date: 2020.10.22 53 | -- Auth: Pablo Lozano (@sqlozano) 54 | -- 55 | ---------------------------------------------------------------------------------- 56 | 57 | CREATE OR ALTER VIEW [dbo].[vQueryWaitsIndex] 58 | AS 59 | SELECT 60 | [wdi].[ReportID] 61 | ,[wdi].[CaptureDate] 62 | ,[wdi].[ServerIdentifier] 63 | ,[wdi].[DatabaseName] 64 | ,[wdi].[ObjectID] 65 | ,[wdi].[SchemaName] 66 | ,[wdi].[ObjectName] 67 | ,[wdi].[QueryTextID] 68 | ,CAST(DECOMPRESS([wdi].[QueryText]) AS NVARCHAR(MAX)) AS [QueryText] 69 | ,[q].[n].value('ObjectName[1]', 'NVARCHAR(256)') AS [FullObjectName] 70 | ,[q].[n].value('PlanID[1]', 'BIGINT') AS [PlanID] 71 | ,[q].[n].value('QueryID[1]', 'BIGINT') AS [QueryID] 72 | ,[q].[n].value('StartTime[1]', 'DATETIME2') AS [StartTime] 73 | ,[q].[n].value('EndTime[1]', 'DATETIME2') AS [EndTime] 74 | ,[q].[n].value('IncludeQueryText[1]', 'BIT') AS [IncludeQueryText] 75 | FROM [dbo].[QueryWaitsIndex] [wdi] 76 | CROSS APPLY [wdi].[Parameters].nodes('/Root/WaitDetailsParameters') AS q(n) 77 | GO -------------------------------------------------------------------------------- /QueryWaits/5-dbo.vQueryWaitsStore.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vQueryWaitsStore] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[QueryWaitsStore] to extract the metrics obtained by the execution of [dbo].[QueryWaits] 5 | -- Description of the wait categories can be found here: 6 | -- https://docs.microsoft.com/en-us/sql/relational-databases/system-catalog-views/sys-query-store-wait-stats-transact-sql?view=sql-server-ver15#wait-categories-mapping-table 7 | -- 8 | -- Columns: 9 | -- [ReportID] BIGINT NOT NULL 10 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 11 | -- 12 | -- [PlanID] BIGINT NOT NULL 13 | -- Identifier of the execution plan analyzed (when only one) 14 | -- 15 | -- [QueryID] BIGINT NOT NULL 16 | -- Identifier of the query analyzed (when only one) 17 | -- 18 | -- [QueryTextID] BIGINT NOT NULL 19 | -- Identifier of the query text analyzed (when only one) 20 | -- 21 | -- [StartTime] DATETIME2 NOT NULL 22 | -- Start Time of the interval whose metrics are represented in the next columns 23 | -- 24 | -- [EndTime] DATETIME2 NOT NULL 25 | -- End Time of the interval whose metrics are represented in the next columns 26 | -- 27 | -- [DifferentPlansUsed] INT NOT NULL 28 | -- Number of different plans used in the interval 29 | -- 30 | -- [DifferentQueriesUsed] INT NOT NULL 31 | -- Number of different queries used in the interval 32 | -- 33 | -- [Total_Duration] BIGINT NOT NULL 34 | -- Total duration of the Object/Query/Plan in the interval 35 | -- 36 | -- [Total_CPUTime] BIGINT NOT NULL 37 | -- Total CPU time of the Object/Query/Plan in the interval 38 | -- 39 | -- [Total_CLRTime] BIGINT NOT NULL 40 | -- Total CLR time of the Object/Query/Plan in the interval 41 | -- 42 | -- [Total_Wait] BIGINT NOT NULL 43 | -- Total wait time of the Object/Query/Plan in the interval 44 | -- 45 | -- [Wait_CPU] BIGINT NOT NULL 46 | -- Total CPU wait time of the Object/Query/Plan in the interval 47 | -- 48 | -- [Wait_WorkerThread] BIGINT NOT NULL 49 | -- Total Worker Thread wait time of the Object/Query/Plan in the interval 50 | -- 51 | -- [Wait_Lock] BIGINT NOT NULL 52 | -- Total Lock wait time of the Object/Query/Plan in the interval 53 | -- 54 | -- [Wait_Latch] BIGINT NOT NULL 55 | -- Total Latch wait time of the Object/Query/Plan in the interval 56 | -- 57 | -- [Wait_BufferLatch] BIGINT NOT NULL 58 | -- Total Buffer Latch wait time of the Object/Query/Plan in the interval 59 | -- 60 | -- [Wait_BufferIO] BIGINT NOT NULL 61 | -- Total Buffer IO wait time of the Object/Query/Plan in the interval 62 | -- 63 | -- [Wait_Compilation] BIGINT NOT NULL 64 | -- Total Compilation wait time of the Object/Query/Plan in the interval 65 | -- 66 | -- [Wait_SQLCLR] BIGINT NOT NULL 67 | -- Total SQL CLR wait time of the Object/Query/Plan in the interval 68 | -- 69 | -- [Wait_Mirroring] BIGINT NOT NULL 70 | -- Total Mirroring wait time of the Object/Query/Plan in the interval 71 | -- 72 | -- [Wait_Transaction] BIGINT NOT NULL 73 | -- Total Transaction wait time of the Object/Query/Plan in the interval 74 | -- 75 | -- [Wait_Idle] BIGINT NOT NULL 76 | -- Total Idle wait time of the Object/Query/Plan in the interval 77 | -- 78 | -- [Wait_Preemptive] BIGINT NOT NULL 79 | -- Total Preemptive wait time of the Object/Query/Plan in the interval 80 | -- 81 | -- [Wait_ServiceBroker] BIGINT NOT NULL 82 | -- Total Service Broker wait time of the Object/Query/Plan in the interval 83 | -- 84 | -- [Wait_TranLogIO] BIGINT NOT NULL 85 | -- Total Transactional Log IO wait time of the Object/Query/Plan in the interval 86 | -- 87 | -- [Wait_NetworkIO] BIGINT NOT NULL 88 | -- Total Network IO wait time of the Object/Query/Plan in the interval 89 | -- 90 | -- [Wait_Parallelism] BIGINT NOT NULL 91 | -- Total Paralellism wait time of the Object/Query/Plan in the interval 92 | -- 93 | -- [Wait_Memory] BIGINT NOT NULL 94 | -- Total Memory wait time of the Object/Query/Plan in the interval 95 | -- 96 | -- [Wait_UserWait] BIGINT NOT NULL 97 | -- Total User wait time of the Object/Query/Plan in the interval 98 | -- 99 | -- [Wait_Tracing] BIGINT NOT NULL 100 | -- Total Tracing wait time of the Object/Query/Plan in the interval 101 | -- 102 | -- [Wait_FullTextSearch] BIGINT NOT NULL 103 | -- Total FullText Search wait time of the Object/Query/Plan in the interval 104 | -- 105 | -- [Wait_OtherDiskIO] BIGINT NOT NULL 106 | -- Total Other Disk IO wait time of the Object/Query/Plan in the interval 107 | -- 108 | -- [Wait_Replication] BIGINT NOT NULL 109 | -- Total Replication wait time of the Object/Query/Plan in the interval 110 | -- 111 | -- [Wait_LogRateGovernor] BIGINT NOT NULL 112 | -- Total Log Rate Governor wait time of the Object/Query/Plan in the interval 113 | -- 114 | -- [QueryText] NVARCHAR(MAX) NULL 115 | -- Query Text of the corresponding [QueryTextID] (when included) 116 | -- 117 | -- Date: 2020.10.22 118 | -- Auth: Pablo Lozano (@sqlozano) 119 | -- 120 | ---------------------------------------------------------------------------------- 121 | 122 | CREATE OR ALTER VIEW [dbo].[vQueryWaitsStore] 123 | AS 124 | SELECT 125 | [wdi].[ReportID] 126 | ,[wds].[PlanID] 127 | ,[wds].[QueryID] 128 | ,[wds].[QueryTextID] 129 | ,[wds].[StartTime] 130 | ,[wds].[EndTime] 131 | ,[wds].[DifferentPlansUsed] 132 | ,[wds].[DifferentQueriesUsed] 133 | ,[wds].[Total_Duration] 134 | ,[wds].[Total_CPUTime] 135 | ,[wds].[Total_CLRTime] 136 | ,[wds].[Total_Wait] 137 | ,[wds].[Wait_CPU] 138 | ,[wds].[Wait_WorkerThread] 139 | ,[wds].[Wait_Lock] 140 | ,[wds].[Wait_Latch] 141 | ,[wds].[Wait_BufferLatch] 142 | ,[wds].[Wait_BufferIO] 143 | ,[wds].[Wait_Compilation] 144 | ,[wds].[Wait_SQLCLR] 145 | ,[wds].[Wait_Mirroring] 146 | ,[wds].[Wait_Transaction] 147 | ,[wds].[Wait_Idle] 148 | ,[wds].[Wait_Preemptive] 149 | ,[wds].[Wait_ServiceBroker] 150 | ,[wds].[Wait_TranLogIO] 151 | ,[wds].[Wait_NetworkIO] 152 | ,[wds].[Wait_Parallelism] 153 | ,[wds].[Wait_Memory] 154 | ,[wds].[Wait_UserWait] 155 | ,[wds].[Wait_Tracing] 156 | ,[wds].[Wait_FullTextSearch] 157 | ,[wds].[Wait_OtherDiskIO] 158 | ,[wds].[Wait_Replication] 159 | ,[wds].[Wait_LogRateGovernor] 160 | ,CAST(DECOMPRESS([wdi].[QueryText]) AS NVARCHAR(MAX)) AS [QueryText] 161 | FROM [dbo].[QueryWaitsStore] [wds] 162 | INNER JOIN [dbo].[QueryWaitsIndex] [wdi] 163 | ON [wds].[ReportID] = [wdi].[ReportID] -------------------------------------------------------------------------------- /QueryWaits/README.md: -------------------------------------------------------------------------------- 1 | # QueryWaits 2 | This tool analyzes the wait status for a given Object / Query / Plan, and returns the data along with the runtime times (CPU, CLR and Duration) to provide an overview on how long the Object / Query / Plan takes to complete, and how much of that time can be attributed to actual execution, waits on resources... 3 | \ 4 | (Supported in SQL 2017+: for SQL 2016 the execution of the stored procedure will return an error) 5 | 6 | --- 7 | ## Use cases and examples 8 | ### Object level waits 9 | Get the waits impacting a particular object's execution during a given period 10 | ``` 11 | EXECUTE dbo.QueryWaits 12 | @DatabaseName = 'TargetDB' 13 | ,@ObjectName = 'Schema.Object' 14 | ,@StartTime = '2020-01-01' 15 | ,@EndTime = '2020-02-01' 16 | ``` 17 | ### Query level waits 18 | Get the waits impacting a particular query's execution during a given period 19 | ``` 20 | EXECUTE dbo.QueryWaits 21 | @DatabaseName = 'TargetDB' 22 | ,@QueryID = 15648 23 | ,@StartTime = '2020-01-07 09:00' 24 | ,@EndTime = '2020-01-07 11:00' 25 | ``` 26 | 27 | ### Plan level waits 28 | Get the waits impacting a particular plan's execution during a given period, storing it into SQL tables along with the Query Text 29 | ``` 30 | EXECUTE dbo.QueryWaits 31 | @DatabaseName = 'TargetDB' 32 | ,@PlanID = 14865 33 | ,@StartTime = '2020-01-07 09:00' 34 | ,@EndTime = '2020-01-07 11:00' 35 | ,@ReportIndex = 'dbo.QueryWaitsIndex' 36 | ,@ReportTable = 'dbo.QueryWaitsStore' 37 | ,@IncludeQueryText = 1 38 | ``` -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | 2 | 3 | # QDS Toolbox 4 | This is a collection of tools (comprising a combination of views, procedures, functions...) developed using the Query Store functionality as a base to facilitate its usage and generating reports. These include but are not limited to: 5 | 6 | - Implementations of SSMS GUI reports that can be invoked using T-SQL code, with added functionality (parameterization, saving results to tables) so they can be programmatically executed and used to send out mails. 7 | 8 | - Quick analysis of a server's overall activity to identify bottlenecks and points of high pressure on the SQL instance at any given time, both in real time or in the past. 9 | 10 | - Cleanup of the QDS cache with a smaller footprint than the internal one generates, with added parameters to enable a customizable cleanup (such as removing information regarding dropped objects, and cleaning details of ad-hoc or internal queries executed on the server as index maintenance operations). 11 | 12 | - Analysis of execution plans, both from Query Store, SQL cache and files. 13 | 14 | All these tools have been tested on SQL Server 2016, 2017 and 2019 instances, both with Case Sensitive and Case Insensitive collations, and running on both Windows and Linux. 15 | 16 | Since Query Store did not capture all the information in SQL Server 2016 as it does in later versions, some functionality may be restricted. 17 | 18 | _(Original icon art by https://www.smashicons.com)_ 19 | -------------------------------------------------------------------------------- /ServerTopObjects/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /ServerTopObjects/1-dbo.ServerTopObjectsIndex.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[ServerTopObjectsIndex] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[ServerTopObjects] to store its entry parameters 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [Parameters] XML NULL 20 | -- List of parameters used to invoke the execution of [dbo].[ServerTopObjects] 21 | -- 22 | -- 23 | -- Date: 2022.10.18 24 | -- Auth: Pablo Lozano (@sqlozano) 25 | -- Desc: Created based on [dbo].[ServerTopQueriesIndex] 26 | ---------------------------------------------------------------------------------- 27 | 28 | DROP TABLE IF EXISTS [dbo].[ServerTopObjectsIndex] 29 | CREATE TABLE [dbo].[ServerTopObjectsIndex] 30 | ( 31 | [ReportID] BIGINT IDENTITY(1,1) 32 | ,[CaptureDate] DATETIME2 NOT NULL 33 | ,[ServerIdentifier] SYSNAME NOT NULL 34 | ,[DatabaseName] SYSNAME NOT NULL 35 | ,[Parameters] XML NOT NULL 36 | ) 37 | ALTER TABLE [dbo].[ServerTopObjectsIndex] 38 | ADD CONSTRAINT [PK_ServerTopObjectsIndex] PRIMARY KEY CLUSTERED 39 | ( 40 | [ReportID] 41 | ) -------------------------------------------------------------------------------- /ServerTopObjects/2-dbo.ServerTopObjectsStore.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[ServerTopObjectsStore] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[ServerTopObjects] to store the details returned by the execution of [dbo].[ServerTopObjects] 5 | -- 6 | -- [ReportID] BIGINT NOT NULL 7 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 8 | -- 9 | -- [DatabaseName] SYSNAME NOT NULL 10 | -- Name of the databse the information of the following columns has been extracted from 11 | -- 12 | -- [ObjectID] BIGINT NOT NULL 13 | -- Identifier of the object 14 | -- 15 | -- [ObjectQueryIDs] XML NULL 16 | -- Identifier of the queries part of the object associated to the corresponding [ObjectID] 17 | -- 18 | -- [SchemaName] SYSNAME NULL 19 | -- Name of the schema of the object associated to the corresponding [ObjectID] 20 | -- 21 | -- [ObjectName] SYSNAME NULL 22 | -- Name of the object associated to the corresponding [ObjectID] 23 | -- 24 | -- [ExecutionTypeDesc] NVARCHAR(120) NOT NULL 25 | -- Description of the execution type (Regular, Aborted, Exception) 26 | -- 27 | -- [EstimatedExecutionCount] BIGINT NOT NULL 28 | -- Estimate of the number of executions of the corresponding [ObjectID] and with the same [ExecutionTypeDes], based on the max number of subqueries executed 29 | -- 30 | -- [Duration] BIGINT NOT NULL 31 | -- Total duration of all executions of the corresponding [ObjectID] in microseconds 32 | -- 33 | -- [CPU] BIGINT NOT NULL 34 | -- Total CPU time of all executions of the corresponding [ObjectID] in microseconds 35 | -- 36 | -- [LogicalIOReads] BIGINT NOT NULL 37 | -- Total Logical IO reads of all executions of the corresponding [ObjectID] in 8 KB pages 38 | -- 39 | -- [LogicalIOWrites] BIGINT NOT NULL 40 | -- Total Logical IO Writes of all executions of the corresponding [ObjectID] in 8 KB pages 41 | -- 42 | -- [PhysicalIOReads] BIGINT NOT NULL 43 | -- Total Physical IO Reads of all executions of the corresponding [ObjectID] in 8 KB pages 44 | -- 45 | -- [CLR] BIGINT NOT NULL 46 | -- Total CLR time of all executions of the corresponding [ObjectID] in microseconds 47 | -- 48 | -- [Memory] BIGINT NOT NULL 49 | -- Total Memory usage of all executions of the corresponding [ObjectID] in 8 KB pages 50 | -- 51 | -- [LogBytes] BIGINT NULL 52 | -- Total Log bytes usage of all executions of the corresponding [ObjectID] in Bytes 53 | -- NULL for SQL 2016 (the metric is not registered in this version) 54 | -- 55 | -- [TempDBSpace] BIGINT NULL 56 | -- Total TempDB space usage of all executions of the corresponding [ObjectID] in 8 KB pages 57 | -- NULL for SQL 2016 (the metric is not registered in this version) 58 | -- 59 | -- 60 | -- Date: 2022.10.18 61 | -- Auth: Pablo Lozano (@sqlozano) 62 | -- Desc: Created based on [dbo].[ServerTopQueriesStore] 63 | ---------------------------------------------------------------------------------- 64 | 65 | DROP TABLE IF EXISTS [dbo].[ServerTopObjectsStore] 66 | CREATE TABLE [dbo].[ServerTopObjectsStore] 67 | ( 68 | [ReportID] BIGINT NOT NULL 69 | ,[DatabaseName] SYSNAME NOT NULL 70 | ,[ObjectID] BIGINT NOT NULL 71 | ,[ObjectQueryIDs] XML NULL 72 | ,[SchemaName] SYSNAME NOT NULL 73 | ,[ObjectName] SYSNAME NOT NULL 74 | ,[ExecutionTypeDesc] NVARCHAR(120) NOT NULL 75 | ,[EstimatedExecutionCount] BIGINT NOT NULL 76 | ,[Duration] BIGINT NOT NULL 77 | ,[CPU] BIGINT NOT NULL 78 | ,[LogicalIOReads] BIGINT NOT NULL 79 | ,[LogicalIOWrites] BIGINT NOT NULL 80 | ,[PhysicalIOReads] BIGINT NOT NULL 81 | ,[CLR] BIGINT NOT NULL 82 | ,[Memory] BIGINT NOT NULL 83 | ,[LogBytes] BIGINT NULL 84 | ,[TempDBSpace] BIGINT NULL 85 | ) 86 | ALTER TABLE [dbo].[ServerTopObjectsStore] 87 | ADD CONSTRAINT [PK_ServerTopObjectsStore] PRIMARY KEY CLUSTERED 88 | ( 89 | [ReportID] ASC 90 | ,[DatabaseName] ASC 91 | ,[SchemaName] ASC 92 | ,[ObjectName] ASC 93 | ,[ExecutionTypeDesc] ASC 94 | ) -------------------------------------------------------------------------------- /ServerTopObjects/3-dbo.vServerTopObjectsIndex.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vServerTopObjectsIndex] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[ServerTopObjectsIndex] to extract the entry parameters used by the executions of [dbo].[ServerTopObjects] 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [StartTime] DATETIME2 NOT NULL 20 | -- Start time of the period being analyzed 21 | -- 22 | -- [EndTime] DATETIME2 NOT NULL 23 | -- End time of the period being analyzed 24 | -- 25 | -- [Top] IN NOT NULL 26 | -- Maximum number of queries to be extracted from each database selected 27 | -- 28 | -- [Measurement] NVARCHAR(32) NOT NULL 29 | -- Measurement to order the queries on 30 | -- 31 | -- [Percentages] BIT NOT NULL 32 | -- Flag to determine whether the values are "percentages" 33 | -- When enabled, the [Measurement] values will go from 0 to 100000 (equivalent to 0% to 100%) 34 | -- 35 | -- [AggregateAll] BIT NOT NULL 36 | -- Flag to determine whether all query executions are aggregated 37 | -- 38 | -- [AggregateNonRegular] BIT NOT NULL 39 | -- Flag to determine whether all query executions that didn't have a "regular" exit are aggregated together 40 | -- 41 | -- [IncludeAdhocQueryIDs] BIT NOT NULL 42 | -- Flag to determine the Adhoc Queries are considered for the report 43 | -- 44 | -- [IncludeObjectQueryIDs] BIT NOT NULL 45 | -- Flag to determine whether the individual queries of the Object (or the totality of the Adhoc queries) are included in the report 46 | -- 47 | -- 48 | -- Date: 2022.10.18 49 | -- Auth: Pablo Lozano (@sqlozano) 50 | -- Desc: Created based on [dbo].[vServerTopQueriesIndex] 51 | -- 52 | -- Date: 2022.10.19 53 | -- Auth: Pablo Lozano (@sqlozano) 54 | -- Changes: Added missing description for the columns: [AggregateAll], [AggregateNonRegular] 55 | -- Added columns for new parameters: [IncludeAdhocQueryIDs], [IncludeObjectQueryIDs] 56 | ---------------------------------------------------------------------------------- 57 | 58 | CREATE OR ALTER VIEW [dbo].[vServerTopObjectsIndex] 59 | AS 60 | SELECT 61 | [ReportID] 62 | ,[CaptureDate] 63 | ,[ServerIdentifier] 64 | ,[DatabaseName] 65 | ,q.n.value('StartTime[1]', 'DATETIME2') AS [StartTime] 66 | ,q.n.value('EndTime[1]', 'DATETIME2') AS [EndTime] 67 | ,q.n.value('Top[1]', 'INT') AS [Top] 68 | ,q.n.value('Measurement[1]', 'NVARCHAR(32)') AS [Measurement] 69 | ,q.n.value('Percentages[1]', 'BIT') AS [Percentages] 70 | ,q.n.value('AggregateAll[1]', 'BIT') AS [AggregateAll] 71 | ,q.n.value('AggregateNonRegular[1]','BIT') AS [AggregateNonRegular] 72 | ,q.n.value('IncludeAdhocQueryIDs[1]','BIT') AS [IncludeAdhocQueryIDs] 73 | ,q.n.value('IncludeObjectQueryIDs[1]','BIT') AS [IncludeObjectQueryIDs] 74 | FROM [dbo].[ServerTopObjectsIndex] [stoi] 75 | CROSS APPLY [stoi].[Parameters].nodes('/Root/ServerTopObjectsParameters') AS q(n) 76 | GO -------------------------------------------------------------------------------- /ServerTopObjects/4-dbo.vServerTopObjectsStore.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vServerTopObjectsStore] 3 | -- 4 | -- Desc: This view is built on top of [ServerTopObjectsStore] to extract the details of the top queries identified by the execution of [dbo].[ServerTopObjects] 5 | -- 6 | -- [ReportID] BIGINT NOT NULL 7 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 8 | -- 9 | -- [DatabaseName] SYSNAME NOT NULL 10 | -- Name of the databse the information of the following columns has been extracted from 11 | -- 12 | -- [ObjectID] BIGINT NOT NULL 13 | -- Identifier of the object 14 | -- 15 | -- [ObjectQueryIDs] XML NULL 16 | -- Identifier of the queries part of the object associated to the corresponding [ObjectID] 17 | -- 18 | -- [SchemaName] SYSNAME NULL 19 | -- Name of the object's schema 20 | -- 21 | -- [ObjectName] SYSNAME NULL 22 | -- Name of the object 23 | -- 24 | -- [ExecutionTypeDesc] NVARCHAR(120) NOT NULL 25 | -- Description of the execution type (Regular, Aborted, Exception) 26 | -- 27 | -- [EstimatedExecutionCount] BIGINT NOT NULL 28 | -- Number of executions of the corresponding [ObjectID] and with the same [ExecutionTypeDes] 29 | -- 30 | -- [Duration] BIGINT NOT NULL 31 | -- Total duration of all executions of the corresponding [ObjectID] in microseconds 32 | -- 33 | -- [CPU] BIGINT NOT NULL 34 | -- Total CPU time of all executions of the corresponding [ObjectID] in microseconds 35 | -- 36 | -- [LogicalIOReads] BIGINT NOT NULL 37 | -- Total Logical IO reads of all executions of the corresponding [ObjectID] in 8 KB pages 38 | -- 39 | -- [LogicalIOWrites] BIGINT NOT NULL 40 | -- Total Logical IO Writes of all executions of the corresponding [ObjectID] in 8 KB pages 41 | -- 42 | -- [PhysicalIOReads] BIGINT NOT NULL 43 | -- Total Physical IO Reads of all executions of the corresponding [ObjectID] in 8 KB pages 44 | -- 45 | -- [CLR] BIGINT NOT NULL 46 | -- Total CLR time of all executions of the corresponding [ObjectID] in microseconds 47 | -- 48 | -- [Memory] BIGINT NOT NULL 49 | -- Total Memory usage of all executions of the corresponding [ObjectID] in 8 KB pages 50 | -- 51 | -- [LogBytes] BIGINT NULL 52 | -- Total Log bytes usage of all executions of the corresponding [ObjectID] in Bytes 53 | -- NULL for SQL 2016 (the metric is not registered in this version) 54 | -- 55 | -- [TempDBSpace] BIGINT NULL 56 | -- Total TempDB space usage of all executions of the corresponding [ObjectID] in 8 KB pages 57 | -- NULL for SQL 2016 (the metric is not registered in this version) 58 | -- 59 | -- Date: 2022.10.18 60 | -- Auth: Pablo Lozano (@sqlozano) 61 | -- Desc: Created based on [dbo].[vServerTopObjectsStore] 62 | ---------------------------------------------------------------------------------- 63 | 64 | CREATE OR ALTER VIEW [dbo].[vServerTopObjectsStore] 65 | AS 66 | SELECT 67 | [stoi].[ReportID] 68 | ,[stoi].[CaptureDate] 69 | ,[stoi].[ServerIdentifier] 70 | ,[stoi].[Measurement] 71 | ,[stoi].[Percentages] 72 | ,[stos].[DatabaseName] 73 | ,[stos].[ObjectID] 74 | ,[stos].[ObjectQueryIDs] 75 | ,[stos].[SchemaName] 76 | ,[stos].[ObjectName] 77 | ,[stos].[ExecutionTypeDesc] 78 | ,[stos].[EstimatedExecutionCount] 79 | ,[stos].[Duration] 80 | ,[stos].[CPU] 81 | ,[stos].[LogicalIOReads] 82 | ,[stos].[LogicalIOWrites] 83 | ,[stos].[PhysicalIOReads] 84 | ,[stos].[CLR] 85 | ,[stos].[Memory] 86 | ,[stos].[LogBytes] 87 | ,[stos].[TempDBSpace] 88 | FROM [dbo].[vServerTopObjectsIndex] [stoi] 89 | INNER JOIN [dbo].[ServerTopObjectsStore] [stos] 90 | ON [stoi].[ReportID] = [stos].[ReportID] -------------------------------------------------------------------------------- /ServerTopObjects/README.md: -------------------------------------------------------------------------------- 1 | # ServerTopObjects 2 | 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). 3 | \ 4 | Can optionally include ad hoc queries aggregated under a "virtual" object 5 | \ 6 | (SQL 2016 does not support @Measurement = 'log_bytes_used' / 'tempdb_space_used') 7 | \ 8 | 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 9 | ## Use cases and examples 10 | ### Objects with a high CPU consumption (results in microseconds) 11 | Get a list of objects (top 10 per database), aggregating all exit results of the objects 12 | ``` 13 | EXECUTE [dbo].[ServerTopObjects] 14 | @Measurement = 'cpu_time' 15 | ,@Top = 10 16 | ,@AggregateAll = 1 17 | ``` 18 | ### Objects with a high CPU consumption (results in microseconds) and their corresponding subqueries (subqueries ordered by cpu_time too) 19 | Get a list of objects (top 10 per database), aggregating all exit results of the objects 20 | ``` 21 | EXECUTE [dbo].[ServerTopObjects] 22 | @Measurement = 'cpu_time' 23 | ,@Top = 10 24 | ,@AggregateAll = 1 25 | ,@IncludeObjectQueryIDs = 1 26 | ``` 27 | ### Objects with a high CPU consumption (results in percentage) 28 | Get a list of objects (top 10 per database), aggregating all exit results of the objects 29 | 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 30 | This is done rather than returning a DECIMAL value so that the BIGINT measurement columns in the [dbo].[ServerTopObjects] table can be reused. 31 | ``` 32 | EXECUTE [dbo].[ServerTopObjects] 33 | @Measurement = 'cpu_time' 34 | ,@Top = 10 35 | ,@AggregateAll = 1 36 | ``` 37 | ### Objects / Ad hoc queries with highest TempDB usage for a given database 38 | Store a list with the top 50 objects (or aggregation of all adhoc queries) with the highest TempDB usage for the database TargetDB, 39 | ``` 40 | EXECUTE [dbo].[ServerTopObjects] 41 | @DatabaseName = 'TargetDB' 42 | ,@ReportIndex = 'dbo.ServerTopObjectsIndex' 43 | ,@ReportTable = 'dbo.ServerTopObjectsStore' 44 | ,@Measurement = 'tempdb_space_used' 45 | ,@Top = 50 46 | ,@AggregateAll = 1 47 | ,@IncludeAdhocQueries = 0 48 | ``` 49 | 50 | ## Suggested uses 51 | ### High CPU analysis 52 | 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. 53 | ### Compare adhoc & objects 54 | 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 -------------------------------------------------------------------------------- /ServerTopQueries/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /ServerTopQueries/1-dbo.ServerTopQueriesIndex.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[ServerTopQueriesIndex] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[ServerTopQueries] to store its entry parameters 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [Parameters] XML NULL 20 | -- List of parameters used to invoke the execution of [dbo].[ServerTopQueries] 21 | -- 22 | -- 23 | -- Date: 2020.10.22 24 | -- Auth: Pablo Lozano (@sqlozano) 25 | -- 26 | -- Date: 2021.05.08 27 | -- Auth: Pablo Lozano (@sqlozano) 28 | -- Changed script logic to drop & recreate table 29 | ---------------------------------------------------------------------------------- 30 | 31 | DROP TABLE IF EXISTS [dbo].[ServerTopQueriesIndex] 32 | CREATE TABLE [dbo].[ServerTopQueriesIndex] 33 | ( 34 | [ReportID] BIGINT IDENTITY(1,1) 35 | ,[CaptureDate] DATETIME2 NOT NULL 36 | ,[ServerIdentifier] SYSNAME NOT NULL 37 | ,[DatabaseName] SYSNAME NOT NULL 38 | ,[Parameters] XML NOT NULL 39 | ) 40 | ALTER TABLE [dbo].[ServerTopQueriesIndex] 41 | ADD CONSTRAINT [PK_ServerTopQueriesIndex] PRIMARY KEY CLUSTERED 42 | ( 43 | [ReportID] 44 | ) -------------------------------------------------------------------------------- /ServerTopQueries/2-dbo.ServerTopQueriesStore.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[ServerTopQueriesStore] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[ServerTopQueries] to store the details returned by the execution of [dbo].[ServerTopQueries] 5 | -- 6 | -- [ReportID] BIGINT NOT NULL 7 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 8 | -- 9 | -- [DatabaseName] SYSNAME NOT NULL 10 | -- Name of the databse the information of the following columns has been extracted from 11 | -- 12 | -- [QueryID] BIGINT NOT NULL 13 | -- Identifier of the query the statistics are associated to 14 | -- 15 | -- [MinNumberPlans] INT NOT NULL 16 | -- Minimum number of execution plans found for the QueryID 17 | -- 18 | -- [QueryTextID] BIGINT NOT NULL 19 | -- Identifier of the Query Text belonging to the corresponding [QueryID] 20 | -- 21 | -- [ObjectID] BIGINT NOT NULL 22 | -- Identifier of the object associated to the corresponding [QueryID] (if any) 23 | -- 24 | -- [SchemaName] SYSNAME NULL 25 | -- Name of the schema of the object associated to the corresponding [QueryID] (if any) 26 | -- 27 | -- [ObjectName] SYSNAME NULL 28 | -- Name of the object associated to the corresponding [QueryID] (if any) 29 | -- 30 | -- [ExecutionTypeDesc] NVARCHAR(120) NOT NULL 31 | -- Description of the execution type (Regular, Aborted, Exception) 32 | -- 33 | -- [ExecutionCount] BIGINT NOT NULL 34 | -- Number of executions of the corresponding [PlanID] and with the same [ExecutionTypeDes] 35 | -- 36 | -- [Duration] BIGINT NOT NULL 37 | -- Total duration of all executions of the corresponding [PlanID] in microseconds 38 | -- 39 | -- [CPU] BIGINT NOT NULL 40 | -- Total CPU time of all executions of the corresponding [PlanID] in microseconds 41 | -- 42 | -- [LogicalIOReads] BIGINT NOT NULL 43 | -- Total Logical IO reads of all executions of the corresponding [PlanID] in 8 KB pages 44 | -- 45 | -- [LogicalIOWrites] BIGINT NOT NULL 46 | -- Total Logical IO Writes of all executions of the corresponding [PlanID] in 8 KB pages 47 | -- 48 | -- [PhysicalIOReads] BIGINT NOT NULL 49 | -- Total Physical IO Reads of all executions of the corresponding [PlanID] in 8 KB pages 50 | -- 51 | -- [CLR] BIGINT NOT NULL 52 | -- Total CLR time of all executions of the corresponding [PlanID] in microseconds 53 | -- 54 | -- [Memory] BIGINT NOT NULL 55 | -- Total Memory usage of all executions of the corresponding [PlanID] in 8 KB pages 56 | -- 57 | -- [LogBytes] BIGINT NULL 58 | -- Total Log bytes usage of all executions of the corresponding [PlanID] in Bytes 59 | -- NULL for SQL 2016 (the metric is not registered in this version) 60 | -- 61 | -- [TempDBSpace] BIGINT NULL 62 | -- Total TempDB space usage of all executions of the corresponding [PlanID] in 8 KB pages 63 | -- NULL for SQL 2016 (the metric is not registered in this version) 64 | -- 65 | -- [QuerySqlText] VARBINARY(MAX) NULL 66 | -- Query Text (compressed) corresponding to the [PlanID] 67 | -- 68 | -- Date: 2020.10.22 69 | -- Auth: Pablo Lozano (@sqlozano) 70 | -- 71 | -- Date: 2021.02.28 72 | -- Auth: Pablo Lozano (@sqlozano) 73 | -- Changes: [LogBytes] and [TempDBSpace] metrics allow NULLs to allow compatibility with SQL 2016 (which did not include this features) 74 | -- 75 | -- Date: 2021.05.08 76 | -- Auth: Pablo Lozano (@sqlozano) 77 | -- Changes: Modified script logic to drop & recreate table 78 | -- 79 | -- Date: 2021.08.19 80 | -- Auth: Pablo Lozano (@sqlozano) 81 | -- Changes: Modified table to replace [PlanID] with [MinNumberPlans] 82 | ---------------------------------------------------------------------------------- 83 | 84 | DROP TABLE IF EXISTS [dbo].[ServerTopQueriesStore] 85 | CREATE TABLE [dbo].[ServerTopQueriesStore] 86 | ( 87 | [ReportID] BIGINT NOT NULL 88 | ,[DatabaseName] SYSNAME NOT NULL 89 | ,[QueryID] BIGINT NOT NULL 90 | ,[MinNumberPlans] INT NOT NULL 91 | ,[QueryTextID] BIGINT NOT NULL 92 | ,[ObjectID] BIGINT NOT NULL 93 | ,[SchemaName] SYSNAME NULL 94 | ,[ObjectName] SYSNAME NULL 95 | ,[ExecutionTypeDesc] NVARCHAR(120) NOT NULL 96 | ,[ExecutionCount] BIGINT NOT NULL 97 | ,[Duration] BIGINT NOT NULL 98 | ,[CPU] BIGINT NOT NULL 99 | ,[LogicalIOReads] BIGINT NOT NULL 100 | ,[LogicalIOWrites] BIGINT NOT NULL 101 | ,[PhysicalIOReads] BIGINT NOT NULL 102 | ,[CLR] BIGINT NOT NULL 103 | ,[Memory] BIGINT NOT NULL 104 | ,[LogBytes] BIGINT NULL 105 | ,[TempDBSpace] BIGINT NULL 106 | ,[QuerySqlText] VARBINARY(MAX) NULL 107 | ) 108 | ALTER TABLE [dbo].[ServerTopQueriesStore] 109 | ADD CONSTRAINT [PK_ServerTopQueriesStore] PRIMARY KEY CLUSTERED 110 | ( 111 | [ReportID] ASC 112 | ,[DatabaseName] ASC 113 | ,[QueryID] ASC 114 | ,[ExecutionTypeDesc] ASC 115 | ) -------------------------------------------------------------------------------- /ServerTopQueries/3-dbo.vServerTopQueriesIndex.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vServerTopQueriesIndex] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[ServerTopQueriesIndex] to extract the entry parameters used by the executions of [dbo].[ServerTopQueries] 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [StartTime] DATETIME2 NOT NULL 20 | -- Start time of the period being analyzed 21 | -- 22 | -- [EndTime] DATETIME2 NOT NULL 23 | -- End time of the period being analyzed 24 | -- 25 | -- [Top] IN NOT NULL 26 | -- Maximum number of queries to be extracted from each database selected 27 | -- 28 | -- [Measurement] NVARCHAR(32) NOT NULL 29 | -- Measurement to order the queries on 30 | -- 31 | -- [Percentages] BIT NOT NULL 32 | -- Flag to determine whether the values are "percentages" 33 | -- When enabled, the [Measurement] values will go from 0 to 100000 (equivalent to 0% to 100%) 34 | -- 35 | -- [IncludeQueryText] BIT NOT NULL 36 | -- Flag to include the Query Text in the results generated 37 | -- 38 | -- [ExcludeAdhoc] BIT NOT NULL 39 | -- Flag to exclude adhoc queries (not beloging to any database object) 40 | -- 41 | -- [ExcludeInternal] BIT NOT NULL 42 | -- Flag to exclude internal queries (UPDATE STATISTICS, INDEX REBUILD....) 43 | -- 44 | -- [AggregateAll] BIT NOT NULL 45 | -- Flag to determine whether all query executions are aggregated 46 | -- 47 | -- [AggregateNonRegular] BIT NOT NULL 48 | -- Flag to determine whether all query executions that didn't have a "regular" exit are aggregated together 49 | -- 50 | -- 51 | -- Date: 2020.10.22 52 | -- Auth: Pablo Lozano (@sqlozano) 53 | -- 54 | -- Date: 2021.08.19 55 | -- Auth: Pablo Lozano (@sqlozano) 56 | -- Changes: Added new parameters: @ExecutionRegular, @ExecutionAborted, @ExecutionException, @AggregateAll, @AggregateNonRegular 57 | -- 58 | -- Date: 2021.08.25 59 | -- Auth: Pablo Lozano (@sqlozano) 60 | -- Changes: Removed parameters: @ExecutionRegular, @ExecutionAborted, @ExecutionException after removing them from the procedure 61 | -- 62 | -- Date: 2021.10.15 63 | -- Auth: Pablo Lozano (@sqlozano) 64 | -- Changes: Added parameter: @Percentages 65 | -- 66 | -- Date: 2022.10.19 67 | -- Auth: Pablo Lozano (@sqlozano) 68 | -- Changes: Added missing description for the columns: [AggregateAll], [AggregateNonRegular] 69 | ---------------------------------------------------------------------------------- 70 | 71 | CREATE OR ALTER VIEW [dbo].[vServerTopQueriesIndex] 72 | AS 73 | SELECT 74 | [ReportID] 75 | ,[CaptureDate] 76 | ,[ServerIdentifier] 77 | ,[DatabaseName] 78 | ,q.n.value('StartTime[1]', 'DATETIME2') AS [StartTime] 79 | ,q.n.value('EndTime[1]', 'DATETIME2') AS [EndTime] 80 | ,q.n.value('Top[1]', 'INT') AS [Top] 81 | ,q.n.value('Measurement[1]', 'NVARCHAR(32)') AS [Measurement] 82 | ,q.n.value('Percentages[1]', 'BIT') AS [Percentages] 83 | ,q.n.value('IncludeQueryText[1]', 'BIT') AS [IncludeQueryText] 84 | ,q.n.value('ExcludeAdhoc[1]', 'BIT') AS [ExcludeAdhoc] 85 | ,q.n.value('ExcludeInternal[1]', 'BIT') AS [ExcludeInternal] 86 | ,q.n.value('AggregateAll[1]', 'BIT') AS [AggregateAll] 87 | ,q.n.value('AggregateNonRegular[1]','BIT') AS [AggregateNonRegular] 88 | FROM [dbo].[ServerTopQueriesIndex] [stqi] 89 | CROSS APPLY [stqi].[Parameters].nodes('/Root/ServerTopQueriesParameters') AS q(n) 90 | GO -------------------------------------------------------------------------------- /ServerTopQueries/4-dbo.vServerTopQueriesStore.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vServerTopQueriesStore] 3 | -- 4 | -- Desc: This view is built on top of [ServerTopQueriesStore] to extract the details of the top queries identified by the execution of [dbo].[ServerTopQueries] 5 | -- 6 | -- [ReportID] BIGINT NOT NULL 7 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 8 | -- 9 | -- [DatabaseName] SYSNAME NOT NULL 10 | -- Name of the databse the information of the following columns has been extracted from 11 | -- 12 | -- [QueryID] BIGINT NOT NULL 13 | -- Identifier of the query the statistics are associated to 14 | -- 15 | -- [MinNumberPlans] INT NOT NULL 16 | -- Minimum number of execution plans found for the QueryID 17 | -- 18 | -- [QueryTextID] BIGINT NOT NULL 19 | -- Identifier of the Query Text belonging to the corresponding [QueryID] 20 | -- 21 | -- [ObjectID] BIGINT NOT NULL 22 | -- Identifier of the object associated to the corresponding [QueryID] (if any) 23 | -- 24 | -- [SchemaName] SYSNAME NULL 25 | -- Name of the schema of the object associated to the corresponding [QueryID] (if any) 26 | -- 27 | -- [ObjectName] SYSNAME NULL 28 | -- Name of the object associated to the corresponding [QueryID] (if any) 29 | -- 30 | -- [ExecutionTypeDesc] NVARCHAR(120) NOT NULL 31 | -- Description of the execution type (Regular, Aborted, Exception) 32 | -- 33 | -- [ExecutionCount] BIGINT NOT NULL 34 | -- Number of executions of the corresponding [PlanID] and with the same [ExecutionTypeDes] 35 | -- 36 | -- [Duration] BIGINT NOT NULL 37 | -- Total duration of all executions of the corresponding [PlanID] in microseconds 38 | -- 39 | -- [CPU] BIGINT NOT NULL 40 | -- Total CPU time of all executions of the corresponding [PlanID] in microseconds 41 | -- 42 | -- [LogicalIOReads] BIGINT NOT NULL 43 | -- Total Logical IO reads of all executions of the corresponding [PlanID] in 8 KB pages 44 | -- 45 | -- [LogicalIOWrites] BIGINT NOT NULL 46 | -- Total Logical IO Writes of all executions of the corresponding [PlanID] in 8 KB pages 47 | -- 48 | -- [PhysicalIOReads] BIGINT NOT NULL 49 | -- Total Physical IO Reads of all executions of the corresponding [PlanID] in 8 KB pages 50 | -- 51 | -- [CLR] BIGINT NOT NULL 52 | -- Total CLR time of all executions of the corresponding [PlanID] in microseconds 53 | -- 54 | -- [Memory] BIGINT NOT NULL 55 | -- Total Memory usage of all executions of the corresponding [PlanID] in 8 KB pages 56 | -- 57 | -- [LogBytes] BIGINT NULL 58 | -- Total Log bytes usage of all executions of the corresponding [PlanID] in Bytes 59 | -- NULL for SQL 2016 (the metric is not registered in this version) 60 | -- 61 | -- [TempDBSpace] BIGINT NULL 62 | -- Total TempDB space usage of all executions of the corresponding [PlanID] in 8 KB pages 63 | -- NULL for SQL 2016 (the metric is not registered in this version) 64 | -- 65 | -- [QuerySqlText] NVARCHAR(MAX) NULL 66 | -- Query Text corresponding to the [PlanID] 67 | -- 68 | -- Date: 2020.10.22 69 | -- Auth: Pablo Lozano (@sqlozano) 70 | -- 71 | -- Date: 2021.08.19 72 | -- Auth: Pablo Lozano (@sqlozano) 73 | -- Changes: Modified view to replace [PlanID] with [MinNumberPlans] 74 | -- 75 | -- Date: 2021.10.15 76 | -- Auth: Pablo Lozano (@sqlozano) 77 | -- Changes: Added column [Percentages] for new parameter @Percentages 78 | ---------------------------------------------------------------------------------- 79 | 80 | CREATE OR ALTER VIEW [dbo].[vServerTopQueriesStore] 81 | AS 82 | SELECT 83 | [stqi].[ReportID] 84 | ,[stqi].[CaptureDate] 85 | ,[stqi].[ServerIdentifier] 86 | ,[stqi].[Measurement] 87 | ,[stqi].[Percentages] 88 | ,[stqs].[DatabaseName] 89 | ,[stqs].[QueryID] 90 | ,[stqs].[MinNumberPlans] 91 | ,[stqs].[QueryTextID] 92 | ,[stqs].[ObjectID] 93 | ,[stqs].[SchemaName] 94 | ,[stqs].[ObjectName] 95 | ,[stqs].[ExecutionTypeDesc] 96 | ,[stqs].[ExecutionCount] 97 | ,[stqs].[Duration] 98 | ,[stqs].[CPU] 99 | ,[stqs].[LogicalIOReads] 100 | ,[stqs].[LogicalIOWrites] 101 | ,[stqs].[PhysicalIOReads] 102 | ,[stqs].[CLR] 103 | ,[stqs].[Memory] 104 | ,[stqs].[LogBytes] 105 | ,[stqs].[TempDBSpace] 106 | ,CAST(DECOMPRESS([stqs].[QuerySqlText]) AS NVARCHAR(MAX)) AS [QuerySqlText] 107 | FROM [dbo].[vServerTopQueriesIndex] [stqi] 108 | INNER JOIN [dbo].[ServerTopQueriesStore] [stqs] 109 | ON [stqi].[ReportID] = [stqs].[ReportID] -------------------------------------------------------------------------------- /ServerTopQueries/README.md: -------------------------------------------------------------------------------- 1 | # ServerTopQueries 2 | This tool provides uses the runtime stats for each database on the server to get a list of the TOP XX queries on each database, ordered by any of the measurements Query Store keeps track off (totals). 3 | \ 4 | (SQL 2016 does not support @Measurement = 'log_bytes_used' / 'tempdb_space_used') 5 | ## Use cases and examples 6 | ### Queries with a high CPU consumption (results in microseconds) 7 | Get a list of queries (top 10 per database) along with their query text, aggregating all exit results of the queries 8 | ``` 9 | EXECUTE [dbo].[ServerTopQueries] 10 | @Measurement = 'cpu_time' 11 | ,@Top = 10 12 | ,@AggregateAll = 1 13 | ,@IncludeQueryText = 1 14 | ``` 15 | ### Queries with a high CPU consumption (results in percentage) 16 | Get a list of queries (top 10 per database) along with their query text, aggregating all exit results of the queries 17 | 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 18 | This is done rather than returning a DECIMAL value so that the BIGINT measurement columns in the [dbo].[ServerTopQueries] table can be reused. 19 | ``` 20 | EXECUTE [dbo].[ServerTopQueries] 21 | @Measurement = 'cpu_time' 22 | ,@Top = 10 23 | ,@AggregateAll = 1 24 | ,@IncludeQueryText = 1 25 | ``` 26 | ### Queries with highest TempDB usage for a given database 27 | Store a list with the top 50 queries with the highest TempDB usage for the database Target, along with their query text 28 | ``` 29 | EXECUTE [dbo].[ServerTopQueries] 30 | @DatabaseName = 'TargetDB' 31 | ,@ReportIndex = 'dbo.ServerTopQueriesIndex' 32 | ,@ReportTable = 'dbo.ServerTopQueriesStore' 33 | ,@Measurement = 'tempdb_space_used' 34 | ,@Top = 50 35 | ,@AggregateAll = 1 36 | ,@IncludeQueryText = 1 37 | ``` 38 | 39 | ## Suggested uses 40 | ### High CPU analysis 41 | Execute it to capture highest CPU consumers 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. -------------------------------------------------------------------------------- /StatisticsUsed/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /StatisticsUsed/1-dbo.StatisticsSamplePercent.Function.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- Function Name: [dbo].[StatisticsSamplePercent] 3 | -- 4 | -- Desc: This function returns a sample rate for the statistics update based on current rowcount & sample rate of the statistic 5 | -- 6 | -- Parameters: 7 | -- INPUT 8 | -- @RowsTotal BIGINT 9 | -- Number of rows in the statistics 10 | -- [Default: None] 11 | -- 12 | -- @RowsSampledPercent BIGINT 13 | -- Percentage of rows used in the last calculation of the statistics 14 | -- [Default: None] 15 | -- 16 | -- Notes: 17 | -- This is a sample function and in no way should be taken into your environment without proper testing 18 | -- Feel free to ignore this function and modify the logic in [dbo].[StatisticsUsed] accordingly 19 | -- 20 | -- 21 | -- Date: 2021.05.08 22 | -- Auth: Pablo Lozano (@sqlozano) 23 | ---------------------------------------------------------------------------------- 24 | 25 | CREATE OR ALTER FUNCTION [dbo].[StatisticsSamplePercent] 26 | ( 27 | @RowsTotal BIGINT 28 | ,@RowsSampledPercent DECIMAL(16,2) 29 | ) 30 | RETURNS INT 31 | AS 32 | BEGIN 33 | -- If the previous sample rate was > 75, upscale it to 100 34 | IF (@RowsSampledPercent > 75) RETURN 100 35 | -- Sample values: addapt them based on your metrics and experience with your own data 36 | RETURN 37 | CASE 38 | -- Small tables: 100 % sample 39 | WHEN @RowsTotal < 1000000 THEN 100 40 | -- Medium tables: 50% sample or the same current sample (when it is higher than 50%) 41 | WHEN @RowsTotal BETWEEN 1000000 AND 9999999 THEN IIF(@RowsSampledPercent > 50, CAST(@RowsSampledPercent AS INT), 50) 42 | -- Large tables: 20% sample or the same current sample (when it is higher than 20%) 43 | WHEN @RowsTotal BETWEEN 10000000 AND 99999999 THEN IIF(@RowsSampledPercent > 20, CAST(@RowsSampledPercent AS INT), 20) 44 | -- Very large tables: 5% sample or the same current sample (when it is higher than 5%) 45 | WHEN @RowsTotal > 100000000 THEN IIF(@RowsSampledPercent > 5, CAST(@RowsSampledPercent AS INT), 5) 46 | END 47 | END -------------------------------------------------------------------------------- /StatisticsUsed/2-dbo.StatisticsUsed.Procedure.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/channeladvisor/qdstoolbox/115f671a49ca9910f6dc73ecf8de18b571ecdd7b/StatisticsUsed/2-dbo.StatisticsUsed.Procedure.sql -------------------------------------------------------------------------------- /StatisticsUsed/README.md: -------------------------------------------------------------------------------- 1 | # StatisticsUsed 2 | Based on the execution plans information stored in Query Store, given 3 | - a single Query ID 4 | - a list of Query IDs 5 | - an Object Name 6 | this tool analyzes all the statistics involved in the generation of its plans, and generates the necessary UPDATE STATISTICS commands with customizable sample rates. 7 | 8 | --- 9 | ## Use cases and examples 10 | ### Statistics for specific Query ID 11 | Analyze the execution plans used by the specificed Query ID, highlighting the statistics with a modification rate higher than 10% and not updated in the last 24 hours: 12 | ``` 13 | EXECUTE [dbo].[StatisticsUsed] 14 | @DatabaseName = 'TargetDB' 15 | ,@QueryID = 32131 16 | ,@ExpirationThreshold = 1400 17 | ,@ModificationThreshold = 10 18 | ``` 19 | ### Statistics for list of Query IDs 20 | Analyze the execution plans used by any of the list of Query IDs provided, highlighting the statistics with a modification rate higher than 25% and not updated in the last 60 minutes: 21 | ``` 22 | EXECUTE [dbo].[StatisticsUsed] 23 | @DatabaseName = 'TargetDB' 24 | ,@QueryIDList = '32131,3214,32133' 25 | ,@ExpirationThreshold = 60 26 | ,@ModificationThreshold = 25 27 | ``` 28 | ### Statistics for object 29 | Analyze the execution plans used by the specified pbject, highlighting the statistics with a modification rate higher than 5% and not updated in the last 5 hours and ensuring the new sample rate calculated will be persisted: 30 | ``` 31 | EXECUTE [dbo].[StatisticsUsed] 32 | @DatabaseName = 'TargetDB' 33 | ,@ObjectName = 'dbo.Procedure' 34 | ,@ExpirationThreshold = 300 35 | ,@ModificationThreshold = 5 36 | ,@PersistSamplePercent = 1 37 | ``` 38 | --- 39 | ## Suggested uses 40 | ### "Unforceable" queries 41 | SQL server can't force certain plans (like those using unnamed indexes in temp tables or table variables): even though the command won't return an error, SQL Server won't honor it. Updating the statistics can help SQL Engine opt for a better plan. 42 | ### Autofix regressed queries 43 | When combined with [dbo].[QueryVariation], it can be used to help SQL Engine choose a better plan for those queries whose performance has deteriorated due to a plan change. 44 | ### Programatically update stats 45 | By loading the commands into a table and looping through them with a cursor, it is possible to execute regular stats update for selected queries or objects 46 | ``` 47 | SET NOCOUNT ON 48 | DROP TABLE IF EXISTS #Stats 49 | CREATE TABLE #Stats 50 | ( 51 | [DatabaseName] NVARCHAR(128) 52 | ,[SchemaName] NVARCHAR(128) 53 | ,[TableName] NVARCHAR(128) 54 | ,[StatisticsName] NVARCHAR(128) 55 | ,[RowsTotal] BIGINT 56 | ,[RowsSampled] BIGINT 57 | ,[RowsSampled%] DECIMAL(16,2) 58 | ,[RowsModified] BIGINT 59 | ,[RowsModified%] DECIMAL(16,2) 60 | ,[StatisticsLastUpdated] DATETIME2 61 | ,[Excluded] NVARCHAR(128) 62 | ,[UpdateStatsCommand] NVARCHAR(MAX) 63 | ) 64 | INSERT INTO #Stats 65 | EXECUTE [dbo].[StatisticsUsed] 66 | @DatabaseName = 'TargetDB' 67 | ,@ObjectName = 'dbo.ProblematicProcedure01' 68 | ,@ExpirationThreshold = 1400 69 | ,@ModificationThreshold = 10 70 | 71 | 72 | DECLARE @UpdateStatsCommand NVARCHAR(MAX) 73 | DECLARE [StatsCursor] CURSOR LOCAL FAST_FORWARD READ_ONLY 74 | FOR 75 | SELECT [UpdateStatsCommand] FROM #Stats 76 | 77 | OPEN [StatsCursor] 78 | FETCH NEXT FROM [StatsCursor] INTO @UpdateStatsCommand 79 | WHILE (@@fetch_status >= 0) 80 | BEGIN 81 | PRINT (@UpdateStatsCommand) 82 | EXECUTE (@UpdateStatsCommand) 83 | FETCH NEXT FROM [StatsCursor] INTO @UpdateStatsCommand 84 | END 85 | 86 | CLOSE [StatsCursor] 87 | DEALLOCATE [StatsCursor] 88 | 89 | DROP TABLE IF EXISTS #Stats 90 | ``` -------------------------------------------------------------------------------- /WaitsVariation/0-schema.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM [sys].[schemas] WHERE QUOTENAME([name]) = '[dbo]') 2 | EXECUTE ('CREATE SCHEMA [dbo];') -------------------------------------------------------------------------------- /WaitsVariation/1-dbo.WaitsVariationIndex.Table.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Table Name: [dbo].[WaitsVariationIndex] 3 | -- 4 | -- Desc: This table is used by the procedure [dbo].[WaitsVariation] to store its entry parameters 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [Parameters] XML NULL 20 | -- List of parameters used to invoke the execution of [dbo].[WaitsVariation] 21 | -- 22 | -- Date: 2020.10.22 23 | -- Auth: Pablo Lozano (@sqlozano) 24 | -- 25 | -- Date: 2021.05.08 26 | -- Auth: Pablo Lozano (@sqlozano) 27 | -- Changed script logic to drop & recreate table 28 | ---------------------------------------------------------------------------------- 29 | 30 | DROP TABLE IF EXISTS [dbo].[WaitsVariationIndex] 31 | CREATE TABLE [dbo].[WaitsVariationIndex] 32 | ( 33 | [ReportID] BIGINT IDENTITY(1,1) 34 | ,[CaptureDate] DATETIME2 NOT NULL 35 | ,[ServerIdentifier] SYSNAME NOT NULL 36 | ,[DatabaseName] SYSNAME NOT NULL 37 | ,[Parameters] XML NOT NULL 38 | ) 39 | ALTER TABLE [dbo].[WaitsVariationIndex] 40 | ADD CONSTRAINT [PK_WaitsVariationIndex] PRIMARY KEY CLUSTERED 41 | ( 42 | [ReportID] 43 | ) -------------------------------------------------------------------------------- /WaitsVariation/3-dbo.vWaitsVariationIndexView.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vWaitsVariationIndex] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[WaitsVariationIndex] to extract the entry parameters used by the executions of [dbo].[WaitsVariation] 5 | -- 6 | -- Columns: 7 | -- [ReportID] BIGINT NOT NULL 8 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 9 | -- 10 | -- [ReportDate] DATETIME2 NOT NULL 11 | -- UTC Date of the execution's start 12 | -- 13 | -- [ServerIdentifier] SYSNAME NOT NULL 14 | -- Identifier of the server, so if this data is centralized reports originated on each server can be properly identified 15 | -- 16 | -- [DatabaseName] SYSNAME NOT NULL 17 | -- Name of the database this operation was executed against 18 | -- 19 | -- [WaitType] NVARCHAR(16) NOT NULL 20 | -- Wait Type to analyze 21 | -- 22 | -- [Metric] NVARCHAR(16) NOT NULL 23 | -- Metric on which to analyze the [WaitType] ('Total', 'Avg') 24 | -- 25 | -- [VariationType] NVARCHAR(1) NOT NULL 26 | -- Defines whether queries whose wait metrics indicates an improvement (I) or a regression (R) 27 | -- 28 | -- [RecentStartTime] DATETIME2 NOT NULL 29 | -- Start of the time period considered as "recent" to be compared with the "history" time period. Must be expressed in UTC. 30 | -- 31 | -- [RecentEndTime] DATETIME2 NOT NULL 32 | -- End of the time period considered as "recent" to be compared with the "history" time period. Must be expressed in UTC. 33 | -- 34 | -- [HistoryStartTime] DATETIME2 NOT NULL 35 | -- Start of the time period considered as "history" to be compared with the "recent" time period. Must be expressed in UTC. 36 | -- 37 | -- [HistoryEndTime] DATETIME2 NOT NULL 38 | -- End of the time period considered as "history" to be compared with the "recent" time period. Must be expressed in UTC. 39 | -- 40 | -- [IncludeQueryText] BIT NOT NULL 41 | -- Flag to define whether the text of the query will be returned 42 | -- 43 | -- [ExcludeAdhoc] BIT NOT NULL 44 | -- Flag to define whether to ignore adhoc queries (not part of a DB object) from the analysis 45 | -- 46 | -- [ExcludeInternal] BIT NOT NULL 47 | -- Flag to define whether to ignore internal queries (backup, index rebuild, statistics update...) from the analysis 48 | -- 49 | -- Date: 2020.10.22 50 | -- Auth: Pablo Lozano (@sqlozano) 51 | -- 52 | ---------------------------------------------------------------------------------- 53 | CREATE OR ALTER VIEW [dbo].[vWaitsVariationIndex] 54 | AS 55 | SELECT 56 | [ReportID] 57 | ,[CaptureDate] 58 | ,[ServerIdentifier] 59 | ,[DatabaseName] 60 | ,q.n.value('WaitType[1]', 'NVARCHAR(16)') AS [WaitType] 61 | ,q.n.value('Metric[1]', 'NVARCHAR(16)') AS [Metric] 62 | ,q.n.value('VariationType[1]', 'NVARCHAR(1)') AS [VariationType] 63 | ,q.n.value('RecentStartTime[1]', 'DATETIME2') AS [RecentStartTime] 64 | ,q.n.value('RecentEndTime[1]', 'DATETIME2') AS [RecentEndTime] 65 | ,q.n.value('HistoryStartTime[1]', 'DATETIME2') AS [HistoryStartTime] 66 | ,q.n.value('HistoryEndTime[1]', 'DATETIME2') AS [HistoryEndTime] 67 | ,q.n.value('IncludeQueryText[1]', 'BIT') AS [IncludeQueryText] 68 | ,q.n.value('ExcludeAdhoc[1]', 'BIT') AS [ExcludeAdhoc] 69 | ,q.n.value('ExcludeInternal[1]', 'BIT') AS [ExcludeInternal] 70 | FROM [dbo].[WaitsVariationIndex] [wvi] 71 | CROSS APPLY [wvi].[Parameters].nodes('/Root/WaitsVariationParameters') AS q(n) 72 | GO -------------------------------------------------------------------------------- /WaitsVariation/4-dbo.vWaitsVariationStore.View.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- View Name: [dbo].[vWaitsVariationStore] 3 | -- 4 | -- Desc: This view is built on top of [dbo].[WaitsVariationStore] to extract the details generated by the executions of [dbo].[WaitsVariation] 5 | -- Description of the wait categories can be found here: 6 | -- https://docs.microsoft.com/en-us/sql/relational-databases/system-catalog-views/sys-query-store-wait-stats-transact-sql?view=sql-server-ver15#wait-categories-mapping-table 7 | -- 8 | -- Columns: 9 | -- [ReportID] BIGINT NOT NULL 10 | -- Unique Identifier for the execution (operations not logged to table have no ReportID) 11 | -- 12 | -- [QueryID] BIGINT NOT NULL 13 | -- Query Identifier of the query with a wait variation 14 | -- 15 | -- [ObjectID] BIGINT NOT NULL 16 | -- Object Identifier the [QueryID] is part of (if any) 17 | -- 18 | -- [SchemaName] SYSNAME NULL 19 | -- Name of the schema of the object the [QueryID] is part of (if any) 20 | -- 21 | -- [ObjectName] SYSNAME NULL 22 | -- Name of the object the [QueryID] is part of (if any) 23 | -- 24 | -- [ExecutionCount_History] DECIMAL(20,2) NULL 25 | -- Number of executions of the [QueryID] in the period of time identified as "History" 26 | -- 27 | -- [ExecutionCount_Recent] DECIMAL(20,2) NULL 28 | -- Number of executions of the [QueryID] in the period of time identified as "Recent" 29 | -- 30 | -- [ExecutionCount_Variation%] DECIMAL(20,2) NULL 31 | -- Variation (in %) in the number of executions between the period of times identified as "History" and "Recent" 32 | -- 33 | -- [Total_History] DECIMAL(20,2) NULL 34 | -- Total wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 35 | -- 36 | -- [Total_Recent] DECIMAL(20,2) NULL 37 | -- Total wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 38 | -- 39 | -- [Total_Variation%] DECIMAL(20,2) NULL 40 | -- Variation (in %) in the Total wait time between the period of times identified as "History" and "Recent" 41 | -- 42 | -- [Unknown_History] DECIMAL(20,2) NULL 43 | -- Total Unknown wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 44 | -- 45 | -- [Unknown_Recent] DECIMAL(20,2) NULL 46 | -- Total Unknown wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 47 | -- 48 | -- [Unknown_Variation%] DECIMAL(20,2) NULL 49 | -- Variation (in %) in the Unknown wait time between the period of times identified as "History" and "Recent" 50 | -- 51 | -- [CPU_History] DECIMAL(20,2) NULL 52 | -- Total CPU wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 53 | -- 54 | -- [CPU_Recent] DECIMAL(20,2) NULL 55 | -- Total CPU wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 56 | -- 57 | -- [CPU_Variation%] DECIMAL(20,2) NULL 58 | -- Variation (in %) in the CPU wait time between the period of times identified as "History" and "Recent" 59 | -- 60 | -- [WorkerThread_History] DECIMAL(20,2) NULL 61 | -- Worker Thread wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 62 | -- 63 | -- [WorkerThread_Recent] DECIMAL(20,2) NULL 64 | -- Worker Thread wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 65 | -- 66 | -- [WorkerThread_Variation%] DECIMAL(20,2) NULL 67 | -- Variation (in %) in the Worker Thread wait time between the period of times identified as "History" and "Recent" 68 | -- 69 | -- [Lock_History] DECIMAL(20,2) NULL 70 | -- Lock wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 71 | -- 72 | -- [Lock_Recent] DECIMAL(20,2) NULL 73 | -- Lock wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 74 | -- 75 | -- [Lock_Variation%] DECIMAL(20,2) NULL 76 | -- Variation (in %) in the Lock wait time between the period of times identified as "History" and "Recent" 77 | -- 78 | -- [Latch_History] DECIMAL(20,2) NULL 79 | -- Latch wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 80 | -- 81 | -- [Latch_Recent] DECIMAL(20,2) NULL 82 | -- Latch wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 83 | -- 84 | -- [Latch_Variation%] DECIMAL(20,2) NULL 85 | -- Variation (in %) in the Latch wait time between the period of times identified as "History" and "Recent" 86 | -- 87 | -- [BufferLatch_History] DECIMAL(20,2) NULL 88 | -- Buffer Latch wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 89 | -- 90 | -- [BufferLatch_Recent] DECIMAL(20,2) NULL 91 | -- Buffer Latch wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 92 | -- 93 | -- [BufferLatch_Variation%] DECIMAL(20,2) NULL 94 | -- Variation (in %) in the Buffer Latch wait time between the period of times identified as "History" and "Recent" 95 | -- 96 | -- [BufferIO_History] DECIMAL(20,2) NULL 97 | -- Buffer IO wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 98 | -- 99 | -- [BufferIO_Recent] DECIMAL(20,2) NULL 100 | -- Buffer IO wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 101 | -- 102 | -- [BufferIO_Variation%] DECIMAL(20,2) NULL 103 | -- Variation (in %) in the Buffer IO wait time between the period of times identified as "History" and "Recent" 104 | -- 105 | -- [Compilation_History] DECIMAL(20,2) NULL 106 | -- Compilation wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 107 | -- 108 | -- [Compilation_Recent] DECIMAL(20,2) NULL 109 | -- Compilation wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 110 | -- 111 | -- [Compilation_Variation%] DECIMAL(20,2) NULL 112 | -- Variation (in %) in the Compilation wait time between the period of times identified as "History" and "Recent" 113 | -- 114 | -- [SQLCLR_History] DECIMAL(20,2) NULL 115 | -- SQL CLR wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 116 | -- 117 | -- [SQLCLR_Recent] DECIMAL(20,2) NULL 118 | -- SQL CLR wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 119 | -- 120 | -- [SQLCLR_Variation%] DECIMAL(20,2) NULL 121 | -- Variation (in %) in the SQL CLR wait time between the period of times identified as "History" and "Recent" 122 | -- 123 | -- [Mirroring_History] DECIMAL(20,2) NULL 124 | -- Mirroring wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 125 | -- 126 | -- [Mirroring_Recent] DECIMAL(20,2) NULL 127 | -- Mirroring wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 128 | -- 129 | -- [Mirroring_Variation%] DECIMAL(20,2) NULL 130 | -- Variation (in %) in the Mirroring wait time between the period of times identified as "History" and "Recent" 131 | -- 132 | -- [Transaction_History] DECIMAL(20,2) NULL 133 | -- Transaction wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 134 | -- 135 | -- [Transaction_Recent] DECIMAL(20,2) NULL 136 | -- Transaction wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 137 | -- 138 | -- [Transaction_Variation%] DECIMAL(20,2) NULL 139 | -- Variation (in %) in the Transaction wait time between the period of times identified as "History" and "Recent" 140 | -- 141 | -- [Idle_History] DECIMAL(20,2) NULL 142 | -- Idle wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 143 | -- 144 | -- [Idle_Recent] DECIMAL(20,2) NULL 145 | -- Idle wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 146 | -- 147 | -- [Idle_Variation%] DECIMAL(20,2) NULL 148 | -- Variation (in %) in the Idle wait time between the period of times identified as "History" and "Recent" 149 | -- 150 | -- [Preemptive_History] DECIMAL(20,2) NULL 151 | -- Preemptive wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 152 | -- 153 | -- [Preemptive_Recent] DECIMAL(20,2) NULL 154 | -- Preemptive wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 155 | -- 156 | -- [Preemptive_Variation%] DECIMAL(20,2) NULL 157 | -- Variation (in %) in the Preemptive wait time between the period of times identified as "History" and "Recent" 158 | -- 159 | -- [ServiceBroker_History] DECIMAL(20,2) NULL 160 | -- Service Broker wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 161 | -- 162 | -- [ServiceBroker_Recent] DECIMAL(20,2) NULL 163 | -- Service Broker wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 164 | -- 165 | -- [ServiceBroker_Variation%] DECIMAL(20,2) NULL 166 | -- Variation (in %) in the Service Broker wait time between the period of times identified as "History" and "Recent" 167 | -- 168 | -- [TranLogIO_History] DECIMAL(20,2) NULL 169 | -- Transaction LOG IO wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 170 | -- 171 | -- [TranLogIO_Recent] DECIMAL(20,2) NULL 172 | -- Transaction Log IO wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 173 | -- 174 | -- [TranLogIO_Variation%] DECIMAL(20,2) NULL 175 | -- Variation (in %) in the Transaction Log IO wait time between the period of times identified as "History" and "Recent" 176 | -- 177 | -- [NetworkIO_History] DECIMAL(20,2) NULL 178 | -- Network IO wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 179 | -- 180 | -- [NetworkIO_Recent] DECIMAL(20,2) NULL 181 | -- Network IO wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 182 | -- 183 | -- [NetworkIO_Variation%] DECIMAL(20,2) NULL 184 | -- Variation (in %) in the Network IO wait time between the period of times identified as "History" and "Recent" 185 | -- 186 | -- [Parallelism_History] DECIMAL(20,2) NULL 187 | -- Parallelism wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 188 | --- 189 | -- [Parallelism_Recent] DECIMAL(20,2) NULL 190 | -- Parallelism wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 191 | -- 192 | -- [Parallelism_Variation%] DECIMAL(20,2) NULL 193 | -- Variation (in %) in the Parallelism wait time between the period of times identified as "History" and "Recent" 194 | -- 195 | -- [Memory_History] DECIMAL(20,2) NULL 196 | -- Memory wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 197 | -- 198 | -- [Memory_Recent] DECIMAL(20,2) NULL 199 | -- Memory wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 200 | -- 201 | -- [Memory_Variation%] DECIMAL(20,2) NULL 202 | -- Variation (in %) in the Memory wait time between the period of times identified as "History" and "Recent" 203 | -- 204 | -- [UserWait_History] DECIMAL(20,2) NULL 205 | -- User wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 206 | -- 207 | -- [UserWait_Recent] DECIMAL(20,2) NULL 208 | -- User wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 209 | -- 210 | -- [UserWait_Variation%] DECIMAL(20,2) NULL 211 | -- Variation (in %) in the User wait time between the period of times identified as "History" and "Recent" 212 | -- 213 | -- [Tracing_History] DECIMAL(20,2) NULL 214 | -- Tracing wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 215 | -- 216 | -- [Tracing_Recent] DECIMAL(20,2) NULL 217 | -- Tracing wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 218 | -- 219 | -- [Tracing_Variation%] DECIMAL(20,2) NULL 220 | -- Variation (in %) in the Tracing wait time between the period of times identified as "History" and "Recent" 221 | -- 222 | -- [FullTextSearch_History] DECIMAL(20,2) NULL 223 | -- FullTextSearch wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 224 | -- 225 | -- [FullTextSearch_Recent] DECIMAL(20,2) NULL 226 | -- FullTextSearch wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 227 | -- 228 | -- [FullTextSearch_Variation%] DECIMAL(20,2) NULL 229 | -- Variation (in %) in the FullTextSearch wait time between the period of times identified as "History" and "Recent" 230 | -- 231 | -- [OtherDiskIO_History] DECIMAL(20,2) NULL 232 | -- Other Disk IO wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 233 | -- 234 | -- [OtherDiskIO_Recent] DECIMAL(20,2) NULL 235 | -- Other Disk IO wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 236 | -- 237 | -- [OtherDiskIO_Variation%] DECIMAL(20,2) NULL 238 | -- Variation (in %) in the Other Disk IO wait time between the period of times identified as "History" and "Recent" 239 | -- 240 | -- [Replication_History] DECIMAL(20,2) NULL 241 | -- Replication wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 242 | -- 243 | -- [Replication_Recent] DECIMAL(20,2) NULL 244 | -- Replication wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 245 | -- 246 | -- [Replication_Variation%] DECIMAL(20,2) NULL 247 | -- Variation (in %) in the Replication wait time between the period of times identified as "History" and "Recent" 248 | -- 249 | -- [LogRateGovernor_History] DECIMAL(20,2) NULL 250 | -- Log Rate Governor wait time of the [QueryID] in the period of time identified as "History" (in microseconds) 251 | -- 252 | -- [LogRateGovernor_Recent] DECIMAL(20,2) NULL 253 | -- Log Rate Governor wait time of the [QueryID] in the period of time identified as "Recent" (in microseconds) 254 | -- 255 | -- [LogRateGovernor_Variation%] DECIMAL(20,2) NULL 256 | -- Variation (in %) in the Log Rate Governor wait time between the period of times identified as "History" and "Recent" 257 | -- 258 | -- [QuerySqlText] NVARCHAR(MAX) NULL 259 | -- Query text of the [QueryID] 260 | -- 261 | -- Date: 2020.10.22 262 | -- Auth: Pablo Lozano (@sqlozano) 263 | -- 264 | -- Date: 2021.05.05 265 | -- Auth: Pablo Lozano (@sqlozano) 266 | -- Swapped the Recent/History columns so the metrics will be read from left to right "History / Recent / Variation" 267 | ---------------------------------------------------------------------------------- 268 | 269 | CREATE OR ALTER VIEW [dbo].[vWaitsVariationStore] 270 | AS 271 | SELECT 272 | [wvi].[ReportID] 273 | ,[wvs].[QueryID] 274 | ,[wvs].[ObjectID] 275 | ,[wvs].[SchemaName] 276 | ,[wvs].[ObjectName] 277 | ,[wvs].[ExecutionCount_History] 278 | ,[wvs].[ExecutionCount_Recent] 279 | ,[wvs].[ExecutionCount_Variation%] 280 | ,[wvs].[Total_History] 281 | ,[wvs].[Total_Recent] 282 | ,[wvs].[Total_Variation%] 283 | ,[wvs].[Unknown_History] 284 | ,[wvs].[Unknown_Recent] 285 | ,[wvs].[Unknown_Variation%] 286 | ,[wvs].[CPU_History] 287 | ,[wvs].[CPU_Recent] 288 | ,[wvs].[CPU_Variation%] 289 | ,[wvs].[WorkerThread_History] 290 | ,[wvs].[WorkerThread_Recent] 291 | ,[wvs].[WorkerThread_Variation%] 292 | ,[wvs].[Lock_History] 293 | ,[wvs].[Lock_Recent] 294 | ,[wvs].[Lock_Variation%] 295 | ,[wvs].[Latch_History] 296 | ,[wvs].[Latch_Recent] 297 | ,[wvs].[Latch_Variation%] 298 | ,[wvs].[BufferLatch_History] 299 | ,[wvs].[BufferLatch_Recent] 300 | ,[wvs].[BufferLatch_Variation%] 301 | ,[wvs].[BufferIO_History] 302 | ,[wvs].[BufferIO_Recent] 303 | ,[wvs].[BufferIO_Variation%] 304 | ,[wvs].[Compilation_History] 305 | ,[wvs].[Compilation_Recent] 306 | ,[wvs].[Compilation_Variation%] 307 | ,[wvs].[SQLCLR_History] 308 | ,[wvs].[SQLCLR_Recent] 309 | ,[wvs].[SQLCLR_Variation%] 310 | ,[wvs].[Mirroring_History] 311 | ,[wvs].[Mirroring_Recent] 312 | ,[wvs].[Mirroring_Variation%] 313 | ,[wvs].[Transaction_History] 314 | ,[wvs].[Transaction_Recent] 315 | ,[wvs].[Transaction_Variation%] 316 | ,[wvs].[Idle_History] 317 | ,[wvs].[Idle_Recent] 318 | ,[wvs].[Idle_Variation%] 319 | ,[wvs].[Preemptive_History] 320 | ,[wvs].[Preemptive_Recent] 321 | ,[wvs].[Preemptive_Variation%] 322 | ,[wvs].[ServiceBroker_History] 323 | ,[wvs].[ServiceBroker_Recent] 324 | ,[wvs].[ServiceBroker_Variation%] 325 | ,[wvs].[TranLogIO_History] 326 | ,[wvs].[TranLogIO_Recent] 327 | ,[wvs].[TranLogIO_Variation%] 328 | ,[wvs].[NetworkIO_History] 329 | ,[wvs].[NetworkIO_Recent] 330 | ,[wvs].[NetworkIO_Variation%] 331 | ,[wvs].[Parallelism_History] 332 | ,[wvs].[Parallelism_Recent] 333 | ,[wvs].[Parallelism_Variation%] 334 | ,[wvs].[Memory_History] 335 | ,[wvs].[Memory_Recent] 336 | ,[wvs].[Memory_Variation%] 337 | ,[wvs].[UserWait_History] 338 | ,[wvs].[UserWait_Recent] 339 | ,[wvs].[UserWait_Variation%] 340 | ,[wvs].[Tracing_History] 341 | ,[wvs].[Tracing_Recent] 342 | ,[wvs].[Tracing_Variation%] 343 | ,[wvs].[FullTextSearch_History] 344 | ,[wvs].[FullTextSearch_Recent] 345 | ,[wvs].[FullTextSearch_Variation%] 346 | ,[wvs].[OtherDiskIO_History] 347 | ,[wvs].[OtherDiskIO_Recent] 348 | ,[wvs].[OtherDiskIO_Variation%] 349 | ,[wvs].[Replication_History] 350 | ,[wvs].[Replication_Recent] 351 | ,[wvs].[Replication_Variation%] 352 | ,[wvs].[LogRateGovernor_History] 353 | ,[wvs].[LogRateGovernor_Recent] 354 | ,[wvs].[LogRateGovernor_Variation%] 355 | ,CAST(DECOMPRESS([wvs].[QueryText]) AS NVARCHAR(MAX)) AS [QueryText] 356 | FROM [dbo].[WaitsVariationStore] [wvs] 357 | INNER JOIN [dbo].[vWaitsVariationIndex] [wvi] 358 | ON [wvs].[ReportID] = [wvi].[ReportID] 359 | -------------------------------------------------------------------------------- /WaitsVariation/6-dbo.WaitsVariationFromStore.Procedure.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------- 2 | -- Procedure Name: [dbo].[WaitsVariationFromStore] 3 | -- 4 | -- Desc: This script accesses previously stored reports based on query variation, returning only the significant columns based on the parameters 5 | -- used to initially generate the report. 6 | -- 7 | -- 8 | -- Parameters: 9 | -- INPUT 10 | -- @ReportID BIGINT -- Identifier of the report whose data is being queried 11 | -- 12 | -- @VerboseMode BIT -- Flag to determine whether the T-SQL commands that compose this report will be returned to the user. 13 | -- [Default: 0] 14 | -- 15 | -- @TestMode BIT -- Flag to determine whether the actual T-SQL commands that generate the report will be executed. 16 | -- [Default:0] 17 | -- 18 | -- 19 | -- Date: 2020.10.22 20 | -- Auth: Pablo Lozano (@sqlozano) 21 | -- 22 | ---------------------------------------------------------------------------------- 23 | 24 | CREATE OR ALTER PROCEDURE [dbo].[WaitsVariationFromStore] 25 | ( 26 | @ReportID BIGINT 27 | ,@VerboseMode BIT = 0 28 | ,@TestMode BIT = 0 29 | ) 30 | AS 31 | BEGIN 32 | SET NOCOUNT ON 33 | 34 | -- Verify the @ReportID provided is a valid one - START 35 | IF (@ReportID IS NULL) 36 | BEGIN 37 | RAISERROR('NULL is a non valid value for the ReportID.', 16, 0) 38 | RETURN 39 | END 40 | 41 | IF NOT EXISTS (SELECT 1 FROM [dbo].[WaitsVariationIndex] WHERE [ReportID] = @ReportID) 42 | BEGIN 43 | DECLARE @r NVARCHAR(20) = CAST(@ReportID AS NVARCHAR(20)) 44 | RAISERROR('The ReportID [%s] does not exist.', 16, 0, @r) 45 | RETURN 46 | END 47 | -- Verify the @ReportID provided is a valid one - END 48 | 49 | 50 | -- Gather parameters used to generate the Report in order to prepare the output - START 51 | DECLARE @WaitType NVARCHAR(16) 52 | DECLARE @VariationType NVARCHAR(1) 53 | DECLARE @IncludeQueryText BIT 54 | SELECT 55 | @WaitType = [WaitType] 56 | ,@VariationType = [VariationType] 57 | ,@IncludeQueryText = [IncludeQueryText] 58 | FROM [dbo].[vWaitsVariationIndex] WHERE [ReportID] = @ReportID 59 | -- Gather parameters used to generate the Report in order to prepare the output - END 60 | 61 | -- Build query to return the output to the user - START 62 | DECLARE @SqlCmdIndex NVARCHAR(MAX) = 63 | 'SELECT 64 | [wvi].[ServerIdentifier] 65 | ,[wvi].[DatabaseName] 66 | ,[wvi].[WaitType] 67 | ,[wvi].[Metric] 68 | ,[wvi].[VariationType] 69 | ,[wvi].[HistoryStartTime] 70 | ,[wvi].[HistoryEndTime] 71 | ,[wvi].[RecentStartTime] 72 | ,[wvi].[RecentEndTime] 73 | ,[wvi].[ExcludeAdhoc] 74 | ,[wvi].[ExcludeInternal] 75 | ,[wvi].[IncludeQueryText] 76 | FROM 77 | [dbo].[vWaitsVariationIndex] [wvi] 78 | WHERE [wvi].[ReportID] = {@ReportID}' 79 | SET @SqlCmdIndex = REPLACE(@SqlCmdIndex, '{@ReportID}', CAST(@ReportID AS NVARCHAR(20))) 80 | 81 | IF (@VerboseMode = 1) PRINT (@SqlCmdIndex) 82 | IF (@TestMode = 0) EXEC (@SqlCmdIndex) 83 | 84 | DECLARE @SqlCmdStore NVARCHAR(MAX) = 85 | 'SELECT 86 | [wvs].[ObjectID] 87 | ,[wvs].[SchemaName] 88 | ,[wvs].[ObjectName] 89 | ,[wvs].[ExecutionCount_History] 90 | ,[wvs].[ExecutionCount_Recent] 91 | ,[wvs].[ExecutionCount_Variation%] 92 | ,[wvs].[{@WaitType}_History] 93 | ,[wvs].[{@WaitType}_Recent] 94 | ,[wvs].[{@WaitType}_Variation%] 95 | {@IncludeQueryText},[wvs].[QueryText] 96 | FROM [dbo].[vWaitsVariationStore] [wvs] 97 | WHERE [wvs].[ReportID] = {@ReportID} 98 | ORDER BY [{@WaitType}_Variation%] {@ASCDESC}' 99 | 100 | SET @SqlCmdStore = REPLACE(@SqlCmdStore, '{@ReportID}', CAST(@ReportID AS NVARCHAR(20))) 101 | 102 | -- Select appropriate columns based on the @WaitType selected - START 103 | SET @SqlCmdStore = REPLACE(@SqlCmdStore, '{@WaitType}', @WaitType) 104 | -- Select appropriate columns based on the @WaitType selected - END 105 | 106 | -- Modify results' ordering based on @VariationType - START 107 | IF (@VariationType = 'R') 108 | SET @SqlCmdStore = REPLACE(@SqlCmdStore, '{@ASCDESC}', 'DESC') 109 | IF (@VariationType = 'I') 110 | SET @SqlCmdStore = REPLACE(@SqlCmdStore, '{@ASCDESC}', 'ASC') 111 | -- Modify results' ordering based on @VariationType - END 112 | 113 | -- Include / Exclude Query Text based on @IncludeQueryText - START 114 | IF (@IncludeQueryText = 0) 115 | SET @SqlCmdStore = REPLACE(@SqlCmdStore, '{@IncludeQueryText}', '--') 116 | IF (@IncludeQueryText = 1) 117 | SET @SqlCmdStore = REPLACE(@SqlCmdStore, '{@IncludeQueryText}', '') 118 | -- Include / Exclude Query Text based on @IncludeQueryText - END 119 | 120 | -- Build query to return the output to the user - END 121 | 122 | IF (@VerboseMode = 1) PRINT (@SqlCmdStore) 123 | IF (@TestMode = 0) EXEC (@SqlCmdStore) 124 | 125 | END -------------------------------------------------------------------------------- /WaitsVariation/README.md: -------------------------------------------------------------------------------- 1 | # WaitsVariation 2 | Similar to the QueryVariation tool, compares the Wait metrics for a given query between two different periods of time. 3 | 4 | It can be executed in a Test mode to only return the impact executing it would have. both in Test mode or when executed to generate the actual report, the operations's can return an output in different formats: 5 | - One table, containing the detailed results. 6 | - Stored into 2 SQL tables, with one containing the parameters used (both explicitly defined and default values) and another with the detailed results. 7 | - Not returned at all. 8 | 9 | The waits measured are those captured by Query Store 10 | \ 11 | https://docs.microsoft.com/en-us/sql/relational-databases/system-catalog-views/sys-query-store-wait-stats-transact-sql 12 | \ 13 | (Supported in SQL 2017+: for SQL 2016 the execution of the stored procedure will return an error) 14 | --- 15 | ## Use cases and examples 16 | ### Avg CPU wait improvement 17 | Queries whose waits on CPU have decreased when comparing the periods (2020-01-01 00:00 -> 2020-02-01 00:00) and (2020-02-01 00:00 -> 2020-02-01 01:00)\ 18 | ``` 19 | EXECUTE [dbo].[WaitsVariation] 20 | @DatabaseName = 'Target' 21 | ,@WaitType = 'CPU' 22 | ,@Metric = 'avg' 23 | ,@VariationType = 'I' 24 | ,@RecentStartTime = '2020-02-01 00:00' 25 | ,@RecentEndTime = '2020-02-01 01:00' 26 | ,@HistoryStartTime = '2020-01-01 00:00' 27 | ,@HistoryEndTime = '2020-02-01 00:00 28 | ``` 29 | --- 30 | ## Suggested uses 31 | This tool can be used to extract reports similar to the "Regressed Queries" ones SSMS GUI generates, but based on wait times and with the added functionality of storing the reports into tables for later analysis. 32 | ### CPU changes 33 | When the count of CPUs available to the SQL instance is modified, waits on CPU are expected to change and this can be used to measure its impact. 34 | ### Network changes 35 | Making modifications on the network (such as moving the SQL instance and its clients to a separate network, setting a different network route for SQL traffic...) will impact the waits caused by network IO. 36 | ### Locking impact on the query 37 | Changes in the locking mechanism (such as isolation level, indexing or other processes accessing the same tables the investigated query accesses to), will modify the waits on locks. -------------------------------------------------------------------------------- /qdstoolbox.svg: -------------------------------------------------------------------------------- 1 | 2 | image/svg+xml 24 | 25 | 26 | 27 | 28 | 29 | 30 | 31 | 32 | 33 | 44 | QDS 84 | 86 | 87 | 89 | 90 | 92 | 93 | 95 | 96 | 98 | 99 | 101 | 102 | 104 | 105 | 107 | 108 | 110 | 111 | 113 | 114 | 116 | 117 | 119 | 120 | 122 | 123 | 125 | 126 | 128 | 129 | 130 | --------------------------------------------------------------------------------