1
1
IF OBJECT_ID (' dbo.sp_BenchmarkTSQL' , ' P' ) IS NULL
2
2
EXECUTE (' CREATE PROCEDURE dbo.sp_BenchmarkTSQL AS SELECT 1;' );
3
3
GO
4
+
5
+
4
6
ALTER PROCEDURE dbo .sp_BenchmarkTSQL (
5
7
@tsqlStatement NVARCHAR (MAX ) = N ' '
6
8
, @numberOfExecution INT = 10
7
9
, @saveResults BIT = 0
8
10
, @clearCache BIT = 0
9
11
, @calcMedian BIT = 0
12
+ , @printStepInfo BIT = 1
10
13
)
11
14
/*
12
15
.SYNOPSIS
13
16
Calculate SQL statement execution time, save results if need.
14
17
15
18
.DESCRIPTION
16
- Run SQL statement specified times, show results in ms, insert execution details into table [ dbo].[ BenchmarkTSQL] (create if not exist).
19
+ Run SQL statement specified times, show results in ms, insert execution details into table dbo. BenchmarkTSQL (create if not exist).
17
20
18
21
.PARAMETER @tsqlStatement
19
- SQL statement for benchmarking.
22
+ TSQL statement for benchmarking.
20
23
21
24
.PARAMETER @numberOfExecution
22
- Number of execution SQL statement.
25
+ Number of execution TSQL statement.
23
26
24
27
.PARAMETER @saveResults
25
- Save benchmark details to table.
28
+ Save benchmark details to dbo.BenchmarkTSQL table.
26
29
27
30
.PARAMETER @clearCache
28
- Clear cached plan for SQL statement .
31
+ Clear cached plan for TSQL statement.
29
32
30
33
.PARAMETER @calcMedian
31
- Calculate median of execution time.
34
+ Calculate pseudo median of execution time.
35
+
36
+ .PARAMETER @printStepInfo
37
+ PRINT detailed step information: step count, start time, end time, duration
32
38
33
39
.EXAMPLE
34
- [dbo].[sp_BenchmarkTSQL]
35
- @tsqlStatement = 'SELECT * FROM , sys.databases';
40
+ EXEC sp_BenchmarkTSQL @tsqlStatement = 'SELECT * FROM , sys.databases';
36
41
-- RETURN: Incorrect syntax near ','.
37
42
38
43
.EXAMPLE
39
- [dbo].[sp_BenchmarkTSQL]
40
- @tsqlStatement = 'SELECT * FROM sys.databases';
44
+ EXEC sp_BenchmarkTSQL @tsqlStatement = 'SELECT * FROM sys.databases';
45
+
46
+ .EXAMPLE
47
+ EXEC sp_BenchmarkTSQL @tsqlStatement = 'SELECT TOP(10000) * FROM sys.objects AS o1 CROSS JOIN sys.objects AS o2;'
48
+ , @numberOfExecution = 100
49
+ , @calcMedian = 1
50
+ , @clearCache = 1
51
+ , @printStepInfo = 0;
41
52
42
53
.NOTE
43
54
Author: Aleksei Nagorskii
55
+ Created date: 2017-12-14
56
+ Version: 1.0
57
+
58
+ Author: Aleksei Nagorskii
59
+ Modified date: 2017-12-15
60
+ Version: 1.1
61
+
62
+ Author: Konstantin Taranov
63
+ Modified date: 2017-12-16
64
+ Version: 1.2
44
65
*/
45
66
AS
46
67
BEGIN TRY
@@ -63,60 +84,84 @@ BEGIN TRY
63
84
AND error_type_desc IS NOT NULL
64
85
)
65
86
BEGIN
66
- DECLARE @err_msg NVARCHAR (MAX );
87
+ DECLARE @err_msg NVARCHAR (MAX );
88
+
67
89
SELECT @err_msg = [error_message]
68
90
FROM sys .dm_exec_describe_first_result_set (@tsqlStatement, NULL , 0 )
69
91
WHERE column_ordinal = 0 ;
92
+
70
93
THROW 55002 , @err_msg, 1 ;
71
94
END
72
95
73
- DECLARE @crlf VARCHAR (10 ) = CHAR (10 );
74
- DECLARE @cts DATETIME = CURRENT_TIMESTAMP ;
75
- DECLARE @r INT = 0 ;
76
- DECLARE @handle VARBINARY (64 );
77
- DECLARE @min INT ;
78
- DECLARE @avg INT ;
79
- DECLARE @max INT ;
80
- DECLARE @median REAL ;
81
- DECLARE @plan_handle VARBINARY (64 );
82
- DECLARE @rts DATETIME ;
83
- DECLARE @t TABLE (
84
- StartTimeStamp DATETIME2 ,
85
- RunTimeStamp DATETIME2 ,
86
- FinishTimeStamp DATETIME2 ,
87
- TsqlStatement NVARCHAR (MAX ),
88
- ClearCache BIT
96
+ DECLARE @crlf VARCHAR (10 ) = CHAR (10 );
97
+ DECLARE @cts DATETIME = CURRENT_TIMESTAMP ;
98
+ DECLARE @r INT = 0 ;
99
+ DECLARE @handle VARBINARY (64 );
100
+ DECLARE @min INT ;
101
+ DECLARE @avg INT ;
102
+ DECLARE @max INT ;
103
+ DECLARE @median REAL ;
104
+ DECLARE @plan_handle VARBINARY (64 );
105
+ DECLARE @rts DATETIME ;
106
+ DECLARE @t TABLE (
107
+ StartTimeStamp DATETIME2 ,
108
+ RunTimeStamp DATETIME2 ,
109
+ FinishTimeStamp DATETIME2 ,
110
+ TsqlStatement NVARCHAR (MAX ),
111
+ ClearCache BIT
89
112
);
90
113
91
- PRINT (' Benchmark started at ' + CONVERT (VARCHAR (23 ), CURRENT_TIMESTAMP , 121 ))
114
+ PRINT (' Benchmark started at ' + CONVERT (VARCHAR (23 ), CURRENT_TIMESTAMP , 121 ));
115
+
92
116
WHILE @r < @numberOfExecution
93
117
BEGIN
94
118
SET @r = @r + 1 ;
95
119
SET @rts = CURRENT_TIMESTAMP ;
120
+
96
121
IF @clearCache = 1
97
122
BEGIN
98
- SELECT @handle = plan_handle
123
+ SELECT @handle = plan_handle
99
124
FROM sys .dm_exec_cached_plans
100
125
CROSS APPLY sys .dm_exec_sql_text (plan_handle)
101
126
WHERE [text] LIKE @tsqlStatement;
102
- IF @handle IS NOT NULL
103
- DBCC FREEPROCCACHE (@handle);
104
- END
127
+
128
+ IF @handle IS NOT NULL DBCC FREEPROCCACHE (@handle);
129
+ END ;
130
+
105
131
EXECUTE sp_executesql @tsqlStatement;
106
- PRINT (' Run ' + CAST (@r AS VARCHAR (30 )) + ' , start at ' + CONVERT (VARCHAR (23 ), @rts, 121 ) + ' , finish at ' + CONVERT (VARCHAR (23 ), CURRENT_TIMESTAMP , 121 ) + ' , duration: ' + CAST (DATEDIFF (ms, @rts, CURRENT_TIMESTAMP ) AS VARCHAR (MAX )) + ' ms.' );
107
- INSERT @t
108
- VALUES (
109
- @cts,
110
- @rts,
111
- CURRENT_TIMESTAMP ,
112
- @tsqlStatement,
113
- @clearCache
132
+
133
+ IF @printStepInfo = 1
134
+ PRINT (
135
+ ' Run ' + CASE WHEN @r < 10 THEN ' ' + CAST (@r AS VARCHAR (30 ))
136
+ WHEN @r < 100 THEN ' ' + CAST (@r AS VARCHAR (30 ))
137
+ ELSE CAST (@r AS VARCHAR (30 ))
138
+ END +
139
+ ' , start: ' + CONVERT (VARCHAR (23 ), @rts, 121 ) +
140
+ ' , finish: ' + CONVERT (VARCHAR (23 ), CURRENT_TIMESTAMP , 121 ) +
141
+ ' , duration: ' + CAST (DATEDIFF (ms, @rts, CURRENT_TIMESTAMP ) AS VARCHAR (MAX )) + ' ms.'
142
+ );
143
+
144
+ INSERT @t (
145
+ StartTimeStamp
146
+ , RunTimeStamp
147
+ , FinishTimeStamp
148
+ , TsqlStatement
149
+ , ClearCache
150
+ )
151
+ VALUES (
152
+ @cts
153
+ , @rts
154
+ , CURRENT_TIMESTAMP
155
+ , @tsqlStatement
156
+ , @clearCache
114
157
);
115
- END
158
+ END ;
159
+
116
160
SELECT @min = MIN (DATEDIFF (ms, RunTimeStamp, FinishTimeStamp))
117
161
, @avg = AVG (DATEDIFF (ms, RunTimeStamp, FinishTimeStamp))
118
162
, @max = MAX (DATEDIFF (ms, RunTimeStamp, FinishTimeStamp))
119
- FROM @t
163
+ FROM @t;
164
+
120
165
IF @calcMedian = 1
121
166
BEGIN
122
167
SELECT @median = (
@@ -125,17 +170,25 @@ BEGIN TRY
125
170
+
126
171
(SELECT MIN (TMAX) FROM
127
172
(SELECT TOP 50 PERCENT DATEDIFF (ms, RunTimeStamp, FinishTimeStamp) AS TMAX FROM @t ORDER BY TMAX DESC ) AS TopHalf)
128
- ) / 2 .0
129
- PRINT (' Min: ' + CAST (@min AS VARCHAR (30 )) + ' ms, average: ' + CAST (@avg AS VARCHAR (30 )) + ' ms, max: ' + CAST (@max AS VARCHAR (30 )) + ' ms, median: ' + CAST (@median AS VARCHAR (30 )) + ' ms.' + @crlf + ' Benchmark finished at ' + CONVERT (VARCHAR (23 ), CURRENT_TIMESTAMP , 121 ) + ' .' )
130
- END
131
- ELSE
132
- PRINT (' Min: ' + CAST (@min AS VARCHAR (30 )) + ' ms, average: ' + CAST (@avg AS VARCHAR (30 )) + ' ms, max: ' + CAST (@max AS VARCHAR (30 )) + ' ms.' + @crlf + ' Benchmark finished at ' + CONVERT (VARCHAR (23 ), CURRENT_TIMESTAMP , 121 ) + ' .' )
173
+ ) / 2 .0 ;
174
+ END ;
175
+
176
+ PRINT (
177
+ ' Min: ' + CAST (@min AS VARCHAR (30 )) +
178
+ ' ms, Max: ' + CAST (@max AS VARCHAR (30 )) +
179
+ ' ms, Average: ' + CAST (@avg AS VARCHAR (30 )) +
180
+ CASE WHEN @calcMedian = 1 THEN ' ms, Median: ' + CAST (@median AS VARCHAR (30 )) ELSE ' ' END +
181
+ ' ms.' + @crlf +
182
+ ' Benchmark finished at ' + CONVERT (VARCHAR (23 ), CURRENT_TIMESTAMP , 121 ) + ' .'
183
+ );
184
+
185
+
133
186
IF @saveResults = 1
134
187
IF OBJECT_ID (' .[dbo].[BenchmarkTSQL]' , ' U' ) IS NULL
135
- SELECT * INTO [ dbo].[ BenchmarkTSQL] FROM @t
188
+ SELECT * INTO dbo . BenchmarkTSQL FROM @t
136
189
ELSE
137
- INSERT INTO [ dbo].[ BenchmarkTSQL] SELECT * FROM @t;
138
-
190
+ INSERT INTO dbo . BenchmarkTSQL SELECT * FROM @t;
191
+
139
192
SET NOCOUNT ON ;
140
193
END TRY
141
194
0 commit comments