From ac11ac8adc475ac0a27865065bbeaa695fee9b8b Mon Sep 17 00:00:00 2001 From: ClaudioESSilva Date: Wed, 28 Sep 2022 22:06:15 +0100 Subject: [PATCH 1/5] Add filter by execution_type_desc --- sp_QuickieStore/sp_QuickieStore.sql | 26 +++++++++++++++++++++----- 1 file changed, 21 insertions(+), 5 deletions(-) diff --git a/sp_QuickieStore/sp_QuickieStore.sql b/sp_QuickieStore/sp_QuickieStore.sql index 31edc35..be2cf4c 100644 --- a/sp_QuickieStore/sp_QuickieStore.sql +++ b/sp_QuickieStore/sp_QuickieStore.sql @@ -46,7 +46,7 @@ https://github.com/erikdarlingdata/DarlingData */ CREATE OR ALTER PROCEDURE - dbo.sp_QuickieStore + dbo.sp_QuickieStore ( @database_name sysname = NULL, @sort_order varchar(20) = 'cpu', @@ -54,7 +54,8 @@ CREATE OR ALTER PROCEDURE @start_date datetime = NULL, @end_date datetime = NULL, @execution_count bigint = NULL, - @duration_ms bigint = NULL , + @duration_ms bigint = NULL, + @execution_type_desc nvarchar(60) = NULL, @procedure_schema sysname = NULL, @procedure_name sysname = NULL, @include_plan_ids nvarchar(4000) = NULL, @@ -149,6 +150,7 @@ BEGIN WHEN '@end_date' THEN 'the end date of your search' WHEN '@execution_count' THEN 'the minimum number of executions a query must have' WHEN '@duration_ms' THEN 'the minimum duration a query must have' + WHEN '@execution_type_desc' THEN 'the type of execution you want to filter' WHEN '@procedure_schema' THEN 'the schema of the procedure you''re searching for' WHEN '@procedure_name' THEN 'the name of the programmable object you''re searching for' WHEN '@include_plan_ids' THEN 'a list of plan ids to search for' @@ -181,6 +183,7 @@ BEGIN WHEN '@end_date' THEN 'January 1, 1753, through December 31, 9999' WHEN '@execution_count' THEN 'a positive integer between 1 and 9,223,372,036,854,775,807' WHEN '@duration_ms' THEN 'a positive integer between 1 and 9,223,372,036,854,775,807' + WHEN '@execution_type_desc' THEN 'regular, aborted, exception' WHEN '@procedure_schema' THEN 'a valid schema in your database' WHEN '@procedure_name' THEN 'a valid programmable object in your database' WHEN '@include_plan_ids' THEN 'a string; comma separated for multiple ids' @@ -213,6 +216,7 @@ BEGIN WHEN '@end_date' THEN 'NULL' WHEN '@execution_count' THEN 'NULL' WHEN '@duration_ms' THEN 'NULL' + WHEN '@execution_type_desc' THEN 'NULL' WHEN '@procedure_schema' THEN 'NULL; dbo if NULL and procedure name is not NULL' WHEN '@procedure_name' THEN 'NULL' WHEN '@include_plan_ids' THEN 'NULL' @@ -1065,7 +1069,8 @@ SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;', @start_date datetime, @end_date datetime, @execution_count bigint, - @duration_ms bigint', + @duration_ms bigint, + @execution_type_desc nvarchar(60)', @plans_top = CASE WHEN @include_plan_ids IS NULL @@ -1697,6 +1702,13 @@ BEGIN @where_clause += N'AND qsrs.avg_duration >= (@duration_ms * 1000.)' + @nc10; END; +IF @execution_type_desc IS NOT NULL +BEGIN + SELECT + @where_clause += N'AND qsrs.execution_type_desc = @execution_type_desc' + @nc10; +END; + + /* In this section we set up the filter if someone's searching for a single stored procedure in Query Store. @@ -3051,7 +3063,8 @@ EXEC sys.sp_executesql @start_date, @end_date, @execution_count, - @duration_ms; + @duration_ms, + @execution_type_desc; IF @troubleshoot_performance = 1 BEGIN @@ -3233,7 +3246,8 @@ EXEC sys.sp_executesql @start_date, @end_date, @execution_count, - @duration_ms; + @duration_ms, + @execution_type_desc; IF @troubleshoot_performance = 1 BEGIN @@ -6367,6 +6381,8 @@ BEGIN @execution_count, duration_ms = @duration_ms, + execution_type_desc = + @execution_type_desc, procedure_schema = @procedure_schema, procedure_name = From 302bc1e982b274b4b0a71c78f1daf93f4efed4cf Mon Sep 17 00:00:00 2001 From: ClaudioESSilva Date: Wed, 28 Sep 2022 22:07:07 +0100 Subject: [PATCH 2/5] fix AGs validation @ Azure SQL DB --- sp_QuickieStore/sp_QuickieStore.sql | 34 ++++++++++++++++++----------- 1 file changed, 21 insertions(+), 13 deletions(-) diff --git a/sp_QuickieStore/sp_QuickieStore.sql b/sp_QuickieStore/sp_QuickieStore.sql index be2cf4c..8d4b552 100644 --- a/sp_QuickieStore/sp_QuickieStore.sql +++ b/sp_QuickieStore/sp_QuickieStore.sql @@ -1653,19 +1653,27 @@ OPTION(RECOMPILE); /* See if AGs are a thing so we can skip the checks for replica stuff */ -SELECT - @ags_present = - CASE - WHEN EXISTS - ( - SELECT - 1/0 - FROM sys.availability_groups AS ag - ) - THEN 1 - ELSE 0 - END -OPTION(RECOMPILE); +IF (@azure = 1) +BEGIN + SELECT + @ags_present = 0 +END +ELSE +BEGIN + SELECT + @ags_present = + CASE + WHEN EXISTS + ( + SELECT + 1/0 + FROM sys.availability_groups AS ag + ) + THEN 1 + ELSE 0 + END + OPTION(RECOMPILE); +END /* Get filters ready, or whatever From d465757bc9e13264ca25d05e2dc4478fc2727975 Mon Sep 17 00:00:00 2001 From: ClaudioESSilva Date: Wed, 28 Sep 2022 22:13:48 +0100 Subject: [PATCH 3/5] fix spaces vs tab --- sp_QuickieStore/sp_QuickieStore.sql | 20 ++++++++++---------- 1 file changed, 10 insertions(+), 10 deletions(-) diff --git a/sp_QuickieStore/sp_QuickieStore.sql b/sp_QuickieStore/sp_QuickieStore.sql index 8d4b552..80594ce 100644 --- a/sp_QuickieStore/sp_QuickieStore.sql +++ b/sp_QuickieStore/sp_QuickieStore.sql @@ -46,7 +46,7 @@ https://github.com/erikdarlingdata/DarlingData */ CREATE OR ALTER PROCEDURE - dbo.sp_QuickieStore + dbo.sp_QuickieStore ( @database_name sysname = NULL, @sort_order varchar(20) = 'cpu', @@ -55,7 +55,7 @@ CREATE OR ALTER PROCEDURE @end_date datetime = NULL, @execution_count bigint = NULL, @duration_ms bigint = NULL, - @execution_type_desc nvarchar(60) = NULL, + @execution_type_desc nvarchar(60) = NULL, @procedure_schema sysname = NULL, @procedure_name sysname = NULL, @include_plan_ids nvarchar(4000) = NULL, @@ -150,7 +150,7 @@ BEGIN WHEN '@end_date' THEN 'the end date of your search' WHEN '@execution_count' THEN 'the minimum number of executions a query must have' WHEN '@duration_ms' THEN 'the minimum duration a query must have' - WHEN '@execution_type_desc' THEN 'the type of execution you want to filter' + WHEN '@execution_type_desc' THEN 'the type of execution you want to filter' WHEN '@procedure_schema' THEN 'the schema of the procedure you''re searching for' WHEN '@procedure_name' THEN 'the name of the programmable object you''re searching for' WHEN '@include_plan_ids' THEN 'a list of plan ids to search for' @@ -183,7 +183,7 @@ BEGIN WHEN '@end_date' THEN 'January 1, 1753, through December 31, 9999' WHEN '@execution_count' THEN 'a positive integer between 1 and 9,223,372,036,854,775,807' WHEN '@duration_ms' THEN 'a positive integer between 1 and 9,223,372,036,854,775,807' - WHEN '@execution_type_desc' THEN 'regular, aborted, exception' + WHEN '@execution_type_desc' THEN 'regular, aborted, exception' WHEN '@procedure_schema' THEN 'a valid schema in your database' WHEN '@procedure_name' THEN 'a valid programmable object in your database' WHEN '@include_plan_ids' THEN 'a string; comma separated for multiple ids' @@ -216,7 +216,7 @@ BEGIN WHEN '@end_date' THEN 'NULL' WHEN '@execution_count' THEN 'NULL' WHEN '@duration_ms' THEN 'NULL' - WHEN '@execution_type_desc' THEN 'NULL' + WHEN '@execution_type_desc' THEN 'NULL' WHEN '@procedure_schema' THEN 'NULL; dbo if NULL and procedure name is not NULL' WHEN '@procedure_name' THEN 'NULL' WHEN '@include_plan_ids' THEN 'NULL' @@ -1070,7 +1070,7 @@ SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;', @end_date datetime, @execution_count bigint, @duration_ms bigint, - @execution_type_desc nvarchar(60)', + @execution_type_desc nvarchar(60)', @plans_top = CASE WHEN @include_plan_ids IS NULL @@ -3072,7 +3072,7 @@ EXEC sys.sp_executesql @end_date, @execution_count, @duration_ms, - @execution_type_desc; + @execution_type_desc; IF @troubleshoot_performance = 1 BEGIN @@ -3255,7 +3255,7 @@ EXEC sys.sp_executesql @end_date, @execution_count, @duration_ms, - @execution_type_desc; + @execution_type_desc; IF @troubleshoot_performance = 1 BEGIN @@ -6389,8 +6389,8 @@ BEGIN @execution_count, duration_ms = @duration_ms, - execution_type_desc = - @execution_type_desc, + execution_type_desc = + @execution_type_desc, procedure_schema = @procedure_schema, procedure_name = From 899fa7be4f2d6d8123343b589fb7d2686fc00542 Mon Sep 17 00:00:00 2001 From: ClaudioESSilva Date: Wed, 28 Sep 2022 22:28:19 +0100 Subject: [PATCH 4/5] add example using @execution_type_desc --- sp_QuickieStore/Examples.sql | 5 +++++ 1 file changed, 5 insertions(+) diff --git a/sp_QuickieStore/Examples.sql b/sp_QuickieStore/Examples.sql index e58c859..189d592 100644 --- a/sp_QuickieStore/Examples.sql +++ b/sp_QuickieStore/Examples.sql @@ -80,6 +80,11 @@ EXEC dbo.sp_QuickieStore @top = 10, @duration_ms = 10000; +/*Search for queries with a specific execution type*/ +EXEC dbo.sp_QuickieStore + @database_name = 'StackOverflow2013', + @top = 10, + @execution_type_desc = 'aborted'; /*Search for a specific stored procedure*/ EXEC dbo.sp_QuickieStore From 52652d92c21cc229ebd02a639d59415b12d0f78c Mon Sep 17 00:00:00 2001 From: Erik Darling <2136037+erikdarlingdata@users.noreply.github.com> Date: Fri, 21 Oct 2022 11:20:20 -0400 Subject: [PATCH 5/5] Update ClearTokenPerm Agent Job.sql --- ClearTokenPerm/ClearTokenPerm Agent Job.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/ClearTokenPerm/ClearTokenPerm Agent Job.sql b/ClearTokenPerm/ClearTokenPerm Agent Job.sql index 0d6a26f..bd020ad 100644 --- a/ClearTokenPerm/ClearTokenPerm Agent Job.sql +++ b/ClearTokenPerm/ClearTokenPerm Agent Job.sql @@ -6,7 +6,7 @@ BEGIN TRANSACTION; DECLARE @ReturnCode int = 0, @jobId binary(16), - @active_start_date datetime = GETDATE(); + @active_start_date int = (SELECT CONVERT(int, CONVERT(varchar(35), GETDATE(), 112))); IF NOT EXISTS ( @@ -115,4 +115,4 @@ QuitWithRollback: ROLLBACK TRANSACTION; EndSave: -GO \ No newline at end of file +GO