From b639592d8b5dae8d50f334b0df8cadac00aaed4b Mon Sep 17 00:00:00 2001 From: Erik Darling <2136037+erikdarlingdata@users.noreply.github.com> Date: Mon, 1 Apr 2024 21:52:46 -0400 Subject: [PATCH 1/5] Update sp_QuickieStore.sql Closes #391 --- sp_QuickieStore/sp_QuickieStore.sql | 111 +++++++++++++++++----------- 1 file changed, 69 insertions(+), 42 deletions(-) diff --git a/sp_QuickieStore/sp_QuickieStore.sql b/sp_QuickieStore/sp_QuickieStore.sql index faabff9..4e21964 100644 --- a/sp_QuickieStore/sp_QuickieStore.sql +++ b/sp_QuickieStore/sp_QuickieStore.sql @@ -1182,41 +1182,79 @@ cursor block because some of them are assigned for the specific database that is currently being looked at */ -INSERT - #databases WITH(TABLOCK) + +IF ( - database_name -) SELECT - database_name = - ISNULL(@database_name, DB_NAME()) -WHERE @get_all_databases = 0 + CONVERT + ( + sysname, + SERVERPROPERTY('EngineEdition') + ) +) IN (5, 8) +BEGIN + INSERT INTO + #databases WITH(TABLOCK) + ( + database_name + ) + SELECT + database_name = + ISNULL(@database_name, DB_NAME()) + WHERE @get_all_databases = 0 -UNION ALL + UNION ALL -SELECT - database_name = - d.name -FROM sys.databases AS d -WHERE @get_all_databases = 1 -AND d.is_query_store_on = 1 -AND d.database_id > 4 -AND d.state = 0 -AND d.is_in_standby = 0 -AND d.is_read_only = 0 -AND NOT EXISTS -( - SELECT - 1/0 - FROM sys.dm_hadr_availability_replica_states AS s - JOIN sys.availability_databases_cluster AS c - ON s.group_id = c.group_id - AND d.name = c.database_name - WHERE s.is_local <> 1 - AND s.role_desc <> N'PRIMARY' - AND DATABASEPROPERTYEX(c.database_name, N'Updateability') <> N'READ_WRITE' -) -OPTION(RECOMPILE); + SELECT + database_name = + d.name + FROM sys.databases AS d + WHERE @get_all_databases = 1 + AND d.is_query_store_on = 1 + AND d.database_id > 4 + AND d.state = 0 + AND d.is_in_standby = 0 + AND d.is_read_only = 0 + OPTION(RECOMPILE); +END +ELSE +BEGIN + INSERT + #databases WITH(TABLOCK) + ( + database_name + ) + SELECT + database_name = + ISNULL(@database_name, DB_NAME()) + WHERE @get_all_databases = 0 + + UNION ALL + + SELECT + database_name = + d.name + FROM sys.databases AS d + WHERE @get_all_databases = 1 + AND d.is_query_store_on = 1 + AND d.database_id > 4 + AND d.state = 0 + AND d.is_in_standby = 0 + AND d.is_read_only = 0 + AND NOT EXISTS + ( + SELECT + 1/0 + FROM sys.dm_hadr_availability_replica_states AS s + JOIN sys.availability_databases_cluster AS c + ON s.group_id = c.group_id + AND d.name = c.database_name + WHERE s.is_local <> 1 + AND s.role_desc <> N'PRIMARY' + AND DATABASEPROPERTYEX(c.database_name, N'Updateability') <> N'READ_WRITE' + ) + OPTION(RECOMPILE); +END; DECLARE database_cursor CURSOR @@ -1246,17 +1284,6 @@ BEGIN END; SELECT - @azure = - CASE - WHEN - CONVERT - ( - sysname, - SERVERPROPERTY('EDITION') - ) = N'SQL Azure' - THEN 1 - ELSE 0 - END, @engine = CONVERT ( From d783041df4513f96f9d20a79ceed0f5f3b6e51a6 Mon Sep 17 00:00:00 2001 From: Erik Darling <2136037+erikdarlingdata@users.noreply.github.com> Date: Mon, 1 Apr 2024 22:46:04 -0400 Subject: [PATCH 2/5] Update sp_PressureDetector.sql Improve sorting for the uptime wait stats query --- sp_PressureDetector/sp_PressureDetector.sql | 10 +++++++--- 1 file changed, 7 insertions(+), 3 deletions(-) diff --git a/sp_PressureDetector/sp_PressureDetector.sql b/sp_PressureDetector/sp_PressureDetector.sql index 4d3e397..b5c3014 100644 --- a/sp_PressureDetector/sp_PressureDetector.sql +++ b/sp_PressureDetector/sp_PressureDetector.sql @@ -367,6 +367,7 @@ OPTION(MAXDOP 1, RECOMPILE);', percent_signal_waits decimal(38,2), waiting_tasks_count_n bigint, sample_time datetime, + sorting bigint, waiting_tasks_count AS REPLACE ( @@ -519,7 +520,8 @@ OPTION(MAXDOP 1, RECOMPILE);', avg_ms_per_wait, percent_signal_waits, waiting_tasks_count_n, - sample_time + sample_time, + sorting ) SELECT hours_uptime = @@ -655,7 +657,9 @@ OPTION(MAXDOP 1, RECOMPILE);', ), dows.waiting_tasks_count, sample_time = - GETDATE() + GETDATE(), + sorting = + ROW_NUMBER() OVER (ORDER BY dows.wait_time_ms DESC) FROM sys.dm_os_wait_stats AS dows WHERE ( @@ -748,7 +752,7 @@ OPTION(MAXDOP 1, RECOMPILE);', ) FROM @waits AS w ORDER BY - w.hours_wait_time DESC; + w.sorting; END; IF From 67ed9eeba47112b071ff8d836655436343ad11e2 Mon Sep 17 00:00:00 2001 From: Erik Darling <2136037+erikdarlingdata@users.noreply.github.com> Date: Tue, 2 Apr 2024 09:04:02 -0400 Subject: [PATCH 3/5] Update sp_QuickieStore.sql Add another check to prevent AG query --- sp_QuickieStore/sp_QuickieStore.sql | 35 +++++++++++++++++++---------- 1 file changed, 23 insertions(+), 12 deletions(-) diff --git a/sp_QuickieStore/sp_QuickieStore.sql b/sp_QuickieStore/sp_QuickieStore.sql index 4e21964..ab70f92 100644 --- a/sp_QuickieStore/sp_QuickieStore.sql +++ b/sp_QuickieStore/sp_QuickieStore.sql @@ -2308,19 +2308,30 @@ BEGIN END; ELSE BEGIN - SELECT - @ags_present = - CASE - WHEN EXISTS - ( - SELECT - 1/0 - FROM sys.availability_groups AS ag - ) - THEN 1 - ELSE 0 - END + IF + ( + SELECT + CONVERT + ( + sysname, + SERVERPROPERTY('EngineEdition') + ) + ) NOT IN (5, 8) + BEGIN + SELECT + @ags_present = + CASE + WHEN EXISTS + ( + SELECT + 1/0 + FROM sys.availability_groups AS ag + ) + THEN 1 + ELSE 0 + END OPTION(RECOMPILE); + END END; /* From db77a870d666573dc170cf0345952fa26be60806 Mon Sep 17 00:00:00 2001 From: Erik Darling <2136037+erikdarlingdata@users.noreply.github.com> Date: Tue, 2 Apr 2024 09:34:16 -0400 Subject: [PATCH 4/5] Update sp_QuickieStore.sql Closes #395 --- sp_QuickieStore/sp_QuickieStore.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/sp_QuickieStore/sp_QuickieStore.sql b/sp_QuickieStore/sp_QuickieStore.sql index ab70f92..c1c7809 100644 --- a/sp_QuickieStore/sp_QuickieStore.sql +++ b/sp_QuickieStore/sp_QuickieStore.sql @@ -442,7 +442,7 @@ Hold plan_ids for plans we want CREATE TABLE #include_plan_ids ( - plan_id bigint PRIMARY KEY + plan_id bigint PRIMARY KEY WITH (IGNORE_DUP_KEY = ON) ); /* @@ -460,7 +460,7 @@ Hold plan_ids for ignored plans CREATE TABLE #ignore_plan_ids ( - plan_id bigint PRIMARY KEY + plan_id bigint PRIMARY KEY WITH (IGNORE_DUP_KEY = ON) ); /* From 5145534c625c2eb959ffbe2f3dfdf88343b973ef Mon Sep 17 00:00:00 2001 From: Erik Darling <2136037+erikdarlingdata@users.noreply.github.com> Date: Tue, 2 Apr 2024 11:28:27 -0400 Subject: [PATCH 5/5] Update sp_QuickieStore.sql --- sp_QuickieStore/sp_QuickieStore.sql | 17 +++++++++++++++-- 1 file changed, 15 insertions(+), 2 deletions(-) diff --git a/sp_QuickieStore/sp_QuickieStore.sql b/sp_QuickieStore/sp_QuickieStore.sql index c1c7809..7de1b5f 100644 --- a/sp_QuickieStore/sp_QuickieStore.sql +++ b/sp_QuickieStore/sp_QuickieStore.sql @@ -1284,6 +1284,17 @@ BEGIN END; SELECT + @azure = + CASE + WHEN + CONVERT + ( + sysname, + SERVERPROPERTY('EDITION') + ) = N'SQL Azure' + THEN 1 + ELSE 0 + END, @engine = CONVERT ( @@ -3831,7 +3842,8 @@ WHERE qsp.is_forced_plan = 1'; IF @only_queries_with_forced_plan_failures = 1 BEGIN - SELECT @sql += N' + SELECT + @sql += N' AND qsp.last_force_failure_reason > 0' END @@ -4591,7 +4603,8 @@ IF AND @sql_2022_views = 1 ) BEGIN - SELECT @sql += N' + SELECT + @sql += N' qsp.plan_forcing_type_desc, qsp.has_compile_replay_script, qsp.is_optimized_plan_forcing_disabled,