Skip to content

Validated @query_execution_type_desc's value. #494

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion README.md
Original file line number Diff line number Diff line change
Expand Up @@ -245,7 +245,7 @@ Current valid parameter details:
| @timezone | sysname | user specified time zone to override dates displayed in results | SELECT tzi.* FROM sys.time_zone_info AS tzi; | NULL |
| @execution_count | bigint | the minimum number of executions a query must have | a positive integer between 1 and 9,223,372,036,854,775,807 | NULL |
| @duration_ms | bigint | the minimum duration a query must have to show up in results | a positive integer between 1 and 9,223,372,036,854,775,807 | NULL |
| @execution_type_desc | nvarchar | the type of execution you want to filter by (success, failure) | regular, aborted, exception | NULL |
| @execution_type_desc | nvarchar | the type of execution you want to filter by (regular, aborted, exception) | regular, aborted, exception | NULL |
| @procedure_schema | sysname | the schema of the procedure you're searching for | a valid schema in your database | NULL; dbo if NULL and procedure name is not NULL |
| @procedure_name | sysname | the name of the programmable object you're searching for | a valid programmable object in your database, can use wildcards | NULL |
| @include_plan_ids | nvarchar | a list of plan ids to search for | a string; comma separated for multiple ids | NULL |
Expand Down
28 changes: 26 additions & 2 deletions sp_QuickieStore/Examples.sql
Original file line number Diff line number Diff line change
Expand Up @@ -86,18 +86,42 @@ EXEC dbo.sp_QuickieStore
@top = 10,
@duration_ms = 10000;

/*Search for queries with a specific execution type*/

/*Search for queries with a specific execution type
When we do not provide this parameter, we grab all types.
This example grabs "aborted" queries, which are queries cancelled by the client.
This is a great way to find timeouts.
*/
EXEC dbo.sp_QuickieStore
@database_name = 'StackOverflow2013',
@top = 10,
@execution_type_desc = 'aborted';

/*Search for queries that errored
As above, but for "exception" queries.
This grabs queries that were cancelled by throwing exceptions.
It's no substitute for proper error monitoring, but it can be a good early warning.
*/
EXEC dbo.sp_QuickieStore
@database_name = 'StackOverflow2013',
@top = 10,
@execution_type_desc = 'exception';

/*Search for queries that finished normally
As above, but for "regular" queries.
This grabs queries that were not cancelled.
*/
EXEC dbo.sp_QuickieStore
@database_name = 'StackOverflow2013',
@top = 10,
@execution_type_desc = 'regular';


/*Search for a specific stored procedure*/
EXEC dbo.sp_QuickieStore
@database_name = 'StackOverflow2013',
@procedure_name = 'top_percent_sniffer';


/*Search for specific query text*/
EXEC dbo.sp_QuickieStore
@database_name = 'StackOverflow2013',
Expand Down
26 changes: 24 additions & 2 deletions sp_QuickieStore/sp_QuickieStore.sql
Original file line number Diff line number Diff line change
Expand Up @@ -62,7 +62,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*/
Expand Down Expand Up @@ -175,7 +175,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'
Expand Down Expand Up @@ -1512,6 +1512,28 @@ SELECT
)
);

/*
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
Expand Down