Skip to content
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

Change work_start/work_end params to time(0) DT #344

Closed
wants to merge 1 commit into from
Closed
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
215 changes: 63 additions & 152 deletions sp_QuickieStore/sp_QuickieStore.sql
Original file line number Diff line number Diff line change
Expand Up @@ -82,8 +82,8 @@ ALTER PROCEDURE
@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*/
@workdays bit = 0, /*Use this to filter out weekends and after-hours queries*/
@work_start varchar(4) = '9am', /*Use this to set a specific start of your work days*/
@work_end varchar(4) = '5pm', /*Use this to set a specific end of your work days*/
@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*/
@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*/
Expand Down Expand Up @@ -995,18 +995,6 @@ CREATE TABLE
database_name sysname PRIMARY KEY
);

/*
AM/PM mapping table for workday stuff
*/
CREATE TABLE
#am_pm
(
am_pm varchar(4),
t12 integer,
t24 integer
);


/*
Try to be helpful by subbing in a database name if null
*/
Expand Down Expand Up @@ -1072,8 +1060,8 @@ DECLARE
@utc_minutes_difference bigint,
@utc_minutes_original bigint,
@df integer,
@work_start_int integer,
@work_end_int integer;
@work_start_utc time(0),
@work_end_utc time(0);


/*
Expand Down Expand Up @@ -1206,8 +1194,8 @@ SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;',
@execution_type_desc nvarchar(60),
@database_id int,
@queries_top bigint,
@work_start_int integer,
@work_end_int integer',
@work_start_utc time(0),
@work_end_utc time(0)',
@plans_top =
CASE
WHEN @include_plan_ids IS NULL
Expand Down Expand Up @@ -1409,8 +1397,8 @@ SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;',
SYSDATETIME()
),
@df = @@DATEFIRST,
@work_start_int = 0,
@work_end_int = 0;
@work_start_utc = @work_start,
@work_end_utc = @work_end;

/*
Some parameters can't be NULL,
Expand Down Expand Up @@ -2038,117 +2026,51 @@ END;

IF @workdays = 1
BEGIN
SELECT
@work_start = LOWER(REPLACE(@work_start, ' ', '')),
@work_end = LOWER(REPLACE(@work_end, ' ', ''));

INSERT
#am_pm
(
am_pm,
t12,
t24
)
SELECT
am_pm =
CASE
WHEN y.t24 BETWEEN 1 AND 11
THEN RTRIM(y.t12) + 'am'
WHEN y.t24 = 0
THEN RTRIM(y.t12) + 'am'
ELSE RTRIM(y.t12) + 'pm'
END,
y.t12,
y.t24
FROM
(
SELECT
t12 =
CASE x.t12
WHEN 0
THEN 12
ELSE x.t12
END,
t24 =
CASE
WHEN x.t24 < 24
THEN x.t24
ELSE 0
END
FROM
(
SELECT TOP (24)
t12 =
ROW_NUMBER() OVER
(
ORDER BY
1/0
) % 12,
t24 =
ROW_NUMBER() OVER
(
ORDER BY
1/0
)
FROM sys.messages AS m
) AS x
) AS y
ORDER BY
y.t24;

SELECT
@work_start_int =
(
SELECT
ap.t24
FROM #am_pm AS ap
WHERE ap.am_pm = @work_start
),
@work_end_int =
(
SELECT
ap.t24
FROM #am_pm AS ap
WHERE ap.am_pm = @work_end
);

IF @work_start_int IS NULL
AND @work_end_int IS NULL
IF @work_start_utc IS NULL
AND @work_end_utc IS NULL
BEGIN
SELECT
@work_start_int = 9,
@work_end_int = 17;
@work_start_utc = '09:00',
@work_end_utc = '17:00';
END;
IF @work_start_int IS NOT NULL
AND @work_end_int IS NULL

IF @work_start_utc IS NOT NULL
AND @work_end_utc IS NULL
BEGIN
SELECT
@work_end_int = @work_start_int + 8;
@work_end_utc = DATEADD(
HOUR,
8,
@work_start_utc
);
END;
IF @work_start_int IS NULL
AND @work_end_int IS NOT NULL

IF @work_start_utc IS NULL
AND @work_end_utc IS NOT NULL
BEGIN
SELECT
@work_start_int = @work_end_int - 8;
@work_start_utc = DATEADD(
HOUR,
-8,
@work_end_utc
);
END;

SELECT
@work_start_int +=
DATEDIFF
@work_start_utc =
DATEADD
(
MINUTE,
SYSDATETIME(),
SYSUTCDATETIME()
) / 60,
@work_end_int +=
DATEDIFF
@utc_minutes_difference,
@work_start_utc
),
@work_end_utc =
DATEADD
(
MINUTE,
SYSDATETIME(),
SYSUTCDATETIME()
) / 60;
@utc_minutes_difference,
@work_end_utc
);

IF @df = 1
BEGIN
Expand All @@ -2162,11 +2084,25 @@ BEGIN
@where_clause += N'AND DATEPART(WEEKDAY, qsrs.last_execution_time) BETWEEN 2 AND 6' + @nc10;
END;/*df 7*/

IF @work_start_int IS NOT NULL
AND @work_end_int IS NOT NULL
IF @work_start_utc IS NOT NULL
AND @work_end_utc IS NOT NULL
BEGIN
/*
depending on local TZ, work time might span midnight UTC;
account for that by splitting the interval into before/after midnight. for example:
[09:00 - 17:00] PST
= [17:00 - 01:00] UTC
= [17:00 - 00:00] + [00:00 - 01:00] UTC
*/
IF (@work_start_utc < @work_end_utc)
SELECT
@where_clause += N'AND CAST(qsrs.last_execution_time as time(0)) BETWEEN @work_start_utc AND @work_end_utc' + @nc10;
ELSE
SELECT
@where_clause += N'AND DATEPART(HOUR, qsrs.last_execution_time) BETWEEN @work_start_int AND @work_end_int' + @nc10;
@where_clause += N'AND (' + @nc10 +
' CAST(qsrs.last_execution_time as time(0)) BETWEEN @work_start_utc AND ''00:00'' ' + @nc10 +
' OR CAST(qsrs.last_execution_time as time(0)) BETWEEN ''00:00'' AND @work_end_utc' + @nc10 +
')' + @nc10;
END; /*Work hours*/
END; /*Final end*/

Expand Down Expand Up @@ -3679,8 +3615,8 @@ EXEC sys.sp_executesql
@execution_type_desc,
@database_id,
@queries_top,
@work_start_int,
@work_end_int;
@work_start_utc,
@work_end_utc;

IF @troubleshoot_performance = 1
BEGIN
Expand Down Expand Up @@ -3864,8 +3800,8 @@ EXEC sys.sp_executesql
@execution_type_desc,
@database_id,
@queries_top,
@work_start_int,
@work_end_int;
@work_start_utc,
@work_end_utc;

IF @troubleshoot_performance = 1
BEGIN
Expand Down Expand Up @@ -5207,8 +5143,6 @@ BEGIN
#dm_exec_query_stats;
TRUNCATE TABLE
#query_types;
TRUNCATE TABLE
#am_pm;
END;

FETCH NEXT
Expand Down Expand Up @@ -7698,10 +7632,10 @@ BEGIN
@utc_minutes_original,
df =
@df,
work_start_int =
@work_start_int,
work_end_int =
@work_end_int;
work_start_utc =
@work_start_utc,
work_end_utc =
@work_end_utc;

IF EXISTS
(
Expand Down Expand Up @@ -8440,29 +8374,6 @@ BEGIN
result =
'#troubleshoot_performance is empty';
END;

IF EXISTS
(
SELECT
1/0
FROM #am_pm AS ap
)
BEGIN
SELECT
table_name =
'#am_pm',
ap.*
FROM #am_pm AS ap
ORDER BY
ap.t24
OPTION(RECOMPILE);
END;
ELSE
BEGIN
SELECT
result =
'#troubleshoot_performance is empty';
END;
RETURN; /*Stop doing anything, I guess*/
END; /*End debug*/
RETURN; /*Yeah sure why not?*/
Expand Down
Loading