@@ -82,8 +82,8 @@ ALTER PROCEDURE
82
82
@format_output bit = 1 , /* returns numbers formatted with commas*/
83
83
@get_all_databases bit = 0 , /* looks for query store enabled databases and returns combined results from all of them*/
84
84
@workdays bit = 0 , /* Use this to filter out weekends and after-hours queries*/
85
- @work_start varchar ( 4 ) = ' 9am' , /* Use this to set a specific start of your work days*/
86
- @work_end varchar ( 4 ) = ' 5pm' , /* Use this to set a specific end of your work days*/
85
+ @work_start time ( 0 ) = ' 9am' , /* Use this to set a specific start of your work days*/
86
+ @work_end time ( 0 ) = ' 5pm' , /* Use this to set a specific end of your work days*/
87
87
@help bit = 0 , /* return available parameter details, etc.*/
88
88
@debug bit = 0 , /* prints dynamic sql, statement length, parameter and variable values, and raw temp table contents*/
89
89
@troubleshoot_performance bit = 0 , /* set statistics xml on for queries against views*/
@@ -995,18 +995,6 @@ CREATE TABLE
995
995
database_name sysname PRIMARY KEY
996
996
);
997
997
998
- /*
999
- AM/PM mapping table for workday stuff
1000
- */
1001
- CREATE TABLE
1002
- #am_pm
1003
- (
1004
- am_pm varchar (4 ),
1005
- t12 integer ,
1006
- t24 integer
1007
- );
1008
-
1009
-
1010
998
/*
1011
999
Try to be helpful by subbing in a database name if null
1012
1000
*/
@@ -1072,8 +1060,8 @@ DECLARE
1072
1060
@utc_minutes_difference bigint ,
1073
1061
@utc_minutes_original bigint ,
1074
1062
@df integer ,
1075
- @work_start_int integer ,
1076
- @work_end_int integer ;
1063
+ @work_start_utc time ( 0 ) ,
1064
+ @work_end_utc time ( 0 ) ;
1077
1065
1078
1066
1079
1067
/*
@@ -1206,8 +1194,8 @@ SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;',
1206
1194
@execution_type_desc nvarchar(60),
1207
1195
@database_id int,
1208
1196
@queries_top bigint,
1209
- @work_start_int integer ,
1210
- @work_end_int integer ' ,
1197
+ @work_start_utc time(0) ,
1198
+ @work_end_utc time(0) ' ,
1211
1199
@plans_top =
1212
1200
CASE
1213
1201
WHEN @include_plan_ids IS NULL
@@ -1409,8 +1397,8 @@ SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;',
1409
1397
SYSDATETIME ()
1410
1398
),
1411
1399
@df = @@DATEFIRST ,
1412
- @work_start_int = 0 ,
1413
- @work_end_int = 0 ;
1400
+ @work_start_utc = @work_start ,
1401
+ @work_end_utc = @work_end ;
1414
1402
1415
1403
/*
1416
1404
Some parameters can't be NULL,
@@ -2038,135 +2026,94 @@ END;
2038
2026
2039
2027
IF @workdays = 1
2040
2028
BEGIN
2041
- SELECT
2042
- @work_start = LOWER (REPLACE (@work_start, ' ' , ' ' )),
2043
- @work_end = LOWER (REPLACE (@work_end, ' ' , ' ' ));
2044
-
2045
- INSERT
2046
- #am_pm
2047
- (
2048
- am_pm,
2049
- t12,
2050
- t24
2051
- )
2052
- SELECT
2053
- am_pm =
2054
- CASE
2055
- WHEN y .t24 BETWEEN 1 AND 11
2056
- THEN RTRIM (y .t12 ) + ' am'
2057
- WHEN y .t24 = 0
2058
- THEN RTRIM (y .t12 ) + ' am'
2059
- ELSE RTRIM (y .t12 ) + ' pm'
2060
- END ,
2061
- y .t12 ,
2062
- y .t24
2063
- FROM
2064
- (
2065
- SELECT
2066
- t12 =
2067
- CASE x .t12
2068
- WHEN 0
2069
- THEN 12
2070
- ELSE x .t12
2071
- END ,
2072
- t24 =
2073
- CASE
2074
- WHEN x .t24 < 24
2075
- THEN x .t24
2076
- ELSE 0
2077
- END
2078
- FROM
2079
- (
2080
- SELECT TOP (24 )
2081
- t12 =
2082
- ROW_NUMBER () OVER
2083
- (
2084
- ORDER BY
2085
- 1 / 0
2086
- ) % 12 ,
2087
- t24 =
2088
- ROW_NUMBER () OVER
2089
- (
2090
- ORDER BY
2091
- 1 / 0
2092
- )
2093
- FROM sys .messages AS m
2094
- ) AS x
2095
- ) AS y
2096
- ORDER BY
2097
- y .t24 ;
2098
-
2099
- SELECT
2100
- @work_start_int =
2101
- (
2102
- SELECT
2103
- ap .t24
2104
- FROM #am_pm AS ap
2105
- WHERE ap .am_pm = @work_start
2106
- ),
2107
- @work_end_int =
2108
- (
2109
- SELECT
2110
- ap .t24
2111
- FROM #am_pm AS ap
2112
- WHERE ap .am_pm = @work_end
2113
- );
2114
-
2115
- IF @work_start_int IS NULL
2116
- AND @work_end_int IS NULL
2029
+ IF @work_start_utc IS NULL
2030
+ AND @work_end_utc IS NULL
2117
2031
BEGIN
2118
2032
SELECT
2119
- @work_start_int = 9 ,
2120
- @work_end_int = 17 ;
2033
+ @work_start_utc = ' 09:00' ,
2034
+ @work_end_utc = ' 17:00' ;
2121
2035
END ;
2122
-
2123
- IF @work_start_int IS NOT NULL
2124
- AND @work_end_int IS NULL
2036
+
2037
+ IF @work_start_utc IS NOT NULL
2038
+ AND @work_end_utc IS NULL
2125
2039
BEGIN
2126
2040
SELECT
2127
- @work_end_int = @work_start_int + 8 ;
2041
+ @work_end_utc =
2042
+ DATEADD
2043
+ (
2044
+ HOUR,
2045
+ 8 ,
2046
+ @work_start_utc
2047
+ );
2128
2048
END ;
2129
-
2130
- IF @work_start_int IS NULL
2131
- AND @work_end_int IS NOT NULL
2049
+
2050
+ IF @work_start_utc IS NULL
2051
+ AND @work_end_utc IS NOT NULL
2132
2052
BEGIN
2133
2053
SELECT
2134
- @work_start_int = @work_end_int - 8 ;
2054
+ @work_start_utc =
2055
+ DATEADD
2056
+ (
2057
+ HOUR,
2058
+ - 8 ,
2059
+ @work_end_utc
2060
+ );
2135
2061
END ;
2136
2062
2137
2063
SELECT
2138
- @work_start_int + =
2139
- DATEDIFF
2064
+ @work_start_utc =
2065
+ DATEADD
2140
2066
(
2141
2067
MINUTE,
2142
- SYSDATETIME () ,
2143
- SYSUTCDATETIME ()
2144
- ) / 60 ,
2145
- @work_end_int + =
2146
- DATEDIFF
2068
+ @utc_minutes_difference ,
2069
+ @work_start_utc
2070
+ ),
2071
+ @work_end_utc =
2072
+ DATEADD
2147
2073
(
2148
2074
MINUTE,
2149
- SYSDATETIME () ,
2150
- SYSUTCDATETIME ()
2151
- ) / 60 ;
2075
+ @utc_minutes_difference ,
2076
+ @work_end_utc
2077
+ );
2152
2078
2153
2079
IF @df = 1
2154
2080
BEGIN
2155
- SELECT
2156
- @where_clause + = N ' AND DATEPART(WEEKDAY, qsrs.last_execution_time) BETWEEN 1 AND 6' + @nc10;
2081
+ SELECT
2082
+ @where_clause + = N ' AND DATEPART(WEEKDAY, qsrs.last_execution_time) BETWEEN 1 AND 6' + @nc10;
2157
2083
END ;/* df 1*/
2158
2084
2159
2085
IF @df = 7
2160
2086
BEGIN
2161
- SELECT
2162
- @where_clause + = N ' AND DATEPART(WEEKDAY, qsrs.last_execution_time) BETWEEN 2 AND 6' + @nc10;
2087
+ SELECT
2088
+ @where_clause + = N ' AND DATEPART(WEEKDAY, qsrs.last_execution_time) BETWEEN 2 AND 6' + @nc10;
2163
2089
END ;/* df 7*/
2164
2090
2165
- IF @work_start_int IS NOT NULL
2166
- AND @work_end_int IS NOT NULL
2091
+ IF @work_start_utc IS NOT NULL
2092
+ AND @work_end_utc IS NOT NULL
2167
2093
BEGIN
2094
+ /*
2095
+ depending on local TZ, work time might span midnight UTC;
2096
+ account for that by splitting the interval into before/after midnight.
2097
+ for example:
2098
+ [09:00 - 17:00] PST
2099
+ = [17:00 - 01:00] UTC
2100
+ = [17:00 - 00:00) + [00:00 - 01:00] UTC
2101
+
2102
+ NB: because we don't have the benefit of the context of what day midnight
2103
+ is occurring on, we have to rely on the behavior from the documentation of
2104
+ the time DT of higher to lower precision resulting in truncation to split
2105
+ the interval. i.e. 23:59:59.9999999 -> 23:59:59. which should make that
2106
+ value safe to use as the endpoint for our "before midnight" interval.
2107
+ */
2108
+ IF (@work_start_utc < @work_end_utc)
2109
+ SELECT
2110
+ @where_clause + = N ' AND CAST(qsrs.last_execution_time as time(0)) BETWEEN @work_start_utc AND @work_end_utc' + @nc10;
2111
+ ELSE
2168
2112
SELECT
2169
- @where_clause + = N ' AND DATEPART(HOUR, qsrs.last_execution_time) BETWEEN @work_start_int AND @work_end_int' + @nc10;
2113
+ @where_clause + = N ' AND (' + @nc10 +
2114
+ ' CAST(qsrs.last_execution_time as time(0)) BETWEEN @work_start_utc AND '' 23:59:59'' ' + @nc10 +
2115
+ ' OR CAST(qsrs.last_execution_time as time(0)) BETWEEN '' 00:00:00'' AND @work_end_utc' + @nc10 +
2116
+ ' )' + @nc10;
2170
2117
END ; /* Work hours*/
2171
2118
END ; /* Final end*/
2172
2119
@@ -3679,8 +3626,8 @@ EXEC sys.sp_executesql
3679
3626
@execution_type_desc,
3680
3627
@database_id,
3681
3628
@queries_top,
3682
- @work_start_int ,
3683
- @work_end_int ;
3629
+ @work_start_utc ,
3630
+ @work_end_utc ;
3684
3631
3685
3632
IF @troubleshoot_performance = 1
3686
3633
BEGIN
@@ -3864,8 +3811,8 @@ EXEC sys.sp_executesql
3864
3811
@execution_type_desc,
3865
3812
@database_id,
3866
3813
@queries_top,
3867
- @work_start_int ,
3868
- @work_end_int ;
3814
+ @work_start_utc ,
3815
+ @work_end_utc ;
3869
3816
3870
3817
IF @troubleshoot_performance = 1
3871
3818
BEGIN
@@ -5207,8 +5154,6 @@ BEGIN
5207
5154
#dm_exec_query_stats;
5208
5155
TRUNCATE TABLE
5209
5156
#query_types;
5210
- TRUNCATE TABLE
5211
- #am_pm;
5212
5157
END ;
5213
5158
5214
5159
FETCH NEXT
@@ -7698,10 +7643,10 @@ BEGIN
7698
7643
@utc_minutes_original,
7699
7644
df =
7700
7645
@df,
7701
- work_start_int =
7702
- @work_start_int ,
7703
- work_end_int =
7704
- @work_end_int ;
7646
+ work_start_utc =
7647
+ @work_start_utc ,
7648
+ work_end_utc =
7649
+ @work_end_utc ;
7705
7650
7706
7651
IF EXISTS
7707
7652
(
@@ -8440,29 +8385,6 @@ BEGIN
8440
8385
result =
8441
8386
' #troubleshoot_performance is empty' ;
8442
8387
END ;
8443
-
8444
- IF EXISTS
8445
- (
8446
- SELECT
8447
- 1 / 0
8448
- FROM #am_pm AS ap
8449
- )
8450
- BEGIN
8451
- SELECT
8452
- table_name =
8453
- ' #am_pm' ,
8454
- ap.*
8455
- FROM #am_pm AS ap
8456
- ORDER BY
8457
- ap .t24
8458
- OPTION (RECOMPILE );
8459
- END ;
8460
- ELSE
8461
- BEGIN
8462
- SELECT
8463
- result =
8464
- ' #troubleshoot_performance is empty' ;
8465
- END ;
8466
8388
RETURN ; /* Stop doing anything, I guess*/
8467
8389
END ; /* End debug*/
8468
8390
RETURN ; /* Yeah sure why not?*/
0 commit comments