forked from BrentOzarULTD/SQL-Server-First-Responder-Kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
sp_BlitzWho.sql
517 lines (484 loc) · 23.7 KB
/
sp_BlitzWho.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
IF OBJECT_ID('dbo.sp_BlitzWho') IS NULL
EXEC ('CREATE PROCEDURE dbo.sp_BlitzWho AS RETURN 0;')
GO
ALTER PROCEDURE dbo.sp_BlitzWho
@Help TINYINT = 0 ,
@ShowSleepingSPIDs TINYINT = 0,
@Debug BIT = 0,
@VersionDate DATETIME = NULL OUTPUT
AS
BEGIN
SET NOCOUNT ON;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
DECLARE @Version VARCHAR(30);
SET @Version = '5.5';
SET @VersionDate = '20170701';
IF @Help = 1
PRINT '
sp_BlitzWho from http://FirstResponderKit.org
This script gives you a snapshot of everything currently executing on your SQL Server.
To learn more, visit http://FirstResponderKit.org where you can download new
versions for free, watch training videos on how it works, get more info on
the findings, contribute your own code, and more.
Known limitations of this version:
- Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000.
MIT License
Copyright (c) 2017 Brent Ozar Unlimited
Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software without restriction, including without limitation the rights
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:
The above copyright notice and this permission notice shall be included in all
copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.
';
/* Get the major and minor build numbers */
DECLARE @ProductVersion NVARCHAR(128)
,@ProductVersionMajor DECIMAL(10,2)
,@ProductVersionMinor DECIMAL(10,2)
,@EnhanceFlag BIT = 0
,@StringToExecute NVARCHAR(MAX)
,@EnhanceSQL NVARCHAR(MAX) =
N'query_stats.last_dop,
query_stats.min_dop,
query_stats.max_dop,
query_stats.last_grant_kb,
query_stats.min_grant_kb,
query_stats.max_grant_kb,
query_stats.last_used_grant_kb,
query_stats.min_used_grant_kb,
query_stats.max_used_grant_kb,
query_stats.last_ideal_grant_kb,
query_stats.min_ideal_grant_kb,
query_stats.max_ideal_grant_kb,
query_stats.last_reserved_threads,
query_stats.min_reserved_threads,
query_stats.max_reserved_threads,
query_stats.last_used_threads,
query_stats.min_used_threads,
query_stats.max_used_threads,'
,@SessionWaits BIT = 0
,@SessionWaitsSQL NVARCHAR(MAX) =
N'LEFT JOIN ( SELECT DISTINCT
wait.session_id ,
( SELECT TOP 5 waitwait.wait_type + N'' (''
+ CAST(SUM(waitwait.wait_time_ms) AS NVARCHAR(128))
+ N'' ms), ''
FROM sys.dm_exec_session_wait_stats AS waitwait
WHERE waitwait.session_id = wait.session_id
GROUP BY waitwait.wait_type
HAVING SUM(waitwait.wait_time_ms) > 5
ORDER BY SUM(waitwait.wait_time_ms) DESC
FOR
XML PATH('''') ) AS session_wait_info
FROM sys.dm_exec_session_wait_stats AS wait ) AS wt2
ON s.session_id = wt2.session_id
LEFT JOIN sys.dm_exec_query_stats AS session_stats
ON r.sql_handle = session_stats.sql_handle
AND r.plan_handle = session_stats.plan_handle
AND r.statement_start_offset = session_stats.statement_start_offset
AND r.statement_end_offset = session_stats.statement_end_offset'
SET @ProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128));
SELECT @ProductVersionMajor = SUBSTRING(@ProductVersion, 1,CHARINDEX('.', @ProductVersion) + 1 ),
@ProductVersionMinor = PARSENAME(CONVERT(VARCHAR(32), @ProductVersion), 2)
IF @ProductVersionMajor > 9 and @ProductVersionMajor < 11
BEGIN
SET @StringToExecute = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
DECLARE @blocked TABLE
(
dbid SMALLINT NOT NULL,
last_batch DATETIME NOT NULL,
open_tran SMALLINT NOT NULL,
sql_handle BINARY(20) NOT NULL,
session_id SMALLINT NOT NULL,
blocking_session_id SMALLINT NOT NULL,
lastwaittype NCHAR(32) NOT NULL,
waittime BIGINT NOT NULL,
cpu INT NOT NULL,
physical_io BIGINT NOT NULL,
memusage INT NOT NULL
);
INSERT @blocked ( dbid, last_batch, open_tran, sql_handle, session_id, blocking_session_id, lastwaittype, waittime, cpu, physical_io, memusage )
SELECT
sys1.dbid, sys1.last_batch, sys1.open_tran, sys1.sql_handle,
sys2.spid AS session_id, sys2.blocked AS blocking_session_id, sys2.lastwaittype, sys2.waittime, sys2.cpu, sys2.physical_io, sys2.memusage
FROM sys.sysprocesses AS sys1
JOIN sys.sysprocesses AS sys2
ON sys1.spid = sys2.blocked;
SELECT GETDATE() AS run_date ,
COALESCE(
CONVERT(VARCHAR(20), (r.total_elapsed_time / 1000) / 86400) + '':'' + CONVERT(VARCHAR(20), DATEADD(s, (r.total_elapsed_time / 1000), 0), 114) ,
CONVERT(VARCHAR(20), DATEDIFF(SECOND, s.last_request_start_time, GETDATE()) / 86400) + '':''
+ CONVERT(VARCHAR(20), DATEADD(SECOND, DATEDIFF(SECOND, s.last_request_start_time, GETDATE()), 0), 114)
) AS [elapsed_time] ,
s.session_id ,
COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name,
COALESCE(wt.wait_info, RTRIM(blocked.lastwaittype) + '' ('' + CONVERT(VARCHAR(10), blocked.waittime) + '')'' ) AS wait_info ,
s.status ,
ISNULL(SUBSTRING(dest.text,
( query_stats.statement_start_offset / 2 ) + 1,
( ( CASE query_stats.statement_end_offset
WHEN -1 THEN DATALENGTH(dest.text)
ELSE query_stats.statement_end_offset
END - query_stats.statement_start_offset )
/ 2 ) + 1), dest.text) AS query_text ,
derp.query_plan ,
qmg.query_cost ,
CASE WHEN r.blocking_session_id <> 0 AND blocked.session_id IS NULL THEN r.blocking_session_id
WHEN r.blocking_session_id <> 0 AND s.session_id <> blocked.blocking_session_id THEN blocked.blocking_session_id
ELSE NULL END
AS blocking_session_id,
COALESCE(r.cpu_time, s.cpu_time) AS request_cpu_time,
COALESCE(r.logical_reads, s.logical_reads) AS request_logical_reads,
COALESCE(r.writes, s.writes) AS request_writes,
COALESCE(r.reads, s.reads) AS request_physical_reads ,
s.cpu_time AS session_cpu,
tempdb_allocations.tempdb_allocations_mb,
s.logical_reads AS session_logical_reads,
s.reads AS session_physical_reads ,
s.writes AS session_writes,
s.memory_usage ,
r.estimated_completion_time ,
r.deadlock_priority ,
CASE
WHEN s.transaction_isolation_level = 0 THEN ''Unspecified''
WHEN s.transaction_isolation_level = 1 THEN ''Read Uncommitted''
WHEN s.transaction_isolation_level = 2 AND EXISTS (SELECT 1 FROM sys.dm_tran_active_snapshot_database_transactions AS trn WHERE s.session_id = trn.session_id AND is_snapshot = 0 ) THEN ''Read Committed Snapshot Isolation''
WHEN s.transaction_isolation_level = 2 AND NOT EXISTS (SELECT 1 FROM sys.dm_tran_active_snapshot_database_transactions AS trn WHERE s.session_id = trn.session_id AND is_snapshot = 0 ) THEN ''Read Committed''
WHEN s.transaction_isolation_level = 3 THEN ''Repeatable Read''
WHEN s.transaction_isolation_level = 4 THEN ''Serializable''
WHEN s.transaction_isolation_level = 5 THEN ''Snapshot''
ELSE ''WHAT HAVE YOU DONE?''
END AS transaction_isolation_level ,
COALESCE(r.open_transaction_count, blocked.open_tran) AS open_transaction_count ,
qmg.dop AS degree_of_parallelism ,
qmg.request_time ,
COALESCE(CAST(qmg.grant_time AS VARCHAR), ''N/A'') AS grant_time ,
qmg.requested_memory_kb ,
qmg.granted_memory_kb AS grant_memory_kb,
CASE WHEN qmg.grant_time IS NULL THEN ''N/A''
WHEN qmg.requested_memory_kb < qmg.granted_memory_kb
THEN ''Query Granted Less Than Query Requested''
ELSE ''Memory Request Granted''
END AS is_request_granted ,
qmg.required_memory_kb ,
qmg.used_memory_kb ,
qmg.ideal_memory_kb ,
qmg.is_small ,
qmg.timeout_sec ,
qmg.resource_semaphore_id ,
COALESCE(CAST(qmg.wait_order AS VARCHAR), ''N/A'') AS wait_order ,
COALESCE(CAST(qmg.wait_time_ms AS VARCHAR),
''N/A'') AS wait_time_ms ,
CASE qmg.is_next_candidate
WHEN 0 THEN ''No''
WHEN 1 THEN ''Yes''
ELSE ''N/A''
END AS next_candidate_for_memory_grant ,
qrs.target_memory_kb ,
COALESCE(CAST(qrs.max_target_memory_kb AS VARCHAR),
''Small Query Resource Semaphore'') AS max_target_memory_kb ,
qrs.total_memory_kb ,
qrs.available_memory_kb ,
qrs.granted_memory_kb ,
qrs.used_memory_kb ,
qrs.grantee_count ,
qrs.waiter_count ,
qrs.timeout_error_count ,
COALESCE(CAST(qrs.forced_grant_count AS VARCHAR),
''Small Query Resource Semaphore'') AS forced_grant_count,
s.nt_domain ,
s.host_name ,
s.login_name ,
s.nt_user_name ,
s.program_name ,
s.client_interface_name ,
s.login_time ,
r.start_time ,
wg.name AS workload_group_name,
rp.name AS resource_pool_name
FROM sys.dm_exec_sessions AS s
LEFT JOIN sys.dm_exec_requests AS r
ON r.session_id = s.session_id
LEFT JOIN ( SELECT DISTINCT
wait.session_id ,
( SELECT waitwait.wait_type + N'' (''
+ CAST(SUM(waitwait.wait_duration_ms) AS NVARCHAR(128))
+ N'' ms) ''
FROM sys.dm_os_waiting_tasks AS waitwait
WHERE waitwait.session_id = wait.session_id
GROUP BY waitwait.wait_type
ORDER BY SUM(waitwait.wait_duration_ms) DESC
FOR
XML PATH('''') ) AS wait_info
FROM sys.dm_os_waiting_tasks AS wait ) AS wt
ON s.session_id = wt.session_id
LEFT JOIN sys.dm_exec_query_stats AS query_stats
ON r.sql_handle = query_stats.sql_handle
AND r.plan_handle = query_stats.plan_handle
AND r.statement_start_offset = query_stats.statement_start_offset
AND r.statement_end_offset = query_stats.statement_end_offset
LEFT JOIN sys.dm_exec_query_memory_grants qmg
ON r.session_id = qmg.session_id
AND r.request_id = qmg.request_id
LEFT JOIN sys.dm_exec_query_resource_semaphores qrs
ON qmg.resource_semaphore_id = qrs.resource_semaphore_id
AND qmg.pool_id = qrs.pool_id
LEFT JOIN sys.dm_db_task_space_usage tsu
ON tsu.request_id = r.request_id
AND tsu.session_id = r.session_id
AND tsu.session_id = s.session_id
LEFT JOIN sys.resource_governor_workload_groups wg
ON s.group_id = wg.group_id
LEFT JOIN sys.resource_governor_resource_pools rp
ON wg.pool_id = rp.pool_id
OUTER APPLY (
SELECT TOP 1
b.dbid, b.last_batch, b.open_tran, b.sql_handle,
b.session_id, b.blocking_session_id, b.lastwaittype, b.waittime
FROM @blocked b
WHERE (s.session_id = b.session_id
OR s.session_id = b.blocking_session_id)
) AS blocked
OUTER APPLY sys.dm_exec_sql_text(COALESCE(r.sql_handle, blocked.sql_handle)) AS dest
OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS derp
OUTER APPLY (
SELECT CONVERT(DECIMAL(38,2), SUM( ((tsu.user_objects_alloc_page_count * 8) / 1024.) ) ) AS tempdb_allocations_mb
FROM sys.dm_db_task_space_usage tsu
WHERE tsu.request_id = r.request_id
AND tsu.session_id = r.session_id
AND tsu.session_id = s.session_id
) as tempdb_allocations
WHERE s.session_id <> @@SPID
AND s.host_name IS NOT NULL
'
+ CASE WHEN @ShowSleepingSPIDs = 0 THEN
N' AND COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid)) IS NOT NULL'
WHEN @ShowSleepingSPIDs = 1 THEN
N' OR COALESCE(r.open_transaction_count, blocked.open_tran) >= 1'
ELSE N'' END
+
' ORDER BY 2 DESC;
'
END
IF @ProductVersionMajor >= 11
BEGIN
SELECT @EnhanceFlag =
CASE WHEN @ProductVersionMajor = 11 AND @ProductVersionMinor >= 6020 THEN 1
WHEN @ProductVersionMajor = 12 AND @ProductVersionMinor >= 5000 THEN 1
WHEN @ProductVersionMajor = 13 AND @ProductVersionMinor >= 1601 THEN 1
ELSE 0
END
IF OBJECT_ID('sys.dm_exec_session_wait_stats') IS NOT NULL
BEGIN
SET @SessionWaits = 1
END
SELECT @StringToExecute = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
DECLARE @blocked TABLE
(
dbid SMALLINT NOT NULL,
last_batch DATETIME NOT NULL,
open_tran SMALLINT NOT NULL,
sql_handle BINARY(20) NOT NULL,
session_id SMALLINT NOT NULL,
blocking_session_id SMALLINT NOT NULL,
lastwaittype NCHAR(32) NOT NULL,
waittime BIGINT NOT NULL,
cpu INT NOT NULL,
physical_io BIGINT NOT NULL,
memusage INT NOT NULL
);
INSERT @blocked ( dbid, last_batch, open_tran, sql_handle, session_id, blocking_session_id, lastwaittype, waittime, cpu, physical_io, memusage )
SELECT
sys1.dbid, sys1.last_batch, sys1.open_tran, sys1.sql_handle,
sys2.spid AS session_id, sys2.blocked AS blocking_session_id, sys2.lastwaittype, sys2.waittime, sys2.cpu, sys2.physical_io, sys2.memusage
FROM sys.sysprocesses AS sys1
JOIN sys.sysprocesses AS sys2
ON sys1.spid = sys2.blocked;
SELECT GETDATE() AS run_date ,
COALESCE(
CONVERT(VARCHAR(20), (r.total_elapsed_time / 1000) / 86400) + '':'' + CONVERT(VARCHAR(20), DATEADD(s, (r.total_elapsed_time / 1000), 0), 114) ,
CONVERT(VARCHAR(20), DATEDIFF(SECOND, s.last_request_start_time, GETDATE()) / 86400) + '':''
+ CONVERT(VARCHAR(20), DATEADD(SECOND, DATEDIFF(SECOND, s.last_request_start_time, GETDATE()), 0), 114)
) AS [elapsed_time] ,
s.session_id ,
COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name,
COALESCE(wt.wait_info, RTRIM(blocked.lastwaittype) + '' ('' + CONVERT(VARCHAR(10), blocked.waittime) + '')'' ) AS wait_info ,
'+
CASE @SessionWaits
WHEN 1 THEN + N'SUBSTRING(wt2.session_wait_info, 0, LEN(wt2.session_wait_info) -1) AS top_session_waits ,'
ELSE N''
END
+'
s.status ,
ISNULL(SUBSTRING(dest.text,
( query_stats.statement_start_offset / 2 ) + 1,
( ( CASE query_stats.statement_end_offset
WHEN -1 THEN DATALENGTH(dest.text)
ELSE query_stats.statement_end_offset
END - query_stats.statement_start_offset )
/ 2 ) + 1), dest.text) AS query_text ,
derp.query_plan ,
qmg.query_cost ,
CASE WHEN r.blocking_session_id <> 0 AND blocked.session_id IS NULL THEN r.blocking_session_id
WHEN r.blocking_session_id <> 0 AND s.session_id <> blocked.blocking_session_id THEN blocked.blocking_session_id
ELSE NULL END
AS blocking_session_id,
COALESCE(r.cpu_time, s.cpu_time) AS request_cpu_time,
COALESCE(r.logical_reads, s.logical_reads) AS request_logical_reads,
COALESCE(r.writes, s.writes) AS request_writes,
COALESCE(r.reads, s.reads) AS request_physical_reads ,
s.cpu_time AS session_cpu,
tempdb_allocations.tempdb_allocations_mb,
s.logical_reads AS session_logical_reads,
s.reads AS session_physical_reads ,
s.writes AS session_writes,
s.memory_usage ,
r.estimated_completion_time ,
r.deadlock_priority ,'
+
CASE @EnhanceFlag
WHEN 1 THEN @EnhanceSQL
ELSE N''
END
+
N'CASE
WHEN s.transaction_isolation_level = 0 THEN ''Unspecified''
WHEN s.transaction_isolation_level = 1 THEN ''Read Uncommitted''
WHEN s.transaction_isolation_level = 2 AND EXISTS (SELECT 1 FROM sys.dm_tran_active_snapshot_database_transactions AS trn WHERE s.session_id = trn.session_id AND is_snapshot = 0 ) THEN ''Read Committed Snapshot Isolation''
WHEN s.transaction_isolation_level = 2 AND NOT EXISTS (SELECT 1 FROM sys.dm_tran_active_snapshot_database_transactions AS trn WHERE s.session_id = trn.session_id AND is_snapshot = 0 ) THEN ''Read Committed''
WHEN s.transaction_isolation_level = 3 THEN ''Repeatable Read''
WHEN s.transaction_isolation_level = 4 THEN ''Serializable''
WHEN s.transaction_isolation_level = 5 THEN ''Snapshot''
ELSE ''WHAT HAVE YOU DONE?''
END AS transaction_isolation_level ,
COALESCE(r.open_transaction_count, blocked.open_tran) AS open_transaction_count ,
qmg.dop AS degree_of_parallelism ,
qmg.request_time ,
COALESCE(CAST(qmg.grant_time AS VARCHAR), ''Memory Not Granted'') AS grant_time ,
qmg.requested_memory_kb ,
qmg.granted_memory_kb AS grant_memory_kb,
CASE WHEN qmg.grant_time IS NULL THEN ''N/A''
WHEN qmg.requested_memory_kb < qmg.granted_memory_kb
THEN ''Query Granted Less Than Query Requested''
ELSE ''Memory Request Granted''
END AS is_request_granted ,
qmg.required_memory_kb ,
qmg.used_memory_kb ,
qmg.ideal_memory_kb ,
qmg.is_small ,
qmg.timeout_sec ,
qmg.resource_semaphore_id ,
COALESCE(CAST(qmg.wait_order AS VARCHAR), ''N/A'') AS wait_order ,
COALESCE(CAST(qmg.wait_time_ms AS VARCHAR),
''N/A'') AS wait_time_ms ,
CASE qmg.is_next_candidate
WHEN 0 THEN ''No''
WHEN 1 THEN ''Yes''
ELSE ''N/A''
END AS next_candidate_for_memory_grant ,
qrs.target_memory_kb ,
COALESCE(CAST(qrs.max_target_memory_kb AS VARCHAR),
''Small Query Resource Semaphore'') AS max_target_memory_kb ,
qrs.total_memory_kb ,
qrs.available_memory_kb ,
qrs.granted_memory_kb ,
qrs.used_memory_kb ,
qrs.grantee_count ,
qrs.waiter_count ,
qrs.timeout_error_count ,
COALESCE(CAST(qrs.forced_grant_count AS VARCHAR),
''Small Query Resource Semaphore'') AS forced_grant_count,
s.nt_domain ,
s.host_name ,
s.login_name ,
s.nt_user_name ,
s.program_name ,
s.client_interface_name ,
s.login_time ,
r.start_time ,
wg.name AS workload_group_name,
rp.name AS resource_pool_name
FROM sys.dm_exec_sessions AS s
LEFT JOIN sys.dm_exec_requests AS r
ON r.session_id = s.session_id
LEFT JOIN ( SELECT DISTINCT
wait.session_id ,
( SELECT waitwait.wait_type + N'' (''
+ CAST(SUM(waitwait.wait_duration_ms) AS NVARCHAR(128))
+ N'' ms) ''
FROM sys.dm_os_waiting_tasks AS waitwait
WHERE waitwait.session_id = wait.session_id
GROUP BY waitwait.wait_type
ORDER BY SUM(waitwait.wait_duration_ms) DESC
FOR
XML PATH('''') ) AS wait_info
FROM sys.dm_os_waiting_tasks AS wait ) AS wt
ON s.session_id = wt.session_id
LEFT JOIN sys.dm_exec_query_stats AS query_stats
ON r.sql_handle = query_stats.sql_handle
AND r.plan_handle = query_stats.plan_handle
AND r.statement_start_offset = query_stats.statement_start_offset
AND r.statement_end_offset = query_stats.statement_end_offset
'
+
CASE @SessionWaits
WHEN 1 THEN @SessionWaitsSQL
ELSE N''
END
+
'
LEFT JOIN sys.dm_exec_query_memory_grants qmg
ON r.session_id = qmg.session_id
AND r.request_id = qmg.request_id
LEFT JOIN sys.dm_exec_query_resource_semaphores qrs
ON qmg.resource_semaphore_id = qrs.resource_semaphore_id
AND qmg.pool_id = qrs.pool_id
LEFT JOIN sys.resource_governor_workload_groups wg
ON s.group_id = wg.group_id
LEFT JOIN sys.resource_governor_resource_pools rp
ON wg.pool_id = rp.pool_id
OUTER APPLY (
SELECT TOP 1
b.dbid, b.last_batch, b.open_tran, b.sql_handle,
b.session_id, b.blocking_session_id, b.lastwaittype, b.waittime
FROM @blocked b
WHERE (s.session_id = b.session_id
OR s.session_id = b.blocking_session_id)
) AS blocked
OUTER APPLY sys.dm_exec_sql_text(COALESCE(r.sql_handle, blocked.sql_handle)) AS dest
OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS derp
OUTER APPLY (
SELECT CONVERT(DECIMAL(38,2), SUM( ((tsu.user_objects_alloc_page_count * 8) / 1024.) ) ) AS tempdb_allocations_mb
FROM sys.dm_db_task_space_usage tsu
WHERE tsu.request_id = r.request_id
AND tsu.session_id = r.session_id
AND tsu.session_id = s.session_id
) as tempdb_allocations
WHERE s.session_id <> @@SPID
AND s.host_name IS NOT NULL
'
+ CASE WHEN @ShowSleepingSPIDs = 0 THEN
N' AND COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid)) IS NOT NULL'
WHEN @ShowSleepingSPIDs = 1 THEN
N' OR COALESCE(r.open_transaction_count, blocked.open_tran) >= 1'
ELSE N'' END
+
' ORDER BY 2 DESC;
'
END
IF @Debug = 1
BEGIN
PRINT CONVERT(VARCHAR(8000), SUBSTRING(@StringToExecute, 0, 8000))
PRINT CONVERT(VARCHAR(8000), SUBSTRING(@StringToExecute, 8000, 160000))
END
EXEC(@StringToExecute);
END