-
Notifications
You must be signed in to change notification settings - Fork 1k
/
sp_BlitzWho.sql
1388 lines (1307 loc) · 59.3 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
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
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,
@ExpertMode BIT = 0,
@Debug BIT = 0,
@OutputDatabaseName NVARCHAR(256) = NULL ,
@OutputSchemaName NVARCHAR(256) = NULL ,
@OutputTableName NVARCHAR(256) = NULL ,
@OutputTableRetentionDays TINYINT = 3 ,
@MinElapsedSeconds INT = 0 ,
@MinCPUTime INT = 0 ,
@MinLogicalReads INT = 0 ,
@MinPhysicalReads INT = 0 ,
@MinWrites INT = 0 ,
@MinTempdbMB INT = 0 ,
@MinRequestedMemoryKB INT = 0 ,
@MinBlockingSeconds INT = 0 ,
@CheckDateOverride DATETIMEOFFSET = NULL,
@ShowActualParameters BIT = 0,
@GetOuterCommand BIT = 0,
@GetLiveQueryPlan BIT = 0,
@Version VARCHAR(30) = NULL OUTPUT,
@VersionDate DATETIME = NULL OUTPUT,
@VersionCheckMode BIT = 0,
@SortOrder NVARCHAR(256) = N'elapsed time'
AS
BEGIN
SET NOCOUNT ON;
SET STATISTICS XML OFF;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SELECT @Version = '8.22', @VersionDate = '20241019';
IF(@VersionCheckMode = 1)
BEGIN
RETURN;
END;
IF @Help = 1
BEGIN
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.
- Outputting to table is only supported with SQL Server 2012 and higher.
- If @OutputDatabaseName and @OutputSchemaName are populated, the database and
schema must already exist. We will not create them, only the table.
MIT License
Copyright (c) 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.
';
RETURN;
END; /* @Help = 1 */
/* Get the major and minor build numbers */
DECLARE @ProductVersion NVARCHAR(128)
,@ProductVersionMajor DECIMAL(10,2)
,@ProductVersionMinor DECIMAL(10,2)
,@Platform NVARCHAR(8) /* Azure or NonAzure are acceptable */ = (SELECT CASE WHEN @@VERSION LIKE '%Azure%' THEN N'Azure' ELSE N'NonAzure' END AS [Platform])
,@EnhanceFlag BIT = 0
,@BlockingCheck NVARCHAR(MAX)
,@StringToSelect NVARCHAR(MAX)
,@StringToExecute NVARCHAR(MAX)
,@OutputTableCleanupDate DATE
,@SessionWaits BIT = 0
,@SessionWaitsSQL NVARCHAR(MAX) =
N'LEFT JOIN ( SELECT DISTINCT
wait.session_id ,
( SELECT TOP 5 waitwait.wait_type + N'' (''
+ CAST(MAX(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 1
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'
,@ObjectFullName NVARCHAR(2000)
,@OutputTableNameQueryStats_View NVARCHAR(256)
,@LineFeed NVARCHAR(MAX) /* Had to set as MAX up from 10 as it was truncating the view creation*/;
/* Let's get @SortOrder set to lower case here for comparisons later */
SET @SortOrder = REPLACE(LOWER(@SortOrder), N' ', N'_');
SET @ProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128));
SELECT @ProductVersionMajor = SUBSTRING(@ProductVersion, 1,CHARINDEX('.', @ProductVersion) + 1 ),
@ProductVersionMinor = PARSENAME(CONVERT(VARCHAR(32), @ProductVersion), 2)
SELECT
@OutputTableNameQueryStats_View = QUOTENAME(@OutputTableName + '_Deltas'),
@OutputDatabaseName = QUOTENAME(@OutputDatabaseName),
@OutputSchemaName = QUOTENAME(@OutputSchemaName),
@OutputTableName = QUOTENAME(@OutputTableName),
@LineFeed = CHAR(13) + CHAR(10);
IF @OutputDatabaseName IS NOT NULL AND @OutputSchemaName IS NOT NULL AND @OutputTableName IS NOT NULL
AND EXISTS ( SELECT *
FROM sys.databases
WHERE QUOTENAME([name]) = @OutputDatabaseName)
BEGIN
SET @ExpertMode = 1; /* Force ExpertMode when we're logging to table */
/* Create the table if it doesn't exist */
SET @StringToExecute = N'USE '
+ @OutputDatabaseName
+ N'; IF EXISTS(SELECT * FROM '
+ @OutputDatabaseName
+ N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = '''
+ @OutputSchemaName
+ N''') AND NOT EXISTS (SELECT * FROM '
+ @OutputDatabaseName
+ N'.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = '''
+ @OutputSchemaName + N''' AND QUOTENAME(TABLE_NAME) = '''
+ @OutputTableName + N''') CREATE TABLE '
+ @OutputSchemaName + N'.'
+ @OutputTableName
+ N'(';
SET @StringToExecute = @StringToExecute + N'
ID INT IDENTITY(1,1) NOT NULL,
ServerName NVARCHAR(128) NOT NULL,
CheckDate DATETIMEOFFSET NOT NULL,
[elapsed_time] [varchar](41) NULL,
[session_id] [smallint] NOT NULL,
[database_name] [nvarchar](128) NULL,
[query_text] [nvarchar](max) NULL,
[outer_command] NVARCHAR(4000) NULL,
[query_plan] [xml] NULL,
[live_query_plan] [xml] NULL,
[cached_parameter_info] [nvarchar](max) NULL,
[live_parameter_info] [nvarchar](max) NULL,
[query_cost] [float] NULL,
[status] [nvarchar](30) NOT NULL,
[wait_info] [nvarchar](max) NULL,
[wait_resource] [nvarchar](max) NULL,
[top_session_waits] [nvarchar](max) NULL,
[blocking_session_id] [smallint] NULL,
[open_transaction_count] [int] NULL,
[is_implicit_transaction] [int] NOT NULL,
[nt_domain] [nvarchar](128) NULL,
[host_name] [nvarchar](128) NULL,
[login_name] [nvarchar](128) NOT NULL,
[nt_user_name] [nvarchar](128) NULL,
[program_name] [nvarchar](128) NULL,
[fix_parameter_sniffing] [nvarchar](150) NULL,
[client_interface_name] [nvarchar](32) NULL,
[login_time] [datetime] NOT NULL,
[start_time] [datetime] NULL,
[request_time] [datetime] NULL,
[request_cpu_time] [int] NULL,
[request_logical_reads] [bigint] NULL,
[request_writes] [bigint] NULL,
[request_physical_reads] [bigint] NULL,
[session_cpu] [int] NOT NULL,
[session_logical_reads] [bigint] NOT NULL,
[session_physical_reads] [bigint] NOT NULL,
[session_writes] [bigint] NOT NULL,
[tempdb_allocations_mb] [decimal](38, 2) NULL,
[memory_usage] [int] NOT NULL,
[estimated_completion_time] [bigint] NULL,
[percent_complete] [real] NULL,
[deadlock_priority] [int] NULL,
[transaction_isolation_level] [varchar](33) NOT NULL,
[degree_of_parallelism] [smallint] NULL,
[last_dop] [bigint] NULL,
[min_dop] [bigint] NULL,
[max_dop] [bigint] NULL,
[last_grant_kb] [bigint] NULL,
[min_grant_kb] [bigint] NULL,
[max_grant_kb] [bigint] NULL,
[last_used_grant_kb] [bigint] NULL,
[min_used_grant_kb] [bigint] NULL,
[max_used_grant_kb] [bigint] NULL,
[last_ideal_grant_kb] [bigint] NULL,
[min_ideal_grant_kb] [bigint] NULL,
[max_ideal_grant_kb] [bigint] NULL,
[last_reserved_threads] [bigint] NULL,
[min_reserved_threads] [bigint] NULL,
[max_reserved_threads] [bigint] NULL,
[last_used_threads] [bigint] NULL,
[min_used_threads] [bigint] NULL,
[max_used_threads] [bigint] NULL,
[grant_time] [varchar](20) NULL,
[requested_memory_kb] [bigint] NULL,
[grant_memory_kb] [bigint] NULL,
[is_request_granted] [varchar](39) NOT NULL,
[required_memory_kb] [bigint] NULL,
[query_memory_grant_used_memory_kb] [bigint] NULL,
[ideal_memory_kb] [bigint] NULL,
[is_small] [bit] NULL,
[timeout_sec] [int] NULL,
[resource_semaphore_id] [smallint] NULL,
[wait_order] [varchar](20) NULL,
[wait_time_ms] [varchar](20) NULL,
[next_candidate_for_memory_grant] [varchar](3) NOT NULL,
[target_memory_kb] [bigint] NULL,
[max_target_memory_kb] [varchar](30) NULL,
[total_memory_kb] [bigint] NULL,
[available_memory_kb] [bigint] NULL,
[granted_memory_kb] [bigint] NULL,
[query_resource_semaphore_used_memory_kb] [bigint] NULL,
[grantee_count] [int] NULL,
[waiter_count] [int] NULL,
[timeout_error_count] [bigint] NULL,
[forced_grant_count] [varchar](30) NULL,
[workload_group_name] [sysname] NULL,
[resource_pool_name] [sysname] NULL,
[context_info] [varchar](128) NULL,
[query_hash] [binary](8) NULL,
[query_plan_hash] [binary](8) NULL,
[sql_handle] [varbinary] (64) NULL,
[plan_handle] [varbinary] (64) NULL,
[statement_start_offset] INT NULL,
[statement_end_offset] INT NULL,
JoinKey AS ServerName + CAST(CheckDate AS NVARCHAR(50)),
PRIMARY KEY CLUSTERED (ID ASC));';
IF @Debug = 1
BEGIN
PRINT CONVERT(VARCHAR(8000), SUBSTRING(@StringToExecute, 0, 8000))
PRINT CONVERT(VARCHAR(8000), SUBSTRING(@StringToExecute, 8000, 16000))
END
EXEC(@StringToExecute);
/* If the table doesn't have the new JoinKey computed column, add it. See Github #2162. */
SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableName;
SET @StringToExecute = N'IF NOT EXISTS (SELECT * FROM ' + @OutputDatabaseName + N'.sys.all_columns
WHERE object_id = (OBJECT_ID(''' + @ObjectFullName + N''')) AND name = ''JoinKey'')
ALTER TABLE ' + @ObjectFullName + N' ADD JoinKey AS ServerName + CAST(CheckDate AS NVARCHAR(50));';
EXEC(@StringToExecute);
/* If the table doesn't have the new cached_parameter_info computed column, add it. See Github #2842. */
SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableName;
SET @StringToExecute = N'IF NOT EXISTS (SELECT * FROM ' + @OutputDatabaseName + N'.sys.all_columns
WHERE object_id = (OBJECT_ID(''' + @ObjectFullName + N''')) AND name = ''cached_parameter_info'')
ALTER TABLE ' + @ObjectFullName + N' ADD cached_parameter_info NVARCHAR(MAX) NULL;';
EXEC(@StringToExecute);
/* If the table doesn't have the new live_parameter_info computed column, add it. See Github #2842. */
SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableName;
SET @StringToExecute = N'IF NOT EXISTS (SELECT * FROM ' + @OutputDatabaseName + N'.sys.all_columns
WHERE object_id = (OBJECT_ID(''' + @ObjectFullName + N''')) AND name = ''live_parameter_info'')
ALTER TABLE ' + @ObjectFullName + N' ADD live_parameter_info NVARCHAR(MAX) NULL;';
EXEC(@StringToExecute);
/* If the table doesn't have the new outer_command column, add it. See Github #2887. */
SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableName;
SET @StringToExecute = N'IF NOT EXISTS (SELECT * FROM ' + @OutputDatabaseName + N'.sys.all_columns
WHERE object_id = (OBJECT_ID(''' + @ObjectFullName + N''')) AND name = ''outer_command'')
ALTER TABLE ' + @ObjectFullName + N' ADD outer_command NVARCHAR(4000) NULL;';
EXEC(@StringToExecute);
/* If the table doesn't have the new wait_resource column, add it. See Github #2970. */
SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableName;
SET @StringToExecute = N'IF NOT EXISTS (SELECT * FROM ' + @OutputDatabaseName + N'.sys.all_columns
WHERE object_id = (OBJECT_ID(''' + @ObjectFullName + N''')) AND name = ''wait_resource'')
ALTER TABLE ' + @ObjectFullName + N' ADD wait_resource NVARCHAR(MAX) NULL;';
EXEC(@StringToExecute);
/* Delete history older than @OutputTableRetentionDays */
SET @OutputTableCleanupDate = CAST( (DATEADD(DAY, -1 * @OutputTableRetentionDays, GETDATE() ) ) AS DATE);
SET @StringToExecute = N' IF EXISTS(SELECT * FROM '
+ @OutputDatabaseName
+ N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = '''
+ @OutputSchemaName + N''') DELETE '
+ @OutputDatabaseName + '.'
+ @OutputSchemaName + '.'
+ @OutputTableName
+ N' WHERE ServerName = @SrvName AND CheckDate < @CheckDate;';
IF @Debug = 1
BEGIN
PRINT CONVERT(VARCHAR(8000), SUBSTRING(@StringToExecute, 0, 8000))
PRINT CONVERT(VARCHAR(8000), SUBSTRING(@StringToExecute, 8000, 16000))
END
EXEC sp_executesql @StringToExecute,
N'@SrvName NVARCHAR(128), @CheckDate date',
@@SERVERNAME, @OutputTableCleanupDate;
SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableNameQueryStats_View;
/* Create the view */
IF OBJECT_ID(@ObjectFullName) IS NULL
BEGIN
SET @StringToExecute = N'USE '
+ @OutputDatabaseName
+ N'; EXEC (''CREATE VIEW '
+ @OutputSchemaName + '.'
+ @OutputTableNameQueryStats_View + N' AS ' + @LineFeed
+ N'WITH MaxQueryDuration AS ' + @LineFeed
+ N'( ' + @LineFeed
+ N' SELECT ' + @LineFeed
+ N' MIN([ID]) AS [MinID], ' + @LineFeed
+ N' MAX([ID]) AS [MaxID] ' + @LineFeed
+ N' FROM ' + @OutputSchemaName + '.' + @OutputTableName + '' + @LineFeed
+ N' GROUP BY [ServerName], ' + @LineFeed
+ N' [session_id], ' + @LineFeed
+ N' [database_name], ' + @LineFeed
+ N' [request_time], ' + @LineFeed
+ N' [start_time], ' + @LineFeed
+ N' [sql_handle] ' + @LineFeed
+ N') ' + @LineFeed
+ N'SELECT ' + @LineFeed
+ N' [ID], ' + @LineFeed
+ N' [ServerName], ' + @LineFeed
+ N' [CheckDate], ' + @LineFeed
+ N' [elapsed_time], ' + @LineFeed
+ N' [session_id], ' + @LineFeed
+ N' [database_name], ' + @LineFeed
+ N' [query_text_snippet], ' + @LineFeed
+ N' [query_plan], ' + @LineFeed
+ N' [live_query_plan], ' + @LineFeed
+ N' [query_cost], ' + @LineFeed
+ N' [status], ' + @LineFeed
+ N' [wait_info], ' + @LineFeed
+ N' [wait_resource], ' + @LineFeed
+ N' [top_session_waits], ' + @LineFeed
+ N' [blocking_session_id], ' + @LineFeed
+ N' [open_transaction_count], ' + @LineFeed
+ N' [is_implicit_transaction], ' + @LineFeed
+ N' [nt_domain], ' + @LineFeed
+ N' [host_name], ' + @LineFeed
+ N' [login_name], ' + @LineFeed
+ N' [nt_user_name], ' + @LineFeed
+ N' [program_name], ' + @LineFeed
+ N' [fix_parameter_sniffing], ' + @LineFeed
+ N' [client_interface_name], ' + @LineFeed
+ N' [login_time], ' + @LineFeed
+ N' [start_time], ' + @LineFeed
+ N' [request_time], ' + @LineFeed
+ N' [request_cpu_time], ' + @LineFeed
+ N' [degree_of_parallelism], ' + @LineFeed
+ N' [request_logical_reads], ' + @LineFeed
+ N' [Logical_Reads_MB], ' + @LineFeed
+ N' [request_writes], ' + @LineFeed
+ N' [Logical_Writes_MB], ' + @LineFeed
+ N' [request_physical_reads], ' + @LineFeed
+ N' [Physical_reads_MB], ' + @LineFeed
+ N' [session_cpu], ' + @LineFeed
+ N' [session_logical_reads], ' + @LineFeed
+ N' [session_logical_reads_MB], ' + @LineFeed
+ N' [session_physical_reads], ' + @LineFeed
+ N' [session_physical_reads_MB], ' + @LineFeed
+ N' [session_writes], ' + @LineFeed
+ N' [session_writes_MB], ' + @LineFeed
+ N' [tempdb_allocations_mb], ' + @LineFeed
+ N' [memory_usage], ' + @LineFeed
+ N' [estimated_completion_time], ' + @LineFeed
+ N' [percent_complete], ' + @LineFeed
+ N' [deadlock_priority], ' + @LineFeed
+ N' [transaction_isolation_level], ' + @LineFeed
+ N' [last_dop], ' + @LineFeed
+ N' [min_dop], ' + @LineFeed
+ N' [max_dop], ' + @LineFeed
+ N' [last_grant_kb], ' + @LineFeed
+ N' [min_grant_kb], ' + @LineFeed
+ N' [max_grant_kb], ' + @LineFeed
+ N' [last_used_grant_kb], ' + @LineFeed
+ N' [min_used_grant_kb], ' + @LineFeed
+ N' [max_used_grant_kb], ' + @LineFeed
+ N' [last_ideal_grant_kb], ' + @LineFeed
+ N' [min_ideal_grant_kb], ' + @LineFeed
+ N' [max_ideal_grant_kb], ' + @LineFeed
+ N' [last_reserved_threads], ' + @LineFeed
+ N' [min_reserved_threads], ' + @LineFeed
+ N' [max_reserved_threads], ' + @LineFeed
+ N' [last_used_threads], ' + @LineFeed
+ N' [min_used_threads], ' + @LineFeed
+ N' [max_used_threads], ' + @LineFeed
+ N' [grant_time], ' + @LineFeed
+ N' [requested_memory_kb], ' + @LineFeed
+ N' [grant_memory_kb], ' + @LineFeed
+ N' [is_request_granted], ' + @LineFeed
+ N' [required_memory_kb], ' + @LineFeed
+ N' [query_memory_grant_used_memory_kb], ' + @LineFeed
+ N' [ideal_memory_kb], ' + @LineFeed
+ N' [is_small], ' + @LineFeed
+ N' [timeout_sec], ' + @LineFeed
+ N' [resource_semaphore_id], ' + @LineFeed
+ N' [wait_order], ' + @LineFeed
+ N' [wait_time_ms], ' + @LineFeed
+ N' [next_candidate_for_memory_grant], ' + @LineFeed
+ N' [target_memory_kb], ' + @LineFeed
+ N' [max_target_memory_kb], ' + @LineFeed
+ N' [total_memory_kb], ' + @LineFeed
+ N' [available_memory_kb], ' + @LineFeed
+ N' [granted_memory_kb], ' + @LineFeed
+ N' [query_resource_semaphore_used_memory_kb], ' + @LineFeed
+ N' [grantee_count], ' + @LineFeed
+ N' [waiter_count], ' + @LineFeed
+ N' [timeout_error_count], ' + @LineFeed
+ N' [forced_grant_count], ' + @LineFeed
+ N' [workload_group_name], ' + @LineFeed
+ N' [resource_pool_name], ' + @LineFeed
+ N' [context_info], ' + @LineFeed
+ N' [query_hash], ' + @LineFeed
+ N' [query_plan_hash], ' + @LineFeed
+ N' [sql_handle], ' + @LineFeed
+ N' [plan_handle], ' + @LineFeed
+ N' [statement_start_offset], ' + @LineFeed
+ N' [statement_end_offset] ' + @LineFeed
+ N' FROM ' + @LineFeed
+ N' ( ' + @LineFeed
+ N' SELECT ' + @LineFeed
+ N' [ID], ' + @LineFeed
+ N' [ServerName], ' + @LineFeed
+ N' [CheckDate], ' + @LineFeed
+ N' [elapsed_time], ' + @LineFeed
+ N' [session_id], ' + @LineFeed
+ N' [database_name], ' + @LineFeed
+ N' /* Truncate the query text to aid performance of painting the rows in SSMS */ ' + @LineFeed
+ N' CAST([query_text] AS NVARCHAR(1000)) AS [query_text_snippet], ' + @LineFeed
+ N' [query_plan], ' + @LineFeed
+ N' [live_query_plan], ' + @LineFeed
+ N' [query_cost], ' + @LineFeed
+ N' [status], ' + @LineFeed
+ N' [wait_info], ' + @LineFeed
+ N' [wait_resource], ' + @LineFeed
+ N' [top_session_waits], ' + @LineFeed
+ N' [blocking_session_id], ' + @LineFeed
+ N' [open_transaction_count], ' + @LineFeed
+ N' [is_implicit_transaction], ' + @LineFeed
+ N' [nt_domain], ' + @LineFeed
+ N' [host_name], ' + @LineFeed
+ N' [login_name], ' + @LineFeed
+ N' [nt_user_name], ' + @LineFeed
+ N' [program_name], ' + @LineFeed
+ N' [fix_parameter_sniffing], ' + @LineFeed
+ N' [client_interface_name], ' + @LineFeed
+ N' [login_time], ' + @LineFeed
+ N' [start_time], ' + @LineFeed
+ N' [request_time], ' + @LineFeed
+ N' [request_cpu_time], ' + @LineFeed
+ N' [degree_of_parallelism], ' + @LineFeed
+ N' [request_logical_reads], ' + @LineFeed
+ N' ((CAST([request_logical_reads] AS DECIMAL(38,2))* 8)/ 1024) [Logical_Reads_MB], ' + @LineFeed
+ N' [request_writes], ' + @LineFeed
+ N' ((CAST([request_writes] AS DECIMAL(38,2))* 8)/ 1024) [Logical_Writes_MB], ' + @LineFeed
+ N' [request_physical_reads], ' + @LineFeed
+ N' ((CAST([request_physical_reads] AS DECIMAL(38,2))* 8)/ 1024) [Physical_reads_MB], ' + @LineFeed
+ N' [session_cpu], ' + @LineFeed
+ N' [session_logical_reads], ' + @LineFeed
+ N' ((CAST([session_logical_reads] AS DECIMAL(38,2))* 8)/ 1024) [session_logical_reads_MB], ' + @LineFeed
+ N' [session_physical_reads], ' + @LineFeed
+ N' ((CAST([session_physical_reads] AS DECIMAL(38,2))* 8)/ 1024) [session_physical_reads_MB], ' + @LineFeed
+ N' [session_writes], ' + @LineFeed
+ N' ((CAST([session_writes] AS DECIMAL(38,2))* 8)/ 1024) [session_writes_MB], ' + @LineFeed
+ N' [tempdb_allocations_mb], ' + @LineFeed
+ N' [memory_usage], ' + @LineFeed
+ N' [estimated_completion_time], ' + @LineFeed
+ N' [percent_complete], ' + @LineFeed
+ N' [deadlock_priority], ' + @LineFeed
+ N' [transaction_isolation_level], ' + @LineFeed
+ N' [last_dop], ' + @LineFeed
+ N' [min_dop], ' + @LineFeed
+ N' [max_dop], ' + @LineFeed
+ N' [last_grant_kb], ' + @LineFeed
+ N' [min_grant_kb], ' + @LineFeed
+ N' [max_grant_kb], ' + @LineFeed
+ N' [last_used_grant_kb], ' + @LineFeed
+ N' [min_used_grant_kb], ' + @LineFeed
+ N' [max_used_grant_kb], ' + @LineFeed
+ N' [last_ideal_grant_kb], ' + @LineFeed
+ N' [min_ideal_grant_kb], ' + @LineFeed
+ N' [max_ideal_grant_kb], ' + @LineFeed
+ N' [last_reserved_threads], ' + @LineFeed
+ N' [min_reserved_threads], ' + @LineFeed
+ N' [max_reserved_threads], ' + @LineFeed
+ N' [last_used_threads], ' + @LineFeed
+ N' [min_used_threads], ' + @LineFeed
+ N' [max_used_threads], ' + @LineFeed
+ N' [grant_time], ' + @LineFeed
+ N' [requested_memory_kb], ' + @LineFeed
+ N' [grant_memory_kb], ' + @LineFeed
+ N' [is_request_granted], ' + @LineFeed
+ N' [required_memory_kb], ' + @LineFeed
+ N' [query_memory_grant_used_memory_kb], ' + @LineFeed
+ N' [ideal_memory_kb], ' + @LineFeed
+ N' [is_small], ' + @LineFeed
+ N' [timeout_sec], ' + @LineFeed
+ N' [resource_semaphore_id], ' + @LineFeed
+ N' [wait_order], ' + @LineFeed
+ N' [wait_time_ms], ' + @LineFeed
+ N' [next_candidate_for_memory_grant], ' + @LineFeed
+ N' [target_memory_kb], ' + @LineFeed
+ N' [max_target_memory_kb], ' + @LineFeed
+ N' [total_memory_kb], ' + @LineFeed
+ N' [available_memory_kb], ' + @LineFeed
+ N' [granted_memory_kb], ' + @LineFeed
+ N' [query_resource_semaphore_used_memory_kb], ' + @LineFeed
+ N' [grantee_count], ' + @LineFeed
+ N' [waiter_count], ' + @LineFeed
+ N' [timeout_error_count], ' + @LineFeed
+ N' [forced_grant_count], ' + @LineFeed
+ N' [workload_group_name], ' + @LineFeed
+ N' [resource_pool_name], ' + @LineFeed
+ N' [context_info], ' + @LineFeed
+ N' [query_hash], ' + @LineFeed
+ N' [query_plan_hash], ' + @LineFeed
+ N' [sql_handle], ' + @LineFeed
+ N' [plan_handle], ' + @LineFeed
+ N' [statement_start_offset], ' + @LineFeed
+ N' [statement_end_offset] ' + @LineFeed
+ N' FROM ' + @OutputSchemaName + '.' + @OutputTableName + '' + @LineFeed
+ N' ) AS [BlitzWho] ' + @LineFeed
+ N'INNER JOIN [MaxQueryDuration] ON [BlitzWho].[ID] = [MaxQueryDuration].[MaxID]; ' + @LineFeed
+ N''');'
IF @Debug = 1
BEGIN
PRINT CONVERT(VARCHAR(8000), SUBSTRING(@StringToExecute, 0, 8000))
PRINT CONVERT(VARCHAR(8000), SUBSTRING(@StringToExecute, 8000, 16000))
END
EXEC(@StringToExecute);
END;
END
IF OBJECT_ID('tempdb..#WhoReadableDBs') IS NOT NULL
DROP TABLE #WhoReadableDBs;
CREATE TABLE #WhoReadableDBs
(
database_id INT
);
IF EXISTS (SELECT * FROM sys.all_objects o WHERE o.name = 'dm_hadr_database_replica_states')
BEGIN
RAISERROR('Checking for Read intent databases to exclude',0,0) WITH NOWAIT;
EXEC('INSERT INTO #WhoReadableDBs (database_id) SELECT DBs.database_id FROM sys.databases DBs INNER JOIN sys.availability_replicas Replicas ON DBs.replica_id = Replicas.replica_id WHERE replica_server_name NOT IN (SELECT DISTINCT primary_replica FROM sys.dm_hadr_availability_group_states States) AND Replicas.secondary_role_allow_connections_desc = ''READ_ONLY'' AND replica_server_name = @@SERVERNAME;');
END
SELECT @BlockingCheck = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SET LOCK_TIMEOUT 1000; /* To avoid blocking on live query plans. See Github issue #2907. */
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;
'+CASE
WHEN (@GetOuterCommand = 1 AND (NOT EXISTS(SELECT 1 FROM sys.all_objects WHERE [name] = N'dm_exec_input_buffer'))) THEN N'
DECLARE @session_id SMALLINT;
DECLARE @Sessions TABLE
(
session_id INT
);
DECLARE @inputbuffer TABLE
(
ID INT IDENTITY(1,1),
session_id INT,
event_type NVARCHAR(30),
parameters SMALLINT,
event_info NVARCHAR(4000)
);
DECLARE inputbuffer_cursor
CURSOR LOCAL FAST_FORWARD
FOR
SELECT session_id
FROM sys.dm_exec_sessions
WHERE session_id <> @@SPID
AND is_user_process = 1;
OPEN inputbuffer_cursor;
FETCH NEXT FROM inputbuffer_cursor INTO @session_id;
WHILE (@@FETCH_STATUS = 0)
BEGIN;
BEGIN TRY;
INSERT INTO @inputbuffer ([event_type],[parameters],[event_info])
EXEC sp_executesql
N''DBCC INPUTBUFFER(@session_id) WITH NO_INFOMSGS;'',
N''@session_id SMALLINT'',
@session_id;
UPDATE @inputbuffer
SET session_id = @session_id
WHERE ID = SCOPE_IDENTITY();
END TRY
BEGIN CATCH
RAISERROR(''DBCC inputbuffer failed for session %d'',0,0,@session_id) WITH NOWAIT;
END CATCH;
FETCH NEXT FROM inputbuffer_cursor INTO @session_id
END;
CLOSE inputbuffer_cursor;
DEALLOCATE inputbuffer_cursor;'
ELSE N''
END+
N'
DECLARE @LiveQueryPlans TABLE
(
Session_Id INT NOT NULL,
Query_Plan XML NOT NULL
);
'
IF EXISTS (SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_statistics_xml') AND name = 'query_plan' AND @GetLiveQueryPlan=1)
BEGIN
SET @BlockingCheck = @BlockingCheck + N'
INSERT INTO @LiveQueryPlans
SELECT s.session_id, query_plan
FROM sys.dm_exec_sessions AS s
CROSS APPLY sys.dm_exec_query_statistics_xml(s.session_id)
WHERE s.session_id <> @@SPID;';
END
IF @ProductVersionMajor > 9 and @ProductVersionMajor < 11
BEGIN
/* Think of the StringToExecute as starting with this, but we'll set this up later depending on whether we're doing an insert or a select:
SELECT @StringToExecute = N'SELECT GETDATE() AS run_date ,
*/
SET @StringToExecute = N' CASE WHEN YEAR(s.last_request_start_time) = 1900 THEN NULL ELSE COALESCE( RIGHT(''00'' + CONVERT(VARCHAR(20), (ABS(r.total_elapsed_time) / 1000) / 86400), 2) + '':'' + CONVERT(VARCHAR(20), (DATEADD(SECOND, (r.total_elapsed_time / 1000), 0) + DATEADD(MILLISECOND, (r.total_elapsed_time % 1000), 0)), 114), RIGHT(''00'' + CONVERT(VARCHAR(20), DATEDIFF(SECOND, s.last_request_start_time, GETDATE()) / 86400), 2) + '':'' + CONVERT(VARCHAR(20), DATEADD(SECOND, DATEDIFF(SECOND, s.last_request_start_time, GETDATE()), 0), 114) ) END AS [elapsed_time] ,
s.session_id ,
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
WHEN r.blocking_session_id = 0 AND s.session_id = blocked.session_id
THEN blocked.blocking_session_id
WHEN r.blocking_session_id <> 0 AND s.session_id = blocked.blocking_session_id
THEN r.blocking_session_id
ELSE NULL
END AS blocking_session_id,
COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name,
ISNULL(SUBSTRING(dest.text,
( r.statement_start_offset / 2 ) + 1,
( ( CASE r.statement_end_offset
WHEN -1 THEN DATALENGTH(dest.text)
ELSE r.statement_end_offset
END - r.statement_start_offset )
/ 2 ) + 1), dest.text) AS query_text ,
'+CASE
WHEN @GetOuterCommand = 1 THEN N'CAST(event_info AS NVARCHAR(4000)) AS outer_command,'
ELSE N''
END+N'
derp.query_plan ,
qmg.query_cost ,
s.status ,
CASE
WHEN s.status <> ''sleeping'' THEN COALESCE(wt.wait_info, RTRIM(blocked.lastwaittype) + '' ('' + CONVERT(VARCHAR(10), blocked.waittime) + '')'' )
ELSE NULL
END AS wait_info ,
r.wait_resource ,
COALESCE(r.open_transaction_count, blocked.open_tran) AS open_transaction_count ,
CASE WHEN EXISTS ( SELECT 1
FROM sys.dm_tran_active_transactions AS tat
JOIN sys.dm_tran_session_transactions AS tst
ON tst.transaction_id = tat.transaction_id
WHERE tat.name = ''implicit_transaction''
AND s.session_id = tst.session_id
) THEN 1
ELSE 0
END AS is_implicit_transaction ,
s.nt_domain ,
s.host_name ,
s.login_name ,
s.nt_user_name ,'
IF @Platform = 'NonAzure'
BEGIN
SET @StringToExecute +=
N'program_name = COALESCE((
SELECT REPLACE(program_name,Substring(program_name,30,34),''"''+j.name+''"'')
FROM msdb.dbo.sysjobs j WHERE Substring(program_name,32,32) = CONVERT(char(32),CAST(j.job_id AS binary(16)),2)
),s.program_name)'
END
ELSE
BEGIN
SET @StringToExecute += N's.program_name'
END
IF @ExpertMode = 1
BEGIN
SET @StringToExecute +=
N',
''DBCC FREEPROCCACHE ('' + CONVERT(NVARCHAR(128), r.plan_handle, 1) + '');'' AS fix_parameter_sniffing,
s.client_interface_name ,
s.login_time ,
r.start_time ,
qmg.request_time ,
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,
s.logical_reads AS session_logical_reads,
s.reads AS session_physical_reads ,
s.writes AS session_writes,
tempdb_allocations.tempdb_allocations_mb,
s.memory_usage ,
r.estimated_completion_time ,
r.percent_complete ,
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.databases WHERE name = DB_NAME(r.database_id) AND is_read_committed_snapshot_on = 1) THEN ''Read Committed Snapshot Isolation''
WHEN s.transaction_isolation_level = 2 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 ,
qmg.dop AS degree_of_parallelism ,
COALESCE(CAST(qmg.grant_time AS VARCHAR(20)), ''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 AS query_memory_grant_used_memory_kb,
qmg.ideal_memory_kb ,
qmg.is_small ,
qmg.timeout_sec ,
qmg.resource_semaphore_id ,
COALESCE(CAST(qmg.wait_order AS VARCHAR(20)), ''N/A'') AS wait_order ,
COALESCE(CAST(qmg.wait_time_ms AS VARCHAR(20)),
''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(20)),
''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 AS query_resource_semaphore_used_memory_kb,
qrs.grantee_count ,
qrs.waiter_count ,
qrs.timeout_error_count ,
COALESCE(CAST(qrs.forced_grant_count AS VARCHAR(20)),
''Small Query Resource Semaphore'') AS forced_grant_count,
wg.name AS workload_group_name ,
rp.name AS resource_pool_name,
CONVERT(VARCHAR(128), r.context_info) AS context_info
'
END /* IF @ExpertMode = 1 */
SET @StringToExecute +=
N'FROM sys.dm_exec_sessions AS s
'+
CASE
WHEN @GetOuterCommand = 1 THEN CASE
WHEN EXISTS(SELECT 1 FROM sys.all_objects WHERE [name] = N'dm_exec_input_buffer') THEN N'OUTER APPLY sys.dm_exec_input_buffer (s.session_id, 0) AS ib'
ELSE N'LEFT JOIN @inputbuffer ib ON s.session_id = ib.session_id'
END
ELSE N''
END+N'
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(MAX(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.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 - user_objects_dealloc_page_count) + (tsu.internal_objects_alloc_page_count - internal_objects_dealloc_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;
END /* IF @ProductVersionMajor > 9 and @ProductVersionMajor < 11 */
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
WHEN @ProductVersionMajor > 13 THEN 1
ELSE 0
END
IF OBJECT_ID('sys.dm_exec_session_wait_stats') IS NOT NULL
BEGIN
SET @SessionWaits = 1
END
/* Think of the StringToExecute as starting with this, but we'll set this up later depending on whether we're doing an insert or a select:
SELECT @StringToExecute = N'SELECT GETDATE() AS run_date ,
*/
SELECT @StringToExecute = N' CASE WHEN YEAR(s.last_request_start_time) = 1900 THEN NULL ELSE COALESCE( RIGHT(''00'' + CONVERT(VARCHAR(20), (ABS(r.total_elapsed_time) / 1000) / 86400), 2) + '':'' + CONVERT(VARCHAR(20), (DATEADD(SECOND, (r.total_elapsed_time / 1000), 0) + DATEADD(MILLISECOND, (r.total_elapsed_time % 1000), 0)), 114), RIGHT(''00'' + CONVERT(VARCHAR(20), DATEDIFF(SECOND, s.last_request_start_time, GETDATE()) / 86400), 2) + '':'' + CONVERT(VARCHAR(20), DATEADD(SECOND, DATEDIFF(SECOND, s.last_request_start_time, GETDATE()), 0), 114) ) END AS [elapsed_time] ,
s.session_id ,
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
WHEN r.blocking_session_id = 0 AND s.session_id = blocked.session_id
THEN blocked.blocking_session_id
WHEN r.blocking_session_id <> 0 AND s.session_id = blocked.blocking_session_id
THEN r.blocking_session_id
ELSE NULL
END AS blocking_session_id,
COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name,
ISNULL(SUBSTRING(dest.text,
( r.statement_start_offset / 2 ) + 1,
( ( CASE r.statement_end_offset
WHEN -1 THEN DATALENGTH(dest.text)
ELSE r.statement_end_offset
END - r.statement_start_offset )
/ 2 ) + 1), dest.text) AS query_text ,
'+CASE
WHEN @GetOuterCommand = 1 THEN N'CAST(event_info AS NVARCHAR(4000)) AS outer_command,'
ELSE N''
END+N'
derp.query_plan ,
CAST(COALESCE(qs_live.Query_Plan, ' + CASE WHEN @GetLiveQueryPlan=1
THEN '''<?No live query plan available. To turn on live plans, see https://www.BrentOzar.com/go/liveplans ?>'''
ELSE '''<?Live Query Plans were not retrieved. Set @GetLiveQueryPlan=1 to try and retrieve Live Query Plans ?>'''
END
+') AS XML
) AS live_query_plan ,
STUFF((SELECT DISTINCT N'', '' + Node.Data.value(''(@Column)[1]'', ''NVARCHAR(4000)'') + N'' {'' + Node.Data.value(''(@ParameterDataType)[1]'', ''NVARCHAR(4000)'') + N''}: '' + Node.Data.value(''(@ParameterCompiledValue)[1]'', ''NVARCHAR(4000)'')
FROM derp.query_plan.nodes(''/*:ShowPlanXML/*:BatchSequence/*:Batch/*:Statements/*:StmtSimple/*:QueryPlan/*:ParameterList/*:ColumnReference'') AS Node(Data)
FOR XML PATH('''')), 1,2,'''')
AS Cached_Parameter_Info,
'
IF @ShowActualParameters = 1
BEGIN
SELECT @StringToExecute = @StringToExecute + N'qs_live.Live_Parameter_Info as Live_Parameter_Info,'
END
SELECT @StringToExecute = @StringToExecute + N'
qmg.query_cost ,
s.status ,
CASE
WHEN s.status <> ''sleeping'' THEN COALESCE(wt.wait_info, RTRIM(blocked.lastwaittype) + '' ('' + CONVERT(VARCHAR(10), blocked.waittime) + '')'' )
ELSE NULL
END AS wait_info ,
r.wait_resource ,'
+
CASE @SessionWaits
WHEN 1 THEN + N'SUBSTRING(wt2.session_wait_info, 0, LEN(wt2.session_wait_info) ) AS top_session_waits ,'
ELSE N' NULL AS top_session_waits ,'
END
+
N'COALESCE(r.open_transaction_count, blocked.open_tran) AS open_transaction_count ,
CASE WHEN EXISTS ( SELECT 1
FROM sys.dm_tran_active_transactions AS tat
JOIN sys.dm_tran_session_transactions AS tst
ON tst.transaction_id = tat.transaction_id
WHERE tat.name = ''implicit_transaction''
AND s.session_id = tst.session_id
) THEN 1
ELSE 0
END AS is_implicit_transaction ,
s.nt_domain ,
s.host_name ,
s.login_name ,
s.nt_user_name ,'
IF @Platform = 'NonAzure'
BEGIN
SET @StringToExecute +=
N'program_name = COALESCE((
SELECT REPLACE(program_name,Substring(program_name,30,34),''"''+j.name+''"'')
FROM msdb.dbo.sysjobs j WHERE Substring(program_name,32,32) = CONVERT(char(32),CAST(j.job_id AS binary(16)),2)
),s.program_name)'
END
ELSE
BEGIN
SET @StringToExecute += N's.program_name'
END
IF @ExpertMode = 1 /* We show more columns in expert mode, so the SELECT gets longer */
BEGIN
SET @StringToExecute +=
N', ''DBCC FREEPROCCACHE ('' + CONVERT(NVARCHAR(128), r.plan_handle, 1) + '');'' AS fix_parameter_sniffing,
s.client_interface_name ,
s.login_time ,
r.start_time ,
qmg.request_time ,
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,
s.logical_reads AS session_logical_reads,
s.reads AS session_physical_reads ,
s.writes AS session_writes,
tempdb_allocations.tempdb_allocations_mb,
s.memory_usage ,
r.estimated_completion_time ,
r.percent_complete ,