From 5eb6817725c20c7f15cc0bb2ed249e4a39ae0b44 Mon Sep 17 00:00:00 2001 From: Darling Data Date: Tue, 29 Oct 2024 16:38:59 +0000 Subject: [PATCH] Automation: Format and Build SQL File --- Install-All/DarlingData.sql | 2178 ++++++++++++++--- sp_IndexCleanup BETA/sp_IndexCleanup BETA.sql | 2 +- sp_QuickieStore/Examples.sql | 40 +- sp_QuickieStore/sp_QuickieStore.sql | 24 +- 4 files changed, 1840 insertions(+), 404 deletions(-) diff --git a/Install-All/DarlingData.sql b/Install-All/DarlingData.sql index 641d103..0331697 100644 --- a/Install-All/DarlingData.sql +++ b/Install-All/DarlingData.sql @@ -1,4 +1,4 @@ --- Compile Date: 10/09/2024 21:16:04 UTC +-- Compile Date: 10/29/2024 16:38:58 UTC SET ANSI_NULLS ON; SET ANSI_PADDING ON; SET ANSI_WARNINGS ON; @@ -15469,10 +15469,10 @@ OPTION(MAXDOP 1, RECOMPILE);', CROSS JOIN ( SELECT - wg.active_request_count, - wg.queued_request_count, - wg.blocked_task_count, - wg.active_parallel_thread_count + active_request_count = SUM(wg.active_request_count), + queued_request_count = SUM(wg.queued_request_count), + blocked_task_count = SUM(wg.blocked_task_count), + active_parallel_thread_count = SUM(wg.active_parallel_thread_count) FROM sys.dm_resource_governor_workload_groups AS wg ) AS wg OUTER APPLY @@ -16024,7 +16024,7 @@ ALTER PROCEDURE @timezone sysname = NULL, /*user specified time zone to override dates displayed in results*/ @execution_count bigint = NULL, /*the minimum number of executions a query must have*/ @duration_ms bigint = NULL, /*the minimum duration a query must have to show up in results*/ - @execution_type_desc nvarchar(60) = NULL, /*the type of execution you want to filter by (success, failure)*/ + @execution_type_desc nvarchar(60) = NULL, /*the type of execution you want to filter by (regular, aborted, exception)*/ @procedure_schema sysname = NULL, /*the schema of the procedure you're searching for*/ @procedure_name sysname = NULL, /*the name of the programmable object you're searching for*/ @include_plan_ids nvarchar(4000) = NULL, /*a list of plan ids to search for*/ @@ -16051,10 +16051,14 @@ ALTER PROCEDURE @expert_mode bit = 0, /*returns additional columns and results*/ @hide_help_table bit = 0, /*hides the "bottom table" that shows help and support information*/ @format_output bit = 1, /*returns numbers formatted with commas*/ - @get_all_databases bit = 0, /*looks for query store enabled databases and returns combined results from all of them*/ + @get_all_databases bit = 0, /*looks for query store enabled user databases and returns combined results from all of them*/ @workdays bit = 0, /*Use this to filter out weekends and after-hours queries*/ @work_start time(0) = '9am', /*Use this to set a specific start of your work days*/ @work_end time(0) = '5pm', /*Use this to set a specific end of your work days*/ + @regression_baseline_start_date datetimeoffset(7) = NULL, /*the begin date of the baseline that you are checking for regressions against (if any), will be converted to UTC internally*/ + @regression_baseline_end_date datetimeoffset(7) = NULL, /*the end date of the baseline that you are checking for regressions against (if any), will be converted to UTC internally*/ + @regression_comparator varchar(20) = NULL, /*what difference to use ('relative' or 'absolute') when comparing @sort_order's metric for the normal time period with the regression time period.*/ + @regression_direction varchar(20) = NULL, /*when comparing against the regression baseline, want do you want the results sorted by ('magnitude', 'improved', or 'regressed')?*/ @help bit = 0, /*return available parameter details, etc.*/ @debug bit = 0, /*prints dynamic sql, statement length, parameter and variable values, and raw temp table contents*/ @troubleshoot_performance bit = 0, /*set statistics xml on for queries against views*/ @@ -16133,7 +16137,7 @@ BEGIN WHEN N'@timezone' THEN 'user specified time zone to override dates displayed in results' WHEN N'@execution_count' THEN 'the minimum number of executions a query must have' WHEN N'@duration_ms' THEN 'the minimum duration a query must have to show up in results' - WHEN N'@execution_type_desc' THEN 'the type of execution you want to filter by (success, failure)' + WHEN N'@execution_type_desc' THEN 'the type of execution you want to filter by (regular, aborted, exception)' WHEN N'@procedure_schema' THEN 'the schema of the procedure you''re searching for' WHEN N'@procedure_name' THEN 'the name of the programmable object you''re searching for' WHEN N'@include_plan_ids' THEN 'a list of plan ids to search for' @@ -16160,10 +16164,14 @@ BEGIN WHEN N'@expert_mode' THEN 'returns additional columns and results' WHEN N'@hide_help_table' THEN 'hides the "bottom table" that shows help and support information' WHEN N'@format_output' THEN 'returns numbers formatted with commas' - WHEN N'@get_all_databases' THEN 'looks for query store enabled databases and returns combined results from all of them' + WHEN N'@get_all_databases' THEN 'looks for query store enabled user databases and returns combined results from all of them' WHEN N'@workdays' THEN 'use this to filter out weekends and after-hours queries' WHEN N'@work_start' THEN 'use this to set a specific start of your work days' WHEN N'@work_end' THEN 'use this to set a specific end of your work days' + WHEN N'@regression_baseline_start_date' THEN 'the begin date of the baseline that you are checking for regressions against (if any), will be converted to UTC internally' + WHEN N'@regression_baseline_end_date' THEN 'the end date of the baseline that you are checking for regressions against (if any), will be converted to UTC internally' + WHEN N'@regression_comparator' THEN 'what difference to use (''relative'' or ''absolute'') when comparing @sort_order''s metric for the normal time period with any regression time period.' + WHEN N'@regression_direction' THEN 'when comparing against any regression baseline, what do you want the results sorted by (''magnitude'', ''improved'', or ''regressed'')?' WHEN N'@help' THEN 'how you got here' WHEN N'@debug' THEN 'prints dynamic sql, statement length, parameter and variable values, and raw temp table contents' WHEN N'@troubleshoot_performance' THEN 'set statistics xml on for queries against views' @@ -16212,6 +16220,10 @@ BEGIN WHEN N'@workdays' THEN '0 or 1' WHEN N'@work_start' THEN 'a time like 8am, 9am or something' WHEN N'@work_end' THEN 'a time like 5pm, 6pm or something' + WHEN N'@regression_baseline_start_date' THEN 'January 1, 1753, through December 31, 9999' + WHEN N'@regression_baseline_end_date' THEN 'January 1, 1753, through December 31, 9999' + WHEN N'@regression_comparator' THEN 'relative, absolute' + WHEN N'@regression_direction' THEN 'regressed, worse, improved, better, magnitude, absolute, whatever' WHEN N'@help' THEN '0 or 1' WHEN N'@debug' THEN '0 or 1' WHEN N'@troubleshoot_performance' THEN '0 or 1' @@ -16221,7 +16233,7 @@ BEGIN defaults = CASE ap.name - WHEN N'@database_name' THEN 'NULL; current non-system database name if NULL' + WHEN N'@database_name' THEN 'NULL; current database name if NULL' WHEN N'@sort_order' THEN 'cpu' WHEN N'@top' THEN '10' WHEN N'@start_date' THEN 'the last seven days' @@ -16260,6 +16272,10 @@ BEGIN WHEN N'@workdays' THEN '0' WHEN N'@work_start' THEN '9am' WHEN N'@work_end' THEN '5pm' + WHEN N'@regression_baseline_start_date' THEN 'NULL' + WHEN N'@regression_baseline_end_date' THEN 'NULL; One week after @regression_baseline_start_date if that is specified' + WHEN N'@regression_comparator' THEN 'NULL; absolute if @regression_baseline_start_date is specified' + WHEN N'@regression_direction' THEN 'NULL; regressed if @regression_baseline_start_date is specified' WHEN N'@debug' THEN '0' WHEN N'@help' THEN '0' WHEN N'@troubleshoot_performance' THEN '0' @@ -16406,7 +16422,6 @@ CREATE TABLE [object_id] bigint PRIMARY KEY ); - /* Hold plan_ids for ad hoc or procedures we're searching for */ @@ -16497,21 +16512,74 @@ CREATE TABLE database_id int NOT NULL, plan_id bigint NOT NULL, query_hash binary(8) NOT NULL, - plan_hash_count_for_query_hash INT NOT NULL, + plan_hash_count_for_query_hash int NOT NULL, PRIMARY KEY (database_id, plan_id, query_hash) ); /* Largely just exists because total_query_wait_time_ms isn't in our normal output. + +Unfortunately needs an extra column for regression +mode's benefit. The alternative was either a +horrible UNPIVOT with an extra temp table +or changing @parameters everywhere (and +therefore every sp_executesql). */ CREATE TABLE #plan_ids_with_total_waits ( database_id int NOT NULL, plan_id bigint NOT NULL, + from_regression_baseline varchar(3) NOT NULL, total_query_wait_time_ms bigint NOT NULL, - PRIMARY KEY (database_id, plan_id) + PRIMARY KEY (database_id, plan_id, from_regression_baseline) +); + +/* +Used in regression mode to hold the +statistics for each query hash in our +baseline time period. +*/ +CREATE TABLE + #regression_baseline_runtime_stats +( + query_hash binary(8) NOT NULL PRIMARY KEY, + /* Nullable to protect from division by 0. */ + regression_metric_average float NULL +); + +/* +Used in regression mode to hold the +statistics for each query hash in our +normal time period. +*/ +CREATE TABLE + #regression_current_runtime_stats +( + query_hash binary(8) NOT NULL PRIMARY KEY, + /* Nullable to protect from division by 0. */ + current_metric_average float NULL +); + +/* +Used in regression mode to hold the +results of comparing our two time +periods. + +This is also used just like a +sort-helping table. For example, +it is used to bolt columns +on to our final output. +*/ +CREATE TABLE + #regression_changes +( + database_id int NOT NULL, + plan_id bigint NOT NULL, + query_hash binary(8) NOT NULL, + change_since_regression_time_period float NULL, + PRIMARY KEY (database_id, plan_id, query_hash) ); /* @@ -16982,6 +17050,7 @@ CREATE TABLE max_tempdb_space_used_mb bigint NULL, total_tempdb_space_used_mb AS (avg_tempdb_space_used_mb * count_executions), + from_regression_baseline varchar(3) NULL, context_settings nvarchar(256) NULL ); @@ -17190,7 +17259,11 @@ DECLARE @df integer, @work_start_utc time(0), @work_end_utc time(0), - @sort_order_is_a_wait bit; + @sort_order_is_a_wait bit, + @regression_baseline_start_date_original datetimeoffset(7), + @regression_baseline_end_date_original datetimeoffset(7), + @regression_mode bit, + @regression_where_clause nvarchar(max); /* In cases where we are escaping @query_text_search and @@ -17255,6 +17328,174 @@ SELECT ) ); +/* +Set @regression_mode if the given arguments indicate that +we are checking for regressed queries. +*/ +IF +( +@regression_baseline_start_date IS NOT NULL +) +BEGIN + SELECT + @regression_mode = 1; +END; + +/* +Error out if the @regression parameters do not make sense. +*/ +IF +( +@regression_baseline_start_date IS NULL +AND (@regression_baseline_end_date IS NOT NULL OR @regression_comparator IS NOT NULL OR @regression_direction IS NOT NULL) +) +BEGIN + RAISERROR('@regression_baseline_start_date is mandatory if you have specified any other @regression_ parameter.', 11, 1) WITH NOWAIT; +END; + +/* +Error out if the @regression_baseline_start_date and +@regression_baseline_end_date are incompatible. +We could try and guess a sensible resolution, but +I do not think that we can know what people want. +*/ +IF +( +@regression_baseline_start_date IS NOT NULL +AND @regression_baseline_end_date IS NOT NULL +AND @regression_baseline_start_date >= @regression_baseline_end_date +) +BEGIN + RAISERROR('@regression_baseline_start_date has been set greater than or equal to @regression_baseline_end_date. This does not make sense. Check that the values of both parameters are as you intended them to be.', 11, 1) WITH NOWAIT; +END; + + +/* +Validate @regression_comparator. +*/ +IF +( +@regression_comparator IS NOT NULL +AND @regression_comparator NOT IN ('relative', 'absolute') +) +BEGIN + RAISERROR('The regression_comparator (%s) you chose is so out of this world that I''m using ''absolute'' instead', 10, 1, @regression_comparator) WITH NOWAIT; + + SELECT + @regression_comparator = 'absolute'; +END; + +/* +Validate @regression_direction. +*/ +IF +( +@regression_direction IS NOT NULL +AND @regression_direction NOT IN ('regressed', 'worse', 'improved', 'better', 'magnitude', 'absolute') +) +BEGIN + RAISERROR('The regression_direction (%s) you chose is so out of this world that I''m using ''regressed'' instead', 10, 1, @regression_direction) WITH NOWAIT; + + SELECT + @regression_direction = 'regressed'; +END; + +/* +Error out if we're trying to do regression mode with 'recent' +as our @sort_order. How could that ever make sense? +*/ +IF +( +@regression_mode = 1 +AND @sort_order = 'recent' +) +BEGIN + RAISERROR('Your @sort_order is ''recent'', but you are trying to compare metrics for two time periods. If you can imagine a useful way to do that, then make a feature request. Otherwise, either stop specifying any @regression_ parameters or specify a different @sort_order.', 11, 1) WITH NOWAIT; +END; + +/* +Error out if we're trying to do regression mode with 'plan count by hashes' +as our @sort_order. How could that ever make sense? +*/ +IF +( +@regression_mode = 1 +AND @sort_order = 'plan count by hashes' +) +BEGIN + RAISERROR('Your @sort_order is ''plan count by hashes'', but you are trying to compare metrics for two time periods. This is probably not useful, since our method of comparing two time period relies on only checking query hashes that are in both time periods. If you can imagine a useful way to do that, then make a feature request. Otherwise, either stop specifying any @regression_ parameters or specify a different @sort_order.', 11, 1) WITH NOWAIT; +END; + + +/* +Error out if @regression_comparator tells us to use division, +but @regression_direction tells us to take the modulus. +It doesn't make sense to specifically ask us to remove the sign +of something that doesn't care about it. +*/ +IF +( +@regression_comparator = 'relative' +AND @regression_direction IN ('absolute', 'magnitude') +) +BEGIN + RAISERROR('Your @regression_comparator is ''relative'', but you have asked for an ''absolute'' or ''magnitude'' @regression_direction. This is probably a mistake. Your @regression_direction tells us to take the absolute value of our result of comparing the metrics in the current time period to the baseline time period, but your @regression_comparator is telling us to use division to compare the two time periods. This is unlikely to produce useful results. If you can imagine a useful way to do that, then make a feature request. Otherwise, either change @regression_direction to another value (e.g. ''better'' or ''worse'') or change @regression_comparator to ''absolute''.', 11, 1) WITH NOWAIT; +END; + + +/* +Set the _original variables, as we have +for other values that would break inside +the loop without them. + +This is also where we enforce the default +that leaving @regression_baseline_end_date +unspecified will set it to be a week +after @regression_baseline_start_date. + +We do not need to account for the possibility +of @regression_baseline_start_date being NULL. +Due to the above error-throwing, it cannot be +NULL if we are doing anything that would care +about it. +*/ +SELECT + @regression_baseline_start_date_original = + @regression_baseline_start_date, + @regression_baseline_end_date_original = + ISNULL + ( + @regression_baseline_end_date, + DATEADD + ( + DAY, + 7, + @regression_baseline_start_date + ) + ); + +/* +Error out if the @execution_type_desc value is invalid. +*/ +IF +( +@execution_type_desc IS NOT NULL +AND @execution_type_desc NOT IN ('regular', 'aborted', 'exception') +) +BEGIN + RAISERROR('@execution_type_desc can only take one of these three non-NULL values: + 1) ''regular'' (meaning a successful execution), + 2) ''aborted'' (meaning that the client cancelled the query), + 3) ''exception'' (meaning that an exception cancelled the query). + +You supplied ''%s''. + +If you leave @execution_type_desc NULL, then we grab every type of execution. + +See the official documentation for sys.query_store_runtime_stats for more details on the execution types.', 11, 1, @execution_type_desc) WITH NOWAIT; +END; + + /* This section is in a cursor whether we hit one database, or multiple @@ -17442,7 +17683,9 @@ SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;', @database_id int, @queries_top bigint, @work_start_utc time(0), - @work_end_utc time(0)', + @work_end_utc time(0), + @regression_baseline_start_date datetimeoffset(7), + @regression_baseline_end_date datetimeoffset(7)', @plans_top = 9223372036854775807, @queries_top = @@ -17766,6 +18009,37 @@ BEGIN ); END; +/* +As above, but for @regression_baseline_start_date and @regression_baseline_end_date. +We set the other @regression_ variables while we're at it. +*/ +IF @regression_mode = 1 +BEGIN + +/* +We set both _date_original variables earlier. +*/ +SELECT + @regression_baseline_start_date = + DATEADD + ( + MINUTE, + @utc_minutes_difference, + @regression_baseline_start_date_original + ), + @regression_baseline_end_date = + DATEADD + ( + MINUTE, + @utc_minutes_difference, + @regression_baseline_end_date_original + ), + @regression_comparator = + ISNULL(@regression_comparator, 'absolute'), + @regression_direction = + ISNULL(@regression_direction, 'regressed'); +END; + /* Let's make sure things will work */ @@ -20726,17 +21000,74 @@ SELECT LEN(@where_clause) - 1 ); +/* +Regression mode differs significantly from our defaults. +In this mode, we measure every query hash in the time period +specified by @regression_baseline_start_date and +@regression_baseline_end_date ("the baseline time period"). +Our measurements are taken based on the metric given +by @sort_order. +For all of the hashes we have taken measurements for, we +make the same measurement for the time period specified +by @start_date and @end_date ("the current time period"). +We then compare each hashes' measurement across the two +time periods, by the means specified by +@regression_comparator and take the @top results ordered by +@regression_direction. +We then get every plan_id in both time periods for those +query hashes and carry on as normal. + +This gives us three immediate concerns. We: + 1) Need to adjust our @where_clause to refer to the + baseline time period. + 2) Need all of the queries from the baseline time + period (rather than just the @top whatever). + 3) Are interested in the query hashes rather than + just plan_ids. + +We address part of the first concern immediately. +Later, we will do some wicked and foul things to +modify our dynamic SQL's usages of @where_clause +to use @regression_where_clause. +*/ +IF @regression_mode = 1 +BEGIN + +SELECT + @regression_where_clause = + REPLACE + ( + REPLACE + ( + @where_clause, + '@start_date', + '@regression_baseline_start_date' + ), + '@end_date', + '@regression_baseline_end_date' + ); +END; + /* Populate sort-helping tables, if needed. In theory, these exist just to put in scope columns that wouldn't normally be in scope. -However, they're also quite helpful for the next +However, they're also quite helpful for the next temp table, #distinct_plans. Note that this block must come after #maintenance_plans because that edits @where_clause and we want to use that here. + +Regression mode complicates this process considerably. +It forces us to use different dates. +We also have to adjust @top. + +Luckily, the 'plan count by hashes' sort +order is not supported in regression mode. +Earlier on, we throw an error if somebody +tries (it just doesn't make sense). */ IF @sort_order = 'plan count by hashes' BEGIN @@ -20756,9 +21087,9 @@ BEGIN SELECT /* - This sort order is useless if we don't show the - ties, so only DENSE_RANK() makes sense to use. - This is why this is not SELECT TOP. + This sort order is useless if we don't show the + ties, so only DENSE_RANK() makes sense to use. + This is why this is not SELECT TOP. */ @sql += N' SELECT @@ -20803,7 +21134,7 @@ BEGIN qsp.plan_id FROM ' + @database_name_quoted + N'.sys.query_store_query AS qsq JOIN ' + @database_name_quoted + N'.sys.query_store_plan AS qsp - ON qsq.query_id = qsp.query_id + ON qsq.query_id = qsp.query_id JOIN ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs ON qsp.plan_id = qsrs.plan_id WHERE 1 = 1 @@ -20841,7 +21172,9 @@ BEGIN @database_id, @queries_top, @work_start_utc, - @work_end_utc; + @work_end_utc, + @regression_baseline_start_date, + @regression_baseline_end_date; IF @troubleshoot_performance = 1 BEGIN @@ -20860,7 +21193,6 @@ BEGIN @current_table; END; END; - IF @sort_order = 'total waits' BEGIN SELECT @@ -20882,20 +21214,55 @@ BEGIN SELECT TOP (@top) @database_id, qsrs.plan_id, + from_regression_baseline = + CASE + WHEN qsrs.last_execution_time >= @start_date AND qsrs.last_execution_time < @end_date + THEN ''No'' + ELSE ''Yes'' + END, total_query_wait_time_ms = SUM(qsws.total_query_wait_time_ms) FROM ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs JOIN ' + @database_name_quoted + N'.sys.query_store_wait_stats AS qsws ON qsrs.plan_id = qsws.plan_id WHERE 1 = 1 - ' + @where_clause + ' + + CASE WHEN @regression_mode = 1 + THEN N' AND ( 1 = 1 + ' + @regression_where_clause + + N' ) +OR + ( 1 = 1 + ' + + @where_clause + + N' ) ' + ELSE @where_clause + END + N' GROUP - BY qsrs.plan_id + BY qsrs.plan_id, + CASE + WHEN qsrs.last_execution_time >= @start_date AND qsrs.last_execution_time < @end_date + THEN ''No'' + ELSE ''Yes'' + END ORDER BY SUM(qsws.total_query_wait_time_ms) DESC OPTION(RECOMPILE, OPTIMIZE FOR (@top = 9223372036854775807));' + @nc10; + IF @regression_mode = 1 + BEGIN + + /* Very stupid way to stop us repeating the above code. */ + SELECT + @sql = REPLACE + ( + @sql, + 'TOP (@top)', + 'TOP (2147483647 + (0 * @top))' + ); + END; + IF @debug = 1 BEGIN PRINT LEN(@sql); @@ -20907,6 +21274,7 @@ BEGIN ( database_id, plan_id, + from_regression_baseline, total_query_wait_time_ms ) EXEC sys.sp_executesql @@ -20921,7 +21289,9 @@ BEGIN @database_id, @queries_top, @work_start_utc, - @work_end_utc; + @work_end_utc, + @regression_baseline_start_date, + @regression_baseline_end_date; IF @troubleshoot_performance = 1 BEGIN @@ -20941,9 +21311,10 @@ BEGIN END; END; /* - 'total waits' is special. It's a sum, not a max, so - we cover it above rather than here. +'total waits' is special. It's a sum, not a max, so +we cover it above rather than here. */ + IF @sort_order_is_a_wait = 1 AND @sort_order <> 'total waits' BEGIN @@ -20966,6 +21337,12 @@ BEGIN SELECT TOP (@top) @database_id, qsrs.plan_id, + from_regression_baseline = + CASE + WHEN qsrs.last_execution_time >= @start_date AND qsrs.last_execution_time < @end_date + THEN ''No'' + ELSE ''Yes'' + END, total_query_wait_time_ms = MAX(qsws.total_query_wait_time_ms) FROM ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs @@ -20990,14 +21367,44 @@ BEGIN WHEN 'parallelism waits' THEN N'16' WHEN 'memory waits' THEN N'17' END - + @where_clause + + N' + ' + + CASE WHEN @regression_mode = 1 + THEN N' AND ( 1 = 1 + ' + @regression_where_clause + + N' ) + OR + ( 1 = 1 + ' + + @where_clause + + N' ) ' + ELSE @where_clause + END + N' GROUP - BY qsrs.plan_id + BY qsrs.plan_id, + CASE + WHEN qsrs.last_execution_time >= @start_date AND qsrs.last_execution_time < @end_date + THEN ''No'' + ELSE ''Yes'' + END ORDER BY MAX(qsws.total_query_wait_time_ms) DESC OPTION(RECOMPILE, OPTIMIZE FOR (@top = 9223372036854775807));' + @nc10; + IF @regression_mode = 1 + BEGIN + + /* Very stupid way to stop us repeating the above code. */ + SELECT + @sql = REPLACE + ( + @sql, + 'TOP (@top)', + 'TOP (2147483647 + (0 * @top))' + ); + END; + IF @debug = 1 BEGIN PRINT LEN(@sql); @@ -21009,6 +21416,7 @@ BEGIN ( database_id, plan_id, + from_regression_baseline, total_query_wait_time_ms ) EXEC sys.sp_executesql @@ -21023,7 +21431,9 @@ BEGIN @database_id, @queries_top, @work_start_utc, - @work_end_utc; + @work_end_utc, + @regression_baseline_start_date, + @regression_baseline_end_date; IF @troubleshoot_performance = 1 BEGIN @@ -21045,74 +21455,474 @@ END; /*End populating sort-helping tables*/ /* -This gets the plan_ids we care about. - -We unfortunately need an ELSE IF chain here -because the final branch contains defaults -that we only want to hit if we did not hit -any others. +This is where the bulk of the regression mode +work is done. We grab the metrics for both time +periods for each query hash, compare them, +and get the @top. */ -SELECT - @current_table = 'inserting #distinct_plans', - @sql = @isolation_level; - -IF @troubleshoot_performance = 1 +IF @regression_mode = 1 BEGIN - EXEC sys.sp_executesql - @troubleshoot_insert, - N'@current_table nvarchar(100)', - @current_table; + /* + We begin by getting the metrics per query hash + in the time period. + */ + SELECT + @current_table = 'inserting #regression_baseline_runtime_stats', + @sql = @isolation_level; - SET STATISTICS XML ON; -END; + IF @troubleshoot_performance = 1 + BEGIN + EXEC sys.sp_executesql + @troubleshoot_insert, + N'@current_table nvarchar(100)', + @current_table; + + SET STATISTICS XML ON; + END; -IF @sort_order = 'plan count by hashes' -BEGIN - SELECT - @sql += N' - SELECT DISTINCT - plan_id - FROM #plan_ids_with_query_hashes - WHERE database_id = @database_id - OPTION(RECOMPILE);' + @nc10; -END -ELSE IF @sort_order_is_a_wait = 1 -BEGIN SELECT @sql += N' - SELECT DISTINCT - plan_id - FROM #plan_ids_with_total_waits - WHERE database_id = @database_id - OPTION(RECOMPILE);' + @nc10; -END -ELSE -BEGIN SELECT - @sql += N' - SELECT TOP (@top) - qsrs.plan_id - FROM ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs + qsq.query_hash, + /* All of these but count_executions are already floats. */ + regression_metric_average = + CONVERT(FLOAT, AVG( ' + + CASE @sort_order + WHEN 'cpu' THEN N'qsrs.avg_cpu_time' + WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads' + WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads' + WHEN 'writes' THEN N'qsrs.avg_logical_io_writes' + WHEN 'duration' THEN N'qsrs.avg_duration' + WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used' ELSE N'qsrs.avg_cpu_time' END + WHEN 'executions' THEN N'qsrs.count_executions' + ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' ELSE N'qsrs.avg_cpu_time' END + END + + N' )) + FROM ' + @database_name_quoted + N'.sys.query_store_query AS qsq + JOIN ' + @database_name_quoted + N'.sys.query_store_plan AS qsp + ON qsq.query_id = qsp.query_id + JOIN ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs + ON qsp.plan_id = qsrs.plan_id + LEFT JOIN #plan_ids_with_total_waits AS waits + ON qsp.plan_id = waits.plan_id + AND waits.from_regression_baseline = ''Yes'' WHERE 1 = 1 - ' + @where_clause + ' + @regression_where_clause + N' GROUP - BY qsrs.plan_id - ORDER BY - MAX(' + - CASE @sort_order - WHEN 'cpu' THEN N'qsrs.avg_cpu_time' - WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads' - WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads' - WHEN 'writes' THEN N'qsrs.avg_logical_io_writes' - WHEN 'duration' THEN N'qsrs.avg_duration' - WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory' - WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used' ELSE N'qsrs.avg_cpu_time' END - WHEN 'executions' THEN N'qsrs.count_executions' - WHEN 'recent' THEN N'qsrs.last_execution_time' - ELSE N'qsrs.avg_cpu_time' - END + - N') DESC + BY qsq.query_hash + OPTION(RECOMPILE);' + @nc10; + + IF @debug = 1 + BEGIN + PRINT LEN(@sql); + PRINT @sql; + END; + + INSERT + #regression_baseline_runtime_stats WITH(TABLOCK) + ( + query_hash, + regression_metric_average + ) + EXEC sys.sp_executesql + @sql, + @parameters, + @top, + @start_date, + @end_date, + @execution_count, + @duration_ms, + @execution_type_desc, + @database_id, + @queries_top, + @work_start_utc, + @work_end_utc, + @regression_baseline_start_date, + @regression_baseline_end_date; + + IF @troubleshoot_performance = 1 + BEGIN + SET STATISTICS XML OFF; + + EXEC sys.sp_executesql + @troubleshoot_update, + N'@current_table nvarchar(100)', + @current_table; + + EXEC sys.sp_executesql + @troubleshoot_info, + N'@sql nvarchar(max), + @current_table nvarchar(100)', + @sql, + @current_table; + END; + + /* + We now take the same measurement for all of the same query hashes, + but in the @where_clause time period. + */ + SELECT + @current_table = 'inserting #regression_current_runtime_stats', + @sql = @isolation_level; + + IF @troubleshoot_performance = 1 + BEGIN + EXEC sys.sp_executesql + @troubleshoot_insert, + N'@current_table nvarchar(100)', + @current_table; + + SET STATISTICS XML ON; + END; + + SELECT + @sql += N' + SELECT + qsq.query_hash, + /* All of these but count_executions are already floats. */ + current_metric_average = + CONVERT(FLOAT, AVG( ' + + CASE @sort_order + WHEN 'cpu' THEN N'qsrs.avg_cpu_time' + WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads' + WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads' + WHEN 'writes' THEN N'qsrs.avg_logical_io_writes' + WHEN 'duration' THEN N'qsrs.avg_duration' + WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used' ELSE N'qsrs.avg_cpu_time' END + WHEN 'executions' THEN N'qsrs.count_executions' + ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' ELSE N'qsrs.avg_cpu_time' END + END + + N' )) + FROM ' + @database_name_quoted + N'.sys.query_store_query AS qsq + JOIN ' + @database_name_quoted + N'.sys.query_store_plan AS qsp + ON qsq.query_id = qsp.query_id + JOIN ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs + ON qsp.plan_id = qsrs.plan_id + LEFT JOIN #plan_ids_with_total_waits AS waits + ON qsp.plan_id = waits.plan_id + AND waits.from_regression_baseline = ''No'' + WHERE 1 = 1 + AND qsq.query_hash IN (SELECT base.query_hash FROM #regression_baseline_runtime_stats AS base) + ' + @where_clause + + N' + GROUP + BY qsq.query_hash + OPTION(RECOMPILE);' + @nc10; + + IF @debug = 1 + BEGIN + PRINT LEN(@sql); + PRINT @sql; + END; + + INSERT + #regression_current_runtime_stats WITH(TABLOCK) + ( + query_hash, + current_metric_average + ) + EXEC sys.sp_executesql + @sql, + @parameters, + @top, + @start_date, + @end_date, + @execution_count, + @duration_ms, + @execution_type_desc, + @database_id, + @queries_top, + @work_start_utc, + @work_end_utc, + @regression_baseline_start_date, + @regression_baseline_end_date; + + IF @troubleshoot_performance = 1 + BEGIN + SET STATISTICS XML OFF; + + EXEC sys.sp_executesql + @troubleshoot_update, + N'@current_table nvarchar(100)', + @current_table; + + EXEC sys.sp_executesql + @troubleshoot_info, + N'@sql nvarchar(max), + @current_table nvarchar(100)', + @sql, + @current_table; + END; + + SELECT + @current_table = 'inserting #regression_changes', + @sql = @isolation_level; + + IF @troubleshoot_performance = 1 + BEGIN + EXEC sys.sp_executesql + @troubleshoot_insert, + N'@current_table nvarchar(100)', + @current_table; + + SET STATISTICS XML ON; + END; + + /* + Now that we have the data from + both time periods, we must + compare them as @regression_comparator + demands and order them as + @regression_direction demands. + + However, we care about query_hashes + here despite everything after this + wanting plan_ids. This means we + must repeat some of the tricks + we used for #plan_ids_with_query_hashes. + */ + SELECT + @sql += N' + SELECT + @database_id, + plans_for_hashes.plan_id, + hashes_with_changes.query_hash, + change_since_regression_time_period = + ' + + /* + If we are returning differences that are not percentages, + then we need the units we show for any given metric to be + the same as anywhere else that gives the same metric. + If we do not, then our final output will look wrong. + For example, our CPU time will be 1,000 times bigger + here than it is in any other column. + To avoid this problem, we need to replicate the calculations + later used to populate #query_store_runtime_stats. + */ + CASE @regression_comparator + WHEN 'absolute' THEN + CASE @sort_order + WHEN 'cpu' THEN N'hashes_with_changes.change_since_regression_time_period / 1000.' + WHEN 'logical reads' THEN N'(hashes_with_changes.change_since_regression_time_period * 8.) / 1024.' + WHEN 'physical reads' THEN N'(hashes_with_changes.change_since_regression_time_period * 8.) / 1024.' + WHEN 'writes' THEN N'(hashes_with_changes.change_since_regression_time_period * 8.) / 1024.' + WHEN 'duration' THEN N'hashes_with_changes.change_since_regression_time_period / 1000.' + WHEN 'memory' THEN N'(hashes_with_changes.change_since_regression_time_period * 8.) / 1024.' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'(hashes_with_changes.change_since_regression_time_period * 8.) / 1024.' ELSE N'hashes_with_changes.change_since_regression_time_period / 1000.' END + WHEN 'executions' THEN N'hashes_with_changes.change_since_regression_time_period' + ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'hashes_with_changes.change_since_regression_time_period / 1000.' ELSE N'hashes_with_changes.change_since_regression_time_period / 1000.' END + END + ELSE N'hashes_with_changes.change_since_regression_time_period' END + + N' + FROM + ( + SELECT TOP (@top) + compared_stats.query_hash, + compared_stats.change_since_regression_time_period + FROM + ( + SELECT + current_stats.query_hash, + change_since_regression_time_period = + ' + + CASE @regression_comparator + WHEN 'relative' THEN N'((current_stats.current_metric_average / NULLIF(baseline.regression_metric_average, 0.0)) - 1.0)' + WHEN 'absolute' THEN N'(current_stats.current_metric_average - baseline.regression_metric_average)' + END + + N' + FROM #regression_current_runtime_stats AS current_stats + JOIN #regression_baseline_runtime_stats AS baseline + ON current_stats.query_hash = baseline.query_hash + ) AS compared_stats + ORDER BY + ' + /* + Current metrics that are better than that of the baseline period, + will give change_since_regression_time_period values that + are smaller than metrics that are worse. + In other words, ORDER BY change_since_regression_time_period DESC + gives us the regressed queries first. + This is true regardless of @regression_comparator. + To make @regression_direction behave as intended, we + need to account for this. We could use dynamic SQL, + but mathematics has given us better tools. + */ + + CASE @regression_direction + WHEN 'regressed' THEN N'change_since_regression_time_period' + WHEN 'worse' THEN N'change_since_regression_time_period' + WHEN 'improved' THEN N'change_since_regression_time_period * -1.0' + WHEN 'better' THEN N'change_since_regression_time_period * -1.0' + /* + The following two branches cannot be hit if + @regression_comparator is 'relative'. + We have made errors be thrown if somebody tries + to mix the two. + If you can figure out a way to make the two make + sense together, then feel free to add it in. + */ + WHEN 'magnitude' THEN N'ABS(change_since_regression_time_period)' + WHEN 'absolute' THEN N'ABS(change_since_regression_time_period)' + END + + N' DESC + ) AS hashes_with_changes + JOIN + ( + SELECT DISTINCT + qsq.query_hash, + qsp.plan_id + FROM ' + @database_name_quoted + N'.sys.query_store_query AS qsq + JOIN ' + @database_name_quoted + N'.sys.query_store_plan AS qsp + ON qsq.query_id = qsp.query_id + JOIN ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs + ON qsp.plan_id = qsrs.plan_id + WHERE + ( 1 = 1 + ' + /* We want each time period's plan_ids for these query hashes. */ + + @regression_where_clause + + N' + ) + OR + ( 1 = 1 + ' + + @where_clause + + N' + ) + ) AS plans_for_hashes + ON hashes_with_changes.query_hash = plans_for_hashes.query_hash + OPTION(RECOMPILE, OPTIMIZE FOR (@top = 9223372036854775807));' + @nc10; + + IF @debug = 1 + BEGIN + PRINT LEN(@sql); + PRINT @sql; + END; + + INSERT + #regression_changes WITH(TABLOCK) + ( + database_id, + plan_id, + query_hash, + change_since_regression_time_period + ) + EXEC sys.sp_executesql + @sql, + @parameters, + @top, + @start_date, + @end_date, + @execution_count, + @duration_ms, + @execution_type_desc, + @database_id, + @queries_top, + @work_start_utc, + @work_end_utc, + @regression_baseline_start_date, + @regression_baseline_end_date; + + IF @troubleshoot_performance = 1 + BEGIN + SET STATISTICS XML OFF; + + EXEC sys.sp_executesql + @troubleshoot_update, + N'@current_table nvarchar(100)', + @current_table; + + EXEC sys.sp_executesql + @troubleshoot_info, + N'@sql nvarchar(max), + @current_table nvarchar(100)', + @sql, + @current_table; + END; + +END; + +/* +This gets the plan_ids we care about. + +We unfortunately need an ELSE IF chain here +because the final branch contains defaults +that we only want to hit if we did not hit +any others. +*/ +SELECT + @current_table = 'inserting #distinct_plans', + @sql = @isolation_level; + +IF @troubleshoot_performance = 1 +BEGIN + EXEC sys.sp_executesql + @troubleshoot_insert, + N'@current_table nvarchar(100)', + @current_table; + + SET STATISTICS XML ON; +END; + +IF @regression_mode = 1 +BEGIN + SELECT + @sql += N' + SELECT DISTINCT + plan_id + FROM #regression_changes + WHERE database_id = @database_id + OPTION(RECOMPILE);' + @nc10; +END +ELSE IF @sort_order = 'plan count by hashes' +BEGIN + SELECT + @sql += N' + SELECT DISTINCT + plan_id + FROM #plan_ids_with_query_hashes + WHERE database_id = @database_id + OPTION(RECOMPILE);' + @nc10; +END +ELSE IF @sort_order_is_a_wait = 1 +BEGIN + SELECT + @sql += N' + SELECT DISTINCT + plan_id + FROM #plan_ids_with_total_waits + WHERE database_id = @database_id + OPTION(RECOMPILE);' + @nc10; +END +ELSE +BEGIN + SELECT + @sql += N' + SELECT TOP (@top) + qsrs.plan_id + FROM ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs + WHERE 1 = 1 + ' + @where_clause + + N' + GROUP + BY qsrs.plan_id + ORDER BY + MAX(' + + CASE @sort_order + WHEN 'cpu' THEN N'qsrs.avg_cpu_time' + WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads' + WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads' + WHEN 'writes' THEN N'qsrs.avg_logical_io_writes' + WHEN 'duration' THEN N'qsrs.avg_duration' + WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used' ELSE N'qsrs.avg_cpu_time' END + WHEN 'executions' THEN N'qsrs.count_executions' + WHEN 'recent' THEN N'qsrs.last_execution_time' + ELSE N'qsrs.avg_cpu_time' + END + + N') DESC OPTION(RECOMPILE, OPTIMIZE FOR (@top = 9223372036854775807));' + @nc10; END; @@ -21139,7 +21949,9 @@ EXEC sys.sp_executesql @database_id, @queries_top, @work_start_utc, - @work_end_utc; + @work_end_utc, + @regression_baseline_start_date, + @regression_baseline_end_date; IF @troubleshoot_performance = 1 BEGIN @@ -21159,7 +21971,8 @@ BEGIN END; /*End gathering plan ids*/ /* -This gets the runtime stats for the plans we care about +This gets the runtime stats for the plans we care about. +It is notably the last usage of @where_clause. */ SELECT @current_table = 'inserting #query_store_runtime_stats', @@ -21179,65 +21992,65 @@ SELECT @sql += N' SELECT @database_id, - MAX(qsrs.runtime_stats_id), - qsrs.plan_id, - MAX(qsrs.runtime_stats_interval_id), - MAX(qsrs.execution_type_desc), - MIN(qsrs.first_execution_time), - MAX(qsrs.last_execution_time), - SUM(qsrs.count_executions), - AVG((qsrs.avg_duration / 1000.)), - MAX((qsrs.last_duration / 1000.)), - MIN((qsrs.min_duration / 1000.)), - MAX((qsrs.max_duration / 1000.)), - AVG((qsrs.avg_cpu_time / 1000.)), - MAX((qsrs.last_cpu_time / 1000.)), - MIN((qsrs.min_cpu_time / 1000.)), - MAX((qsrs.max_cpu_time / 1000.)), - AVG(((qsrs.avg_logical_io_reads * 8.) / 1024.)), - MAX(((qsrs.last_logical_io_reads * 8.) / 1024.)), - MIN(((qsrs.min_logical_io_reads * 8.) / 1024.)), - MAX(((qsrs.max_logical_io_reads * 8.) / 1024.)), - AVG(((qsrs.avg_logical_io_writes * 8.) / 1024.)), - MAX(((qsrs.last_logical_io_writes * 8.) / 1024.)), - MIN(((qsrs.min_logical_io_writes * 8.) / 1024.)), - MAX(((qsrs.max_logical_io_writes * 8.) / 1024.)), - AVG(((qsrs.avg_physical_io_reads * 8.) / 1024.)), - MAX(((qsrs.last_physical_io_reads * 8.) / 1024.)), - MIN(((qsrs.min_physical_io_reads * 8.) / 1024.)), - MAX(((qsrs.max_physical_io_reads * 8.) / 1024.)), - AVG((qsrs.avg_clr_time / 1000.)), - MAX((qsrs.last_clr_time / 1000.)), - MIN((qsrs.min_clr_time / 1000.)), - MAX((qsrs.max_clr_time / 1000.)), - MAX(qsrs.last_dop), - MIN(qsrs.min_dop), - MAX(qsrs.max_dop), - AVG(((qsrs.avg_query_max_used_memory * 8.) / 1024.)), - MAX(((qsrs.last_query_max_used_memory * 8.) / 1024.)), - MIN(((qsrs.min_query_max_used_memory * 8.) / 1024.)), - MAX(((qsrs.max_query_max_used_memory * 8.) / 1024.)), - AVG(qsrs.avg_rowcount), - MAX(qsrs.last_rowcount), - MIN(qsrs.min_rowcount), - MAX(qsrs.max_rowcount),'; + MAX(qsrs_with_lasts.runtime_stats_id), + qsrs_with_lasts.plan_id, + MAX(qsrs_with_lasts.runtime_stats_interval_id), + MAX(qsrs_with_lasts.execution_type_desc), + MIN(qsrs_with_lasts.first_execution_time), + MAX(qsrs_with_lasts.partitioned_last_execution_time), + SUM(qsrs_with_lasts.count_executions), + AVG((qsrs_with_lasts.avg_duration / 1000.)), + MAX((qsrs_with_lasts.partitioned_last_duration / 1000.)), + MIN((qsrs_with_lasts.min_duration / 1000.)), + MAX((qsrs_with_lasts.max_duration / 1000.)), + AVG((qsrs_with_lasts.avg_cpu_time / 1000.)), + MAX((qsrs_with_lasts.partitioned_last_cpu_time / 1000.)), + MIN((qsrs_with_lasts.min_cpu_time / 1000.)), + MAX((qsrs_with_lasts.max_cpu_time / 1000.)), + AVG(((qsrs_with_lasts.avg_logical_io_reads * 8.) / 1024.)), + MAX(((qsrs_with_lasts.partitioned_last_logical_io_reads * 8.) / 1024.)), + MIN(((qsrs_with_lasts.min_logical_io_reads * 8.) / 1024.)), + MAX(((qsrs_with_lasts.max_logical_io_reads * 8.) / 1024.)), + AVG(((qsrs_with_lasts.avg_logical_io_writes * 8.) / 1024.)), + MAX(((qsrs_with_lasts.partitioned_last_logical_io_writes * 8.) / 1024.)), + MIN(((qsrs_with_lasts.min_logical_io_writes * 8.) / 1024.)), + MAX(((qsrs_with_lasts.max_logical_io_writes * 8.) / 1024.)), + AVG(((qsrs_with_lasts.avg_physical_io_reads * 8.) / 1024.)), + MAX(((qsrs_with_lasts.partitioned_last_physical_io_reads * 8.) / 1024.)), + MIN(((qsrs_with_lasts.min_physical_io_reads * 8.) / 1024.)), + MAX(((qsrs_with_lasts.max_physical_io_reads * 8.) / 1024.)), + AVG((qsrs_with_lasts.avg_clr_time / 1000.)), + MAX((qsrs_with_lasts.partitioned_last_clr_time / 1000.)), + MIN((qsrs_with_lasts.min_clr_time / 1000.)), + MAX((qsrs_with_lasts.max_clr_time / 1000.)), + MAX(qsrs_with_lasts.partitioned_last_dop), + MIN(qsrs_with_lasts.min_dop), + MAX(qsrs_with_lasts.max_dop), + AVG(((qsrs_with_lasts.avg_query_max_used_memory * 8.) / 1024.)), + MAX(((qsrs_with_lasts.partitioned_last_query_max_used_memory * 8.) / 1024.)), + MIN(((qsrs_with_lasts.min_query_max_used_memory * 8.) / 1024.)), + MAX(((qsrs_with_lasts.max_query_max_used_memory * 8.) / 1024.)), + AVG(qsrs_with_lasts.avg_rowcount), + MAX(qsrs_with_lasts.partitioned_last_rowcount), + MIN(qsrs_with_lasts.min_rowcount), + MAX(qsrs_with_lasts.max_rowcount),'; IF @new = 1 BEGIN SELECT @sql += N' - AVG(((qsrs.avg_num_physical_io_reads * 8.) / 1024.)), - MAX(((qsrs.last_num_physical_io_reads * 8.) / 1024.)), - MIN(((qsrs.min_num_physical_io_reads * 8.) / 1024.)), - MAX(((qsrs.max_num_physical_io_reads * 8.) / 1024.)), - AVG((qsrs.avg_log_bytes_used / 100000000.)), - MAX((qsrs.last_log_bytes_used / 100000000.)), - MIN((qsrs.min_log_bytes_used / 100000000.)), - MAX((qsrs.max_log_bytes_used / 100000000.)), - AVG(((qsrs.avg_tempdb_space_used * 8) / 1024.)), - MAX(((qsrs.last_tempdb_space_used * 8) / 1024.)), - MIN(((qsrs.min_tempdb_space_used * 8) / 1024.)), - MAX(((qsrs.max_tempdb_space_used * 8) / 1024.)),'; + AVG(((qsrs_with_lasts.avg_num_physical_io_reads * 8.) / 1024.)), + MAX(((qsrs_with_lasts.partitioned_last_num_physical_io_reads * 8.) / 1024.)), + MIN(((qsrs_with_lasts.min_num_physical_io_reads * 8.) / 1024.)), + MAX(((qsrs_with_lasts.max_num_physical_io_reads * 8.) / 1024.)), + AVG((qsrs_with_lasts.avg_log_bytes_used / 100000000.)), + MAX((qsrs_with_lasts.partitioned_last_log_bytes_used / 100000000.)), + MIN((qsrs_with_lasts.min_log_bytes_used / 100000000.)), + MAX((qsrs_with_lasts.max_log_bytes_used / 100000000.)), + AVG(((qsrs_with_lasts.avg_tempdb_space_used * 8) / 1024.)), + MAX(((qsrs_with_lasts.partitioned_last_tempdb_space_used * 8) / 1024.)), + MIN(((qsrs_with_lasts.min_tempdb_space_used * 8) / 1024.)), + MAX(((qsrs_with_lasts.max_tempdb_space_used * 8) / 1024.)),'; END; IF @new = 0 @@ -21258,55 +22071,291 @@ IF @new = 0 NULL,'; END; +/* +In regression mode, we do not mind seeing the +same plan_id twice. We need the below to make +the two time periods under consideration +distinct. +*/ +IF @regression_mode = 1 +BEGIN + SELECT + @sql += N' + CASE + WHEN qsrs_with_lasts.last_execution_time >= @start_date AND qsrs_with_lasts.last_execution_time < @end_date + THEN ''No'' + ELSE ''Yes'' + END,'; +END +ELSE +BEGIN + SELECT + @sql += N' + NULL,'; +END; + SELECT @sql += N' context_settings = NULL -FROM #distinct_plans AS dp -CROSS APPLY +FROM ( - SELECT TOP (@queries_top) - qsrs.* - FROM ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs' - IF @sort_order = 'plan count by hashes' - BEGIN - SELECT - @sql += N' - JOIN #plan_ids_with_query_hashes AS hashes - ON qsrs.plan_id = hashes.plan_id - AND hashes.database_id = @database_id' - END; - IF @sort_order_is_a_wait = 1 + SELECT + qsrs.*, + /* + We need this here to make sure that PARTITION BY runs before GROUP BY but after CROSS APPLY. + If it were after GROUP BY, then we would be dealing with already aggregated data. + If it were inside the CROSS APPLY, then we would be dealing with windows of size one. + Both are very wrong, so we need this. + */ + partitioned_last_execution_time = + LAST_VALUE(qsrs.last_execution_time) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_duration = + LAST_VALUE(qsrs.last_duration) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_cpu_time = + LAST_VALUE(qsrs.last_cpu_time) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_logical_io_reads = + LAST_VALUE(qsrs.last_logical_io_reads) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_logical_io_writes = + LAST_VALUE(qsrs.last_logical_io_writes) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_physical_io_reads = + LAST_VALUE(qsrs.last_physical_io_reads) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_clr_time = + LAST_VALUE(qsrs.last_clr_time) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_dop = + LAST_VALUE(qsrs.last_dop) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_query_max_used_memory = + LAST_VALUE(qsrs.last_query_max_used_memory) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_rowcount = + LAST_VALUE(qsrs.last_rowcount) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ),'; +IF @new = 1 BEGIN SELECT @sql += N' - JOIN #plan_ids_with_total_waits AS waits - ON qsrs.plan_id = waits.plan_id - AND waits.database_id = @database_id' - END; + partitioned_last_num_physical_io_reads = + LAST_VALUE(qsrs.last_num_physical_io_reads) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_log_bytes_used = + LAST_VALUE(qsrs.last_log_bytes_used) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_tempdb_space_used = + LAST_VALUE(qsrs.last_tempdb_space_used) OVER + ( + PARTITION BY + qsrs.plan_id, + qsrs.execution_type + ORDER BY + qsrs.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + )'; + END +IF @new = 0 + BEGIN + SELECT + @sql += N' + NULL' + END SELECT @sql += N' - WHERE qsrs.plan_id = dp.plan_id - AND 1 = 1 - ' + @where_clause - + N' - ORDER BY ' + -CASE @sort_order - WHEN 'cpu' THEN N'qsrs.avg_cpu_time' - WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads' - WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads' - WHEN 'writes' THEN N'qsrs.avg_logical_io_writes' - WHEN 'duration' THEN N'qsrs.avg_duration' - WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory' - WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used' ELSE N'qsrs.avg_cpu_time' END - WHEN 'executions' THEN N'qsrs.count_executions' - WHEN 'recent' THEN N'qsrs.last_execution_time' - WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' - ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' ELSE N'qsrs.avg_cpu_time' END -END + N' DESC -) AS qsrs + FROM #distinct_plans AS dp + CROSS APPLY + ( + SELECT TOP (@queries_top) + qsrs.*' + + SELECT + @sql += N' + FROM ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs' + IF @regression_mode = 1 + BEGIN + SELECT + @sql += N' + JOIN #regression_changes AS regression + ON qsrs.plan_id = regression.plan_id + AND regression.database_id = @database_id' + END + ELSE IF @sort_order = 'plan count by hashes' + BEGIN + SELECT + @sql += N' + JOIN #plan_ids_with_query_hashes AS hashes + ON qsrs.plan_id = hashes.plan_id + AND hashes.database_id = @database_id' + END + ELSE IF @sort_order_is_a_wait = 1 + BEGIN + /* + Note that we do not need this join in + regression mode, even if we are looking + at a wait. The tables here are only for + sorting. In regression mode, we sort + by columns found in #regression_changes. + */ + SELECT + @sql += N' + JOIN #plan_ids_with_total_waits AS waits + ON qsrs.plan_id = waits.plan_id + AND waits.database_id = @database_id' + END; + + SELECT + @sql += N' + WHERE qsrs.plan_id = dp.plan_id + AND 1 = 1 + ' + + CASE WHEN @regression_mode = 1 + THEN N' AND ( 1 = 1 + ' + @regression_where_clause + + N' ) + OR + ( 1 = 1 + ' + + @where_clause + + N' ) ' + ELSE @where_clause + END + + N' + ORDER BY ' + + CASE @regression_mode + WHEN 1 THEN + /* As seen when populating #regression_changes. */ + CASE @regression_direction + WHEN 'regressed' THEN N'regression.change_since_regression_time_period' + WHEN 'worse' THEN N'regression.change_since_regression_time_period' + WHEN 'improved' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'better' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'magnitude' THEN N'ABS(regression.change_since_regression_time_period)' + WHEN 'absolute' THEN N'ABS(regression.change_since_regression_time_period)' + END + ELSE + CASE @sort_order + WHEN 'cpu' THEN N'qsrs.avg_cpu_time' + WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads' + WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads' + WHEN 'writes' THEN N'qsrs.avg_logical_io_writes' + WHEN 'duration' THEN N'qsrs.avg_duration' + WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used' ELSE N'qsrs.avg_cpu_time' END + WHEN 'executions' THEN N'qsrs.count_executions' + WHEN 'recent' THEN N'qsrs.last_execution_time' + WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' + ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' ELSE N'qsrs.avg_cpu_time' END + END + END + N' DESC + ) AS qsrs +) as qsrs_with_lasts GROUP BY - qsrs.plan_id + qsrs_with_lasts.plan_id ' + +/* +In regression mode, we do not mind seeing the +same plan_id twice. We need the below to make +the two time periods under consideration +distinct. +*/ +CASE @regression_mode + WHEN 1 THEN N' , + CASE + WHEN qsrs_with_lasts.last_execution_time >= @start_date AND qsrs_with_lasts.last_execution_time < @end_date + THEN ''No'' + ELSE ''Yes'' + END' + ELSE N' ' +END ++ N' OPTION(RECOMPILE, OPTIMIZE FOR (@queries_top = 9223372036854775807));' + @nc10; IF @debug = 1 @@ -21332,6 +22381,7 @@ INSERT avg_num_physical_io_reads_mb, last_num_physical_io_reads_mb, min_num_physical_io_reads_mb, max_num_physical_io_reads_mb, avg_log_bytes_used_mb, last_log_bytes_used_mb, min_log_bytes_used_mb, max_log_bytes_used_mb, avg_tempdb_space_used_mb, last_tempdb_space_used_mb, min_tempdb_space_used_mb, max_tempdb_space_used_mb, + from_regression_baseline, context_settings ) EXEC sys.sp_executesql @@ -21346,7 +22396,9 @@ EXEC sys.sp_executesql @database_id, @queries_top, @work_start_utc, - @work_end_utc; + @work_end_utc, + @regression_baseline_start_date, + @regression_baseline_end_date; IF @troubleshoot_performance = 1 BEGIN @@ -21802,37 +22854,102 @@ INSERT max_used_threads ) SELECT - deqs.statement_sql_handle, - MAX(deqs.total_grant_kb) / 1024., - MAX(deqs.last_grant_kb) / 1024., - MAX(deqs.min_grant_kb) / 1024., - MAX(deqs.max_grant_kb) / 1024., - MAX(deqs.total_used_grant_kb) / 1024., - MAX(deqs.last_used_grant_kb) / 1024., - MAX(deqs.min_used_grant_kb) / 1024., - MAX(deqs.max_used_grant_kb) / 1024., - MAX(deqs.total_ideal_grant_kb) / 1024., - MAX(deqs.last_ideal_grant_kb) / 1024., - MAX(deqs.min_ideal_grant_kb) / 1024., - MAX(deqs.max_ideal_grant_kb) / 1024., - MAX(deqs.total_reserved_threads), - MAX(deqs.last_reserved_threads), - MAX(deqs.min_reserved_threads), - MAX(deqs.max_reserved_threads), - MAX(deqs.total_used_threads), - MAX(deqs.last_used_threads), - MAX(deqs.min_used_threads), - MAX(deqs.max_used_threads) -FROM sys.dm_exec_query_stats AS deqs -WHERE EXISTS - ( - SELECT - 1/0 - FROM #query_store_query_text AS qsqt - WHERE qsqt.statement_sql_handle = deqs.statement_sql_handle - ) + deqs_with_lasts.statement_sql_handle, + MAX(deqs_with_lasts.total_grant_kb) / 1024., + MAX(deqs_with_lasts.partitioned_last_grant_kb) / 1024., + MAX(deqs_with_lasts.min_grant_kb) / 1024., + MAX(deqs_with_lasts.max_grant_kb) / 1024., + MAX(deqs_with_lasts.total_used_grant_kb) / 1024., + MAX(deqs_with_lasts.partitioned_last_used_grant_kb) / 1024., + MAX(deqs_with_lasts.min_used_grant_kb) / 1024., + MAX(deqs_with_lasts.max_used_grant_kb) / 1024., + MAX(deqs_with_lasts.total_ideal_grant_kb) / 1024., + MAX(deqs_with_lasts.partitioned_last_ideal_grant_kb) / 1024., + MAX(deqs_with_lasts.min_ideal_grant_kb) / 1024., + MAX(deqs_with_lasts.max_ideal_grant_kb) / 1024., + MAX(deqs_with_lasts.total_reserved_threads), + MAX(deqs_with_lasts.partitioned_last_reserved_threads), + MAX(deqs_with_lasts.min_reserved_threads), + MAX(deqs_with_lasts.max_reserved_threads), + MAX(deqs_with_lasts.total_used_threads), + MAX(deqs_with_lasts.partitioned_last_used_threads), + MAX(deqs_with_lasts.min_used_threads), + MAX(deqs_with_lasts.max_used_threads) +FROM +( + SELECT + deqs.statement_sql_handle, + deqs.total_grant_kb, + deqs.min_grant_kb, + deqs.max_grant_kb, + deqs.total_used_grant_kb, + deqs.min_used_grant_kb, + deqs.max_used_grant_kb, + deqs.total_ideal_grant_kb, + deqs.min_ideal_grant_kb, + deqs.max_ideal_grant_kb, + deqs.total_reserved_threads, + deqs.min_reserved_threads, + deqs.max_reserved_threads, + deqs.total_used_threads, + deqs.min_used_threads, + deqs.max_used_threads, + partitioned_last_grant_kb = + LAST_VALUE(deqs.last_grant_kb) OVER + ( + PARTITION BY + deqs.sql_handle + ORDER BY + deqs.last_execution_time DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_used_grant_kb = + LAST_VALUE(deqs.last_used_grant_kb) OVER + ( + PARTITION BY + deqs.sql_handle + ORDER BY + deqs.last_execution_time DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_ideal_grant_kb = + LAST_VALUE(deqs.last_ideal_grant_kb) OVER + ( + PARTITION BY + deqs.sql_handle + ORDER BY + deqs.last_execution_time DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_reserved_threads = + LAST_VALUE(deqs.last_reserved_threads) OVER + ( + PARTITION BY + deqs.sql_handle + ORDER BY + deqs.last_execution_time DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ), + partitioned_last_used_threads = + LAST_VALUE(deqs.last_used_threads) OVER + ( + PARTITION BY + deqs.sql_handle + ORDER BY + deqs.last_execution_time DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ) + FROM sys.dm_exec_query_stats AS deqs + WHERE EXISTS + ( + SELECT + 1/0 + FROM #query_store_query_text AS qsqt + WHERE qsqt.statement_sql_handle = deqs.statement_sql_handle + ) +) AS deqs_with_lasts GROUP BY - deqs.statement_sql_handle + deqs_with_lasts.statement_sql_handle OPTION(RECOMPILE); SELECT @@ -22090,37 +23207,59 @@ BEGIN @sql += N' SELECT @database_id, - qsws.plan_id, - qsws.wait_category_desc, + qsws_with_lasts.plan_id, + qsws_with_lasts.wait_category_desc, total_query_wait_time_ms = - SUM(qsws.total_query_wait_time_ms), + SUM(qsws_with_lasts.total_query_wait_time_ms), avg_query_wait_time_ms = - SUM(qsws.avg_query_wait_time_ms), + SUM(qsws_with_lasts.avg_query_wait_time_ms), last_query_wait_time_ms = - SUM(qsws.last_query_wait_time_ms), + MAX(qsws_with_lasts.partitioned_last_query_wait_time_ms), min_query_wait_time_ms = - SUM(qsws.min_query_wait_time_ms), + SUM(qsws_with_lasts.min_query_wait_time_ms), max_query_wait_time_ms = - SUM(qsws.max_query_wait_time_ms) -FROM #query_store_runtime_stats AS qsrs -CROSS APPLY + SUM(qsws_with_lasts.max_query_wait_time_ms) +FROM ( - SELECT TOP (5) - qsws.* - FROM ' + @database_name_quoted + N'.sys.query_store_wait_stats AS qsws - WHERE qsws.runtime_stats_interval_id = qsrs.runtime_stats_interval_id - AND qsws.plan_id = qsrs.plan_id - AND qsws.wait_category > 0 - AND qsws.min_query_wait_time_ms > 0 - ORDER BY - qsws.avg_query_wait_time_ms DESC -) AS qsws -WHERE qsrs.database_id = @database_id + SELECT + qsws.*, + /* + We need this here to make sure that PARTITION BY runs before GROUP BY but after CROSS APPLY. + If it were after GROUP BY, then we would be dealing with already aggregated data. + If it were inside the CROSS APPLY, then we would be dealing with windows of size one. + Both are very wrong, so we need this. + */ + partitioned_last_query_wait_time_ms = + LAST_VALUE(qsws.last_query_wait_time_ms) OVER + ( + PARTITION BY + qsws.plan_id, + qsws.execution_type, + qsws.wait_category_desc + ORDER BY + qsws.runtime_stats_interval_id DESC + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ) + FROM #query_store_runtime_stats AS qsrs + CROSS APPLY + ( + SELECT TOP (5) + qsws.* + FROM ' + @database_name_quoted + N'.sys.query_store_wait_stats AS qsws + WHERE qsws.runtime_stats_interval_id = qsrs.runtime_stats_interval_id + AND qsws.plan_id = qsrs.plan_id + AND qsws.wait_category > 0 + AND qsws.min_query_wait_time_ms > 0 + ORDER BY + qsws.avg_query_wait_time_ms DESC + ) AS qsws + WHERE qsrs.database_id = @database_id +) AS qsws_with_lasts GROUP BY - qsws.plan_id, - qsws.wait_category_desc + qsws_with_lasts.plan_id, + qsws_with_lasts.wait_category_desc HAVING - SUM(qsws.min_query_wait_time_ms) > 0. + SUM(qsws_with_lasts.min_query_wait_time_ms) > 0. OPTION(RECOMPILE);' + @nc10; IF @debug = 1 @@ -22720,6 +23859,12 @@ primary key violations */ IF @get_all_databases = 1 BEGIN + TRUNCATE TABLE + #regression_baseline_runtime_stats; + + TRUNCATE TABLE + #regression_current_runtime_stats; + TRUNCATE TABLE #distinct_plans; @@ -22895,9 +24040,9 @@ FROM WHEN @timezone IS NULL THEN SWITCHOFFSET - ( + ( qsrs.first_execution_time, - @utc_offset_string + @utc_offset_string ) WHEN @timezone IS NOT NULL THEN qsrs.first_execution_time AT TIME ZONE @timezone @@ -22909,15 +24054,35 @@ FROM WHEN @timezone IS NULL THEN SWITCHOFFSET - ( + ( qsrs.last_execution_time, - @utc_offset_string + @utc_offset_string ) WHEN @timezone IS NOT NULL THEN qsrs.last_execution_time AT TIME ZONE @timezone END, last_execution_time_utc = qsrs.last_execution_time, + ' + /* + Bolt any regression mode columns on, because we need them to + be in scope for sorting. + Has the helpful side-effect of making them visible + in the final output, because our SELECT is just x.*. + + We bolt them on here because it makes a lot of sense to + put the column showing if something is from the baseline time + period right next to the columns showing the dates. + */ + + CASE + WHEN @regression_mode = 1 + THEN N' from_regression_baseline_time_period = qsrs.from_regression_baseline, + query_hash_from_regression_checking = regression.query_hash, + change_in_average_for_query_hash_since_regression_time_period = regression.change_since_regression_time_period, + ' + ELSE N'' + END + + N' qsrs.count_executions, qsrs.executions_per_second, qsrs.avg_duration_ms, @@ -22997,36 +24162,49 @@ FROM PARTITION BY qsrs.plan_id ORDER BY - ' + - CASE @sort_order - WHEN 'cpu' THEN N'qsrs.avg_cpu_time_ms' - WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads_mb' - WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads_mb' - WHEN 'writes' THEN N'qsrs.avg_logical_io_writes_mb' - WHEN 'duration' THEN N'qsrs.avg_duration_ms' - WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory_mb' - WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used_mb' ELSE N'qsrs.avg_cpu_time' END - WHEN 'executions' THEN N'qsrs.count_executions' - WHEN 'recent' THEN N'qsrs.last_execution_time' - WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' - ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' ELSE N'qsrs.avg_cpu_time' END + ' + + + CASE WHEN @regression_mode = 1 THEN + /* As seen when populating #regression_changes. */ + CASE @regression_direction + WHEN 'regressed' THEN N'regression.change_since_regression_time_period' + WHEN 'worse' THEN N'regression.change_since_regression_time_period' + WHEN 'improved' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'better' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'magnitude' THEN N'ABS(regression.change_since_regression_time_period)' + WHEN 'absolute' THEN N'ABS(regression.change_since_regression_time_period)' + END + ELSE + CASE @sort_order + WHEN 'cpu' THEN N'qsrs.avg_cpu_time_ms' + WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads_mb' + WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads_mb' + WHEN 'writes' THEN N'qsrs.avg_logical_io_writes_mb' + WHEN 'duration' THEN N'qsrs.avg_duration_ms' + WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory_mb' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used_mb' ELSE N'qsrs.avg_cpu_time' END + WHEN 'executions' THEN N'qsrs.count_executions' + WHEN 'recent' THEN N'qsrs.last_execution_time' + WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' + ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' + ELSE N'qsrs.avg_cpu_time' END + END END + N' DESC )' /* - Bolt any special sorting columns on, because we need them to - be in scope for sorting. - Has the side-effect of making them visible in the final output, - because our SELECT is just x.*. - - But, really, is having the columns visible in the output a bad thing? - I find it's helpful. + Bolt any special sorting columns on, because we need them to + be in scope for sorting. + Has the helpful side-effect of making them visible + in the final output, because our SELECT is just x.*. */ - + CASE WHEN @sort_order = 'plan count by hashes' - THEN N' , hashes.plan_hash_count_for_query_hash, hashes.query_hash' + + CASE + WHEN @sort_order = 'plan count by hashes' + THEN N' , hashes.plan_hash_count_for_query_hash, + query_hash_from_hash_counting = hashes.query_hash' WHEN @sort_order_is_a_wait = 1 - THEN N' , waits.total_query_wait_time_ms AS total_wait_time_from_sort_order_ms' + THEN N' , total_wait_time_from_sort_order_ms = waits.total_query_wait_time_ms' ELSE N'' - END + END ) ); END; /*End expert mode 1, format output 0 columns*/ @@ -23138,9 +24316,9 @@ FROM WHEN @timezone IS NULL THEN SWITCHOFFSET - ( + ( qsrs.first_execution_time, - @utc_offset_string + @utc_offset_string ) WHEN @timezone IS NOT NULL THEN qsrs.first_execution_time AT TIME ZONE @timezone @@ -23152,15 +24330,49 @@ FROM WHEN @timezone IS NULL THEN SWITCHOFFSET - ( + ( qsrs.last_execution_time, - @utc_offset_string + @utc_offset_string ) WHEN @timezone IS NOT NULL THEN qsrs.last_execution_time AT TIME ZONE @timezone END, last_execution_time_utc = qsrs.last_execution_time, + ' + ) + /* + Bolt any regression mode columns on, because we need them to + be in scope for sorting. + Has the helpful side-effect of making them visible + in the final output, because our SELECT is just x.*. + + We bolt them on here because it makes a lot of sense to + put the column showing if something is from the baseline time + period right next to the columns showing the dates. + */ + + CASE + WHEN @regression_mode = 1 + THEN N' from_regression_baseline_time_period = qsrs.from_regression_baseline, + query_hash_from_regression_checking = regression.query_hash, + ' + ELSE N'' + END + + CASE + /* Be extra nice and make the 'relative' version of regression mode appear as a percentage. */ + WHEN @regression_mode = 1 AND @regression_comparator = 'relative' + THEN N' change_in_average_for_query_hash_since_regression_time_period = FORMAT(regression.change_since_regression_time_period, ''P2''), + ' + WHEN @regression_mode = 1 + THEN N' change_in_average_for_query_hash_since_regression_time_period = FORMAT(regression.change_since_regression_time_period, ''N2''), + ' + ELSE N'' + END + + + CONVERT + ( + nvarchar(MAX), + N' count_executions = FORMAT(qsrs.count_executions, ''N0''), executions_per_second = FORMAT(qsrs.executions_per_second, ''N0''), avg_duration_ms = FORMAT(qsrs.avg_duration_ms, ''N0''), @@ -23241,37 +24453,50 @@ FROM PARTITION BY qsrs.plan_id ORDER BY - ' + - CASE @sort_order - WHEN 'cpu' THEN N'qsrs.avg_cpu_time_ms' - WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads_mb' - WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads_mb' - WHEN 'writes' THEN N'qsrs.avg_logical_io_writes_mb' - WHEN 'duration' THEN N'qsrs.avg_duration_ms' - WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory_mb' - WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used_mb' ELSE N'qsrs.avg_cpu_time' END - WHEN 'executions' THEN N'qsrs.count_executions' - WHEN 'recent' THEN N'qsrs.last_execution_time' - WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' - ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' ELSE N'qsrs.avg_cpu_time' END + ' + + + CASE WHEN @regression_mode = 1 THEN + /* As seen when populating #regression_changes. */ + CASE @regression_direction + WHEN 'regressed' THEN N'regression.change_since_regression_time_period' + WHEN 'worse' THEN N'regression.change_since_regression_time_period' + WHEN 'improved' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'better' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'magnitude' THEN N'ABS(regression.change_since_regression_time_period)' + WHEN 'absolute' THEN N'ABS(regression.change_since_regression_time_period)' + END + ELSE + CASE @sort_order + WHEN 'cpu' THEN N'qsrs.avg_cpu_time_ms' + WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads_mb' + WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads_mb' + WHEN 'writes' THEN N'qsrs.avg_logical_io_writes_mb' + WHEN 'duration' THEN N'qsrs.avg_duration_ms' + WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory_mb' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used_mb' ELSE N'qsrs.avg_cpu_time' END + WHEN 'executions' THEN N'qsrs.count_executions' + WHEN 'recent' THEN N'qsrs.last_execution_time' + WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' + ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' + ELSE N'qsrs.avg_cpu_time' END + END END + N' DESC )' /* - Bolt any special sorting columns on, because we need them to - be in scope for sorting. - Has the side-effect of making them visible in the final output, - because our SELECT is just x.*. - - But, really, is having the columns visible in the output a bad thing? - I find it's helpful, but it does mean that we have to format them - when applicable. + Bolt any special sorting columns on, because we need them to + be in scope for sorting. + Has the helpful side-effect of making them visible + in the final output, because our SELECT is just x.*. + However, we must format them where applicable. */ - + CASE WHEN @sort_order = 'plan count by hashes' - THEN N' , FORMAT(hashes.plan_hash_count_for_query_hash, ''N0'') AS plan_hash_count_for_query_hash, hashes.query_hash' + + CASE + WHEN @sort_order = 'plan count by hashes' + THEN N' , plan_hash_count_for_query_hash = FORMAT(hashes.plan_hash_count_for_query_hash, ''N0''), + query_hash_from_hash_counting = hashes.query_hash' WHEN @sort_order_is_a_wait = 1 - THEN N' , FORMAT(waits.total_query_wait_time_ms, ''N0'') AS total_wait_time_from_sort_order_ms' + THEN N' , total_wait_time_from_sort_order_ms = FORMAT(waits.total_query_wait_time_ms, ''N0'')' ELSE N'' - END + END ) ); END; /*End expert mode = 1, format output = 1*/ @@ -23380,9 +24605,9 @@ FROM WHEN @timezone IS NULL THEN SWITCHOFFSET - ( + ( qsrs.first_execution_time, - @utc_offset_string + @utc_offset_string ) WHEN @timezone IS NOT NULL THEN qsrs.first_execution_time AT TIME ZONE @timezone @@ -23394,15 +24619,35 @@ FROM WHEN @timezone IS NULL THEN SWITCHOFFSET - ( + ( qsrs.last_execution_time, - @utc_offset_string + @utc_offset_string ) WHEN @timezone IS NOT NULL THEN qsrs.last_execution_time AT TIME ZONE @timezone END, last_execution_time_utc = qsrs.last_execution_time, + ' + /* + Bolt any regression mode columns on, because we need them to + be in scope for sorting. + Has the helpful side-effect of making them visible + in the final output, because our SELECT is just x.*. + + We bolt them on here because it makes a lot of sense to + put the column showing if something is from the baseline time + period right next to the columns showing the dates. + */ + + CASE + WHEN @regression_mode = 1 + THEN N' from_regression_baseline_time_period = qsrs.from_regression_baseline, + query_hash_from_regression_checking = regression.query_hash, + change_in_average_for_query_hash_since_regression_time_period = regression.change_since_regression_time_period, + ' + ELSE N'' + END + + N' qsrs.count_executions, qsrs.executions_per_second, qsrs.avg_duration_ms, @@ -23461,35 +24706,47 @@ FROM ORDER BY ' + - CASE @sort_order - WHEN 'cpu' THEN N'qsrs.avg_cpu_time_ms' - WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads_mb' - WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads_mb' - WHEN 'writes' THEN N'qsrs.avg_logical_io_writes_mb' - WHEN 'duration' THEN N'qsrs.avg_duration_ms' - WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory_mb' - WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used_mb' ELSE N'qsrs.avg_cpu_time' END - WHEN 'executions' THEN N'qsrs.count_executions' - WHEN 'recent' THEN N'qsrs.last_execution_time' - WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' - ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' ELSE N'qsrs.avg_cpu_time' END + CASE WHEN @regression_mode = 1 THEN + /* As seen when populating #regression_changes. */ + CASE @regression_direction + WHEN 'regressed' THEN N'regression.change_since_regression_time_period' + WHEN 'worse' THEN N'regression.change_since_regression_time_period' + WHEN 'improved' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'better' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'magnitude' THEN N'ABS(regression.change_since_regression_time_period)' + WHEN 'absolute' THEN N'ABS(regression.change_since_regression_time_period)' + END + ELSE + CASE @sort_order + WHEN 'cpu' THEN N'qsrs.avg_cpu_time_ms' + WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads_mb' + WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads_mb' + WHEN 'writes' THEN N'qsrs.avg_logical_io_writes_mb' + WHEN 'duration' THEN N'qsrs.avg_duration_ms' + WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory_mb' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used_mb' ELSE N'qsrs.avg_cpu_time' END + WHEN 'executions' THEN N'qsrs.count_executions' + WHEN 'recent' THEN N'qsrs.last_execution_time' + WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' + ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' + ELSE N'qsrs.avg_cpu_time' END + END END + N' DESC )' /* - Bolt any special sorting columns on, because we need them to - be in scope for sorting. - Has the side-effect of making them visible in the final output, - because our SELECT is just x.*. - - But, really, is having the columns visible in the output a bad thing? - I find it's helpful. + Bolt any special sorting columns on, because we need them to + be in scope for sorting. + Has the helpful side-effect of making them visible + in the final output, because our SELECT is just x.*. */ - + CASE WHEN @sort_order = 'plan count by hashes' - THEN N' , hashes.plan_hash_count_for_query_hash, hashes.query_hash' + + CASE + WHEN @sort_order = 'plan count by hashes' + THEN N' , hashes.plan_hash_count_for_query_hash, + query_hash_from_hash_counting = hashes.query_hash' WHEN @sort_order_is_a_wait = 1 - THEN N' , waits.total_query_wait_time_ms AS total_wait_time_from_sort_order_ms' + THEN N' , total_wait_time_from_sort_order_ms = waits.total_query_wait_time_ms' ELSE N'' - END + END ) ); END; /*End expert mode = 0, format output = 0*/ @@ -23599,9 +24856,9 @@ FROM WHEN @timezone IS NULL THEN SWITCHOFFSET - ( + ( qsrs.first_execution_time, - @utc_offset_string + @utc_offset_string ) WHEN @timezone IS NOT NULL THEN qsrs.first_execution_time AT TIME ZONE @timezone @@ -23613,15 +24870,44 @@ FROM WHEN @timezone IS NULL THEN SWITCHOFFSET - ( + ( qsrs.last_execution_time, - @utc_offset_string + @utc_offset_string ) WHEN @timezone IS NOT NULL THEN qsrs.last_execution_time AT TIME ZONE @timezone END, last_execution_time_utc = qsrs.last_execution_time, + ' + /* + Bolt any regression mode columns on, because we need them to + be in scope for sorting. + Has the helpful side-effect of making them visible + in the final output, because our SELECT is just x.*. + + We bolt them on here because it makes a lot of sense to + put the column showing if something is from the baseline time + period right next to the columns showing the dates. + */ + + CASE + WHEN @regression_mode = 1 + THEN N' from_regression_baseline_time_period = qsrs.from_regression_baseline, + query_hash_from_regression_checking = regression.query_hash, + ' + ELSE N'' + END + + CASE + /* Be extra nice and make the 'relative' version of regression mode appear as a percentage. */ + WHEN @regression_mode = 1 AND @regression_comparator = 'relative' + THEN N' change_in_average_for_query_hash_since_regression_time_period = FORMAT(regression.change_since_regression_time_period, ''P2''), + ' + WHEN @regression_mode = 1 + THEN N' change_in_average_for_query_hash_since_regression_time_period = FORMAT(regression.change_since_regression_time_period, ''N2''), + ' + ELSE N'' + END + + N' count_executions = FORMAT(qsrs.count_executions, ''N0''), executions_per_second = FORMAT(qsrs.executions_per_second, ''N0''), avg_duration_ms = FORMAT(qsrs.avg_duration_ms, ''N0''), @@ -23680,36 +24966,48 @@ FROM ORDER BY ' + - CASE @sort_order - WHEN 'cpu' THEN N'qsrs.avg_cpu_time_ms' - WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads_mb' - WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads_mb' - WHEN 'writes' THEN N'qsrs.avg_logical_io_writes_mb' - WHEN 'duration' THEN N'qsrs.avg_duration_ms' - WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory_mb' - WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used_mb' ELSE N'qsrs.avg_cpu_time' END - WHEN 'executions' THEN N'qsrs.count_executions' - WHEN 'recent' THEN N'qsrs.last_execution_time' - WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' - ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' ELSE N'qsrs.avg_cpu_time' END + CASE WHEN @regression_mode = 1 THEN + /* As seen when populating #regression_changes. */ + CASE @regression_direction + WHEN 'regressed' THEN N'regression.change_since_regression_time_period' + WHEN 'worse' THEN N'regression.change_since_regression_time_period' + WHEN 'improved' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'better' THEN N'regression.change_since_regression_time_period * -1.0' + WHEN 'magnitude' THEN N'ABS(regression.change_since_regression_time_period)' + WHEN 'absolute' THEN N'ABS(regression.change_since_regression_time_period)' + END + ELSE + CASE @sort_order + WHEN 'cpu' THEN N'qsrs.avg_cpu_time_ms' + WHEN 'logical reads' THEN N'qsrs.avg_logical_io_reads_mb' + WHEN 'physical reads' THEN N'qsrs.avg_physical_io_reads_mb' + WHEN 'writes' THEN N'qsrs.avg_logical_io_writes_mb' + WHEN 'duration' THEN N'qsrs.avg_duration_ms' + WHEN 'memory' THEN N'qsrs.avg_query_max_used_memory_mb' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'qsrs.avg_tempdb_space_used_mb' ELSE N'qsrs.avg_cpu_time' END + WHEN 'executions' THEN N'qsrs.count_executions' + WHEN 'recent' THEN N'qsrs.last_execution_time' + WHEN 'plan count by hashes' THEN N'hashes.plan_hash_count_for_query_hash DESC, hashes.query_hash' + ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'waits.total_query_wait_time_ms' + ELSE N'qsrs.avg_cpu_time' END + END END + N' DESC )' /* - Bolt any special sorting columns on, because we need them to - be in scope for sorting. - Has the side-effect of making them visible in the final output, - because our SELECT is just x.*. - - But, really, is having the columns visible in the output a bad thing? - I find it's helpful, but it does mean that we have to format them - when applicable. + Bolt any special sorting columns on, because we need them to + be in scope for sorting. + Has the helpful side-effect of making them visible + in the final output, because our SELECT is just x.*. + However, we must format them where applicable. */ - + CASE WHEN @sort_order = 'plan count by hashes' - THEN N' , FORMAT(hashes.plan_hash_count_for_query_hash, ''N0'') AS plan_hash_count_for_query_hash, hashes.query_hash' + + CASE + WHEN @sort_order = 'plan count by hashes' + THEN N' , plan_hash_count_for_query_hash = FORMAT(hashes.plan_hash_count_for_query_hash, ''N0''), + query_hash_from_hash_counting = hashes.query_hash' WHEN @sort_order_is_a_wait = 1 - THEN N' , FORMAT(waits.total_query_wait_time_ms, ''N0'') AS total_wait_time_from_sort_order_ms' + THEN N' , total_wait_time_from_sort_order_ms = FORMAT(waits.total_query_wait_time_ms, ''N0'')' ELSE N'' - END + END ) ); END; /*End expert mode = 0, format output = 1*/ @@ -23724,22 +25022,43 @@ FROM nvarchar(MAX), N' FROM #query_store_runtime_stats AS qsrs' - ) + ); + + /* + Bolt on any sort-helping tables. + */ + IF @regression_mode = 1 + BEGIN + SELECT + @sql += N' + JOIN #regression_changes AS regression + ON qsrs.plan_id = regression.plan_id + AND qsrs.database_id = regression.database_id'; + END; + IF @sort_order = 'plan count by hashes' BEGIN SELECT @sql += N' JOIN #plan_ids_with_query_hashes AS hashes ON qsrs.plan_id = hashes.plan_id - AND qsrs.database_id = hashes.database_id' + AND qsrs.database_id = hashes.database_id'; END; + IF @sort_order_is_a_wait = 1 BEGIN SELECT @sql += N' JOIN #plan_ids_with_total_waits AS waits ON qsrs.plan_id = waits.plan_id - AND qsrs.database_id = waits.database_id' + AND qsrs.database_id = waits.database_id'; + + IF @regression_mode = 1 + BEGIN + SELECT + @sql += N' + AND qsrs.from_regression_baseline = waits.from_regression_baseline' + END; END; SELECT @@ -23790,8 +25109,8 @@ SELECT FROM #query_store_query AS qsq WHERE qsq.query_id = qsp.query_id AND qsq.database_id = qsp.database_id - ORDER - BY qsq.last_execution_time DESC + ORDER BY + qsq.last_execution_time DESC ) AS qsq' ); @@ -23914,11 +25233,27 @@ SELECT nvarchar(MAX), N' ) AS x -WHERE x.n = 1 -ORDER BY ' + +' + CASE WHEN @regression_mode = 1 THEN N' ' ELSE N' WHERE x.n = 1 ' END ++ N' ORDER BY ' + CASE @format_output WHEN 0 THEN + CASE WHEN @regression_mode = 1 + AND @regression_direction IN ('improved', 'better') + THEN 'x.change_in_average_for_query_hash_since_regression_time_period ASC, + x.query_hash_from_regression_checking, + x.from_regression_baseline_time_period' + WHEN @regression_mode = 1 + AND @regression_direction IN ('regressed', 'worse') + THEN 'x.change_in_average_for_query_hash_since_regression_time_period DESC, + x.query_hash_from_regression_checking, + x.from_regression_baseline_time_period' + WHEN @regression_mode = 1 + AND @regression_direction IN ('magnitude', 'absolute') + THEN 'ABS(x.change_in_average_for_query_hash_since_regression_time_period) DESC, + x.query_hash_from_regression_checking, + x.from_regression_baseline_time_period' + ELSE CASE @sort_order WHEN 'cpu' THEN N'x.avg_cpu_time_ms' WHEN 'logical reads' THEN N'x.avg_logical_io_reads_mb' @@ -23929,15 +25264,31 @@ ORDER BY ' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'x.avg_tempdb_space_used_mb' ELSE N'x.avg_cpu_time' END WHEN 'executions' THEN N'x.count_executions' WHEN 'recent' THEN N'x.last_execution_time' - WHEN 'plan count by hashes' THEN N'x.plan_hash_count_for_query_hash DESC, x.query_hash' + WHEN 'plan count by hashes' THEN N'x.plan_hash_count_for_query_hash DESC, x.query_hash_from_hash_counting' ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'x.total_wait_time_from_sort_order_ms' ELSE N'x.avg_cpu_time' END - END + END END /* - The ORDER BY is on the same level as the topmost SELECT, which is just SELECT x.*. - This means that to sort formatted output, we have to un-format it. + The ORDER BY is on the same level as the topmost SELECT, which is just SELECT x.*. + This means that to sort formatted output, we have to un-format it. */ WHEN 1 THEN + CASE WHEN @regression_mode = 1 + AND @regression_direction IN ('improved', 'better') + THEN 'TRY_PARSE(replace(x.change_in_average_for_query_hash_since_regression_time_period, ''%'', '''') AS money) ASC, + x.query_hash_from_regression_checking, + x.from_regression_baseline_time_period' + WHEN @regression_mode = 1 + AND @regression_direction IN ('regressed', 'worse') + THEN 'TRY_PARSE(replace(x.change_in_average_for_query_hash_since_regression_time_period, ''%'', '''') AS money) DESC, + x.query_hash_from_regression_checking, + x.from_regression_baseline_time_period' + WHEN @regression_mode = 1 + AND @regression_direction IN ('magnitude', 'absolute') + THEN 'ABS(TRY_PARSE(replace(x.change_in_average_for_query_hash_since_regression_time_period, ''%'', '''') AS money)) DESC, + x.query_hash_from_regression_checking, + x.from_regression_baseline_time_period' + ELSE CASE @sort_order WHEN 'cpu' THEN N'TRY_PARSE(x.avg_cpu_time_ms AS money)' WHEN 'logical reads' THEN N'TRY_PARSE(x.avg_logical_io_reads_mb AS money)' @@ -23948,9 +25299,9 @@ ORDER BY ' + WHEN 'tempdb' THEN CASE WHEN @new = 1 THEN N'TRY_PARSE(x.avg_tempdb_space_used_mb AS money)' ELSE N'TRY_PARSE(x.avg_cpu_time AS money)' END WHEN 'executions' THEN N'TRY_PARSE(x.count_executions AS money)' WHEN 'recent' THEN N'x.last_execution_time' - WHEN 'plan count by hashes' THEN N'TRY_PARSE(x.plan_hash_count_for_query_hash AS money) DESC, x.query_hash' + WHEN 'plan count by hashes' THEN N'TRY_PARSE(x.plan_hash_count_for_query_hash AS money) DESC, x.query_hash_from_hash_counting' ELSE CASE WHEN @sort_order_is_a_wait = 1 THEN N'TRY_PARSE(x.total_wait_time_from_sort_order_ms AS money)' ELSE N'TRY_PARSE(x.avg_cpu_time AS money)' END - END + END END END + N' DESC OPTION(RECOMPILE);' @@ -24022,11 +25373,11 @@ BEGIN CASE WHEN @timezone IS NULL THEN - SWITCHOFFSET + SWITCHOFFSET ( - qspf.create_time, - @utc_offset_string - ) + qspf.create_time, + @utc_offset_string + ) WHEN @timezone IS NOT NULL THEN qspf.create_time AT TIME ZONE @timezone END, @@ -24036,11 +25387,11 @@ BEGIN CASE WHEN @timezone IS NULL THEN - SWITCHOFFSET + SWITCHOFFSET ( - qspf.last_updated_time, - @utc_offset_string - ) + qspf.last_updated_time, + @utc_offset_string + ) WHEN @timezone IS NOT NULL THEN qspf.last_updated_time AT TIME ZONE @timezone END, @@ -25384,8 +26735,6 @@ BEGIN @database_name, sort_order = @sort_order, - sort_order_is_a_wait = - @sort_order_is_a_wait, [top] = @top, start_date = @@ -25460,6 +26809,14 @@ BEGIN @work_start, work_end = @work_end, + regression_baseline_start_date = + @regression_baseline_start_date, + regression_baseline_end_date = + @regression_baseline_end_date, + regression_comparator = + @regression_comparator, + regression_direction = + @regression_direction, help = @help, debug = @@ -25506,6 +26863,8 @@ BEGIN @nc10, where_clause = @where_clause, + regression_where_clause = + @regression_where_clause, procedure_exists = @procedure_exists, query_store_exists = @@ -25514,6 +26873,8 @@ BEGIN @query_store_trouble, query_store_waits_enabled = @query_store_waits_enabled, + sort_order_is_a_wait = + @sort_order_is_a_wait, sql_2022_views = @sql_2022_views, ags_present = @@ -25540,6 +26901,12 @@ BEGIN @start_date_original, end_date_original = @end_date_original, + regression_baseline_start_date_original = + @regression_baseline_start_date_original, + regression_baseline_end_date_original = + @regression_baseline_end_date_original, + regression_mode = + @regression_mode, timezone = @timezone, utc_minutes_difference = @@ -25783,6 +27150,75 @@ BEGIN '#plan_ids_with_total_waits is empty'; END; + IF EXISTS + ( + SELECT + 1/0 + FROM #regression_baseline_runtime_stats AS runtime_stats_baseline + ) + BEGIN + SELECT + table_name = + '#regression_baseline_runtime_stats', + runtime_stats_baseline.* + FROM #regression_baseline_runtime_stats AS runtime_stats_baseline + ORDER BY + runtime_stats_baseline.query_hash + OPTION(RECOMPILE); + END; + ELSE + BEGIN + SELECT + result = + '#regression_baseline_runtime_stats is empty'; + END; + + IF EXISTS + ( + SELECT + 1/0 + FROM #regression_current_runtime_stats AS runtime_stats_current + ) + BEGIN + SELECT + table_name = + '#regression_current_runtime_stats', + runtime_stats_current.* + FROM #regression_current_runtime_stats AS runtime_stats_current + ORDER BY + runtime_stats_current.query_hash + OPTION(RECOMPILE); + END; + ELSE + BEGIN + SELECT + result = + '#regression_current_runtime_stats is empty'; + END; + + IF EXISTS + ( + SELECT + 1/0 + FROM #regression_changes AS changes + ) + BEGIN + SELECT + table_name = + '#regression_changes', + changes.* + FROM #regression_changes AS changes + ORDER BY + changes.plan_id + OPTION(RECOMPILE); + END; + ELSE + BEGIN + SELECT + result = + '#regression_changes is empty'; + END; + IF EXISTS ( SELECT diff --git a/sp_IndexCleanup BETA/sp_IndexCleanup BETA.sql b/sp_IndexCleanup BETA/sp_IndexCleanup BETA.sql index 2c2a703..331ea57 100644 --- a/sp_IndexCleanup BETA/sp_IndexCleanup BETA.sql +++ b/sp_IndexCleanup BETA/sp_IndexCleanup BETA.sql @@ -15,7 +15,7 @@ SET ARITHABORT ON; SET CONCAT_NULL_YIELDS_NULL ON; SET QUOTED_IDENTIFIER ON; SET NUMERIC_ROUNDABORT OFF; -SET IMPLICIT_TRANSACTIONS OFF; +SET IMPLICIT_TRANSACTIONS OFF; SET STATISTICS TIME, IO OFF; GO diff --git a/sp_QuickieStore/Examples.sql b/sp_QuickieStore/Examples.sql index 8013097..e2bbd58 100644 --- a/sp_QuickieStore/Examples.sql +++ b/sp_QuickieStore/Examples.sql @@ -1,16 +1,16 @@ -/* +/* ███████╗██╗ ██╗ █████╗ ███╗ ███╗██████╗ ██╗ ███████╗ ██╔════╝╚██╗██╔╝██╔══██╗████╗ ████║██╔══██╗██║ ██╔════╝ -█████╗ ╚███╔╝ ███████║██╔████╔██║██████╔╝██║ █████╗ -██╔══╝ ██╔██╗ ██╔══██║██║╚██╔╝██║██╔═══╝ ██║ ██╔══╝ +█████╗ ╚███╔╝ ███████║██╔████╔██║██████╔╝██║ █████╗ +██╔══╝ ██╔██╗ ██╔══██║██║╚██╔╝██║██╔═══╝ ██║ ██╔══╝ ███████╗██╔╝ ██╗██║ ██║██║ ╚═╝ ██║██║ ███████╗███████╗ ╚══════╝╚═╝ ╚═╝╚═╝ ╚═╝╚═╝ ╚═╝╚═╝ ╚══════╝╚══════╝ - - ██████╗ █████╗ ██╗ ██╗ ███████╗ -██╔════╝██╔══██╗██║ ██║ ██╔════╝ -██║ ███████║██║ ██║ ███████╗ -██║ ██╔══██║██║ ██║ ╚════██║ -╚██████╗██║ ██║███████╗███████╗███████║ + + ██████╗ █████╗ ██╗ ██╗ ███████╗ +██╔════╝██╔══██╗██║ ██║ ██╔════╝ +██║ ███████║██║ ██║ ███████╗ +██║ ██╔══██║██║ ██║ ╚════██║ +╚██████╗██║ ██║███████╗███████╗███████║ ╚═════╝╚═╝ ╚═╝╚══════╝╚══════╝╚══════╝ Copyright 2024 Darling Data, LLC @@ -44,7 +44,7 @@ EXEC dbo.sp_QuickieStore EXEC dbo.sp_QuickieStore @database_name = 'StackOverflow2013', @top = 10, - @include_query_ids = '13977, 13978'; + @include_query_ids = '13977, 13978'; /*Search for specific plan_ids*/ @@ -55,12 +55,12 @@ EXEC dbo.sp_QuickieStore @start_date = '20210320', @include_plan_ids = '1896, 1897'; - + /*Ignore for specific query_ids*/ EXEC dbo.sp_QuickieStore @database_name = 'StackOverflow2013', @top = 10, - @ignore_query_ids = '13977, 13978'; + @ignore_query_ids = '13977, 13978'; /*Ignore for specific plan_ids*/ @@ -69,7 +69,7 @@ EXEC dbo.sp_QuickieStore @sort_order = 'memory', @top = 10, @start_date = '20210320', - @ignore_plan_ids = '1896, 1897'; + @ignore_plan_ids = '1896, 1897'; /*Search for queries within a date range*/ @@ -78,7 +78,7 @@ EXEC dbo.sp_QuickieStore @sort_order = 'memory', @top = 10, @start_date = '20210320', - @end_date = '20210321'; + @end_date = '20210321'; /*Filter out weekends and anything outside of your choice of hours.*/ EXEC dbo.sp_QuickieStore @@ -260,7 +260,7 @@ EXEC dbo.sp_QuickieStore @database_name = 'StackOverflow2013', @sort_order = 'memory', @top = 10, - @expert_mode = 1; + @expert_mode = 1; /*Use format output to add commas to larger numbers @@ -304,12 +304,12 @@ EXEC dbo.sp_QuickieStore EXEC dbo.sp_QuickieStore @include_plan_hashes = '0x6B84B820B8B38564,0x6B84B999D7B38564'; -/*Search by SQL Handles +/*Search by SQL Handles Do you need to find if one Query Store is tracking the same query that is present in another database's Query Store? If so, use the statement_sql_handle to do that. This helps with scenarios where you have multiple production databases which have the same schema and you want to compare performance across Query Stores. */ EXEC dbo.sp_QuickieStore - @include_sql_handles = + @include_sql_handles = '0x0900F46AC89E66DF744C8A0AD4FD3D3306B90000000000000000000000000000000000000000000000000000,0x0200000AC89E66DF744C8A0AD4FD3D3306B90000000000000000000000000000000000000000000000000000'; /*Search, but ignoring some query hashes*/ @@ -322,7 +322,7 @@ EXEC dbo.sp_QuickieStore /*Search, but ignoring some SQL Handles*/ EXEC dbo.sp_QuickieStore - @ignore_sql_handles = + @ignore_sql_handles = '0x0900F46AC89E66DF744C8A0AD4FD3D3306B90000000000000000000000000000000000000000000000000000,0x0200000AC89E66DF744C8A0AD4FD3D3306B90000000000000000000000000000000000000000000000000000'; /*What query hashes have the most plans? @@ -410,8 +410,8 @@ EXEC dbo.sp_QuickieStore DECLARE @version_output varchar(30), @version_date_output datetime; -EXEC sp_QuickieStore - @version = @version_output OUTPUT, +EXEC sp_QuickieStore + @version = @version_output OUTPUT, @version_date = @version_date_output OUTPUT; SELECT diff --git a/sp_QuickieStore/sp_QuickieStore.sql b/sp_QuickieStore/sp_QuickieStore.sql index b172297..7728474 100644 --- a/sp_QuickieStore/sp_QuickieStore.sql +++ b/sp_QuickieStore/sp_QuickieStore.sql @@ -5213,7 +5213,7 @@ BEGIN @work_end_utc, @regression_baseline_start_date, @regression_baseline_end_date; - + IF @troubleshoot_performance = 1 BEGIN SET STATISTICS XML OFF; @@ -5263,7 +5263,7 @@ BEGIN FROM ' + @database_name_quoted + N'.sys.query_store_runtime_stats AS qsrs JOIN ' + @database_name_quoted + N'.sys.query_store_wait_stats AS qsws ON qsrs.plan_id = qsws.plan_id - WHERE 1 = 1 + WHERE 1 = 1 ' + CASE WHEN @regression_mode = 1 THEN N' AND ( 1 = 1 @@ -5346,11 +5346,11 @@ OR @current_table nvarchar(100)', @sql, @current_table; - END; + END; END; /* 'total waits' is special. It's a sum, not a max, so -we cover it above rather than here. +we cover it above rather than here. */ IF @sort_order_is_a_wait = 1 @@ -5722,7 +5722,7 @@ BEGIN must repeat some of the tricks we used for #plan_ids_with_query_hashes. */ - SELECT + SELECT @sql += N' SELECT @database_id, @@ -5764,7 +5764,7 @@ BEGIN ( SELECT current_stats.query_hash, - change_since_regression_time_period = + change_since_regression_time_period = ' + CASE @regression_comparator WHEN 'relative' THEN N'((current_stats.current_metric_average / NULLIF(baseline.regression_metric_average, 0.0)) - 1.0)' @@ -5782,7 +5782,7 @@ BEGIN will give change_since_regression_time_period values that are smaller than metrics that are worse. In other words, ORDER BY change_since_regression_time_period DESC - gives us the regressed queries first. + gives us the regressed queries first. This is true regardless of @regression_comparator. To make @regression_direction behave as intended, we need to account for this. We could use dynamic SQL, @@ -5828,7 +5828,7 @@ BEGIN ' + @where_clause + N' - ) + ) ) AS plans_for_hashes ON hashes_with_changes.query_hash = plans_for_hashes.query_hash OPTION(RECOMPILE, OPTIMIZE FOR (@top = 9223372036854775807));' + @nc10; @@ -6118,7 +6118,7 @@ distinct. IF @regression_mode = 1 BEGIN SELECT - @sql += N' + @sql += N' CASE WHEN qsrs_with_lasts.last_execution_time >= @start_date AND qsrs_with_lasts.last_execution_time < @end_date THEN ''No'' @@ -6128,14 +6128,14 @@ END ELSE BEGIN SELECT - @sql += N' + @sql += N' NULL,'; END; SELECT @sql += N' context_settings = NULL -FROM +FROM ( SELECT qsrs.*, @@ -6304,7 +6304,7 @@ SELECT @sql += N' JOIN #regression_changes AS regression ON qsrs.plan_id = regression.plan_id - AND regression.database_id = @database_id' + AND regression.database_id = @database_id' END ELSE IF @sort_order = 'plan count by hashes' BEGIN