-
Notifications
You must be signed in to change notification settings - Fork 1k
/
sp_BlitzLock.sql
4169 lines (3879 loc) · 149 KB
/
sp_BlitzLock.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_BlitzLock') IS NULL
BEGIN
EXEC ('CREATE PROCEDURE dbo.sp_BlitzLock AS RETURN 0;');
END;
GO
ALTER PROCEDURE
dbo.sp_BlitzLock
(
@DatabaseName sysname = NULL,
@StartDate datetime = NULL,
@EndDate datetime = NULL,
@ObjectName nvarchar(1024) = NULL,
@StoredProcName nvarchar(1024) = NULL,
@AppName sysname = NULL,
@HostName sysname = NULL,
@LoginName sysname = NULL,
@EventSessionName sysname = N'system_health',
@TargetSessionType sysname = NULL,
@VictimsOnly bit = 0,
@DeadlockType nvarchar(20) = NULL,
@Debug bit = 0,
@Help bit = 0,
@Version varchar(30) = NULL OUTPUT,
@VersionDate datetime = NULL OUTPUT,
@VersionCheckMode bit = 0,
@OutputDatabaseName sysname = NULL,
@OutputSchemaName sysname = N'dbo', /*ditto as below*/
@OutputTableName sysname = N'BlitzLock', /*put a standard here no need to check later in the script*/
@ExportToExcel bit = 0
)
WITH RECOMPILE
AS
BEGIN
SET STATISTICS XML OFF;
SET NOCOUNT ON;
SET XACT_ABORT OFF;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SELECT @Version = '8.22', @VersionDate = '20241019';
IF @VersionCheckMode = 1
BEGIN
RETURN;
END;
IF @Help = 1
BEGIN
PRINT N'
/*
sp_BlitzLock from http://FirstResponderKit.org
This script checks for and analyzes deadlocks from the system health session or a custom extended event path
Variables you can use:
@DatabaseName: If you want to filter to a specific database
@StartDate: The date you want to start searching on, defaults to last 7 days
@EndDate: The date you want to stop searching on, defaults to current date
@ObjectName: If you want to filter to a specific able.
The object name has to be fully qualified ''Database.Schema.Table''
@StoredProcName: If you want to search for a single stored proc
The proc name has to be fully qualified ''Database.Schema.Sproc''
@AppName: If you want to filter to a specific application
@HostName: If you want to filter to a specific host
@LoginName: If you want to filter to a specific login
@EventSessionName: If you want to point this at an XE session rather than the system health session.
@TargetSessionType: Can be ''ring_buffer'' or ''event_file''. Leave NULL to auto-detect.
@OutputDatabaseName: If you want to output information to a specific database
@OutputSchemaName: Specify a schema name to output information to a specific Schema
@OutputTableName: Specify table name to to output information to a specific table
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 SQL Server 2012 and newer is supported
- If your tables have weird characters in them (https://en.wikipedia.org/wiki/List_of_xml_and_HTML_character_entity_references) you may get errors trying to parse the xml.
I took a long look at this one, and:
1) Trying to account for all the weird places these could crop up is a losing effort.
2) Replace is slow af on lots of xml.
Unknown limitations of this version:
- None. (If we knew them, they would be known. Duh.)
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 */
/*Declare local variables used in the procudure*/
DECLARE
@DatabaseId int =
DB_ID(@DatabaseName),
@ProductVersion nvarchar(128) =
CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(128)),
@ProductVersionMajor float =
SUBSTRING
(
CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(128)),
1,
CHARINDEX('.', CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(128))) + 1
),
@ProductVersionMinor int =
PARSENAME
(
CONVERT
(
varchar(32),
CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(128))
),
2
),
@ObjectFullName nvarchar(MAX) = N'',
@Azure bit =
CASE
WHEN
(
SELECT
CONVERT
(
integer,
SERVERPROPERTY('EngineEdition')
)
) = 5
THEN 1
ELSE 0
END,
@MI bit =
CASE
WHEN
(
SELECT
CONVERT
(
integer,
SERVERPROPERTY('EngineEdition')
)
) = 8
THEN 1
ELSE 0
END,
@RDS bit =
CASE
WHEN LEFT(CAST(SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS varchar(8000)), 8) <> 'EC2AMAZ-'
AND LEFT(CAST(SERVERPROPERTY('MachineName') AS varchar(8000)), 8) <> 'EC2AMAZ-'
AND DB_ID('rdsadmin') IS NULL
THEN 0
ELSE 1
END,
@d varchar(40) = '',
@StringToExecute nvarchar(4000) = N'',
@StringToExecuteParams nvarchar(500) = N'',
@r sysname = NULL,
@OutputTableFindings nvarchar(100) = N'[BlitzLockFindings]',
@DeadlockCount int = 0,
@ServerName sysname = @@SERVERNAME,
@OutputDatabaseCheck bit = -1,
@SessionId int = 0,
@TargetSessionId int = 0,
@FileName nvarchar(4000) = N'',
@inputbuf_bom nvarchar(1) = CONVERT(nvarchar(1), 0x0a00, 0),
@deadlock_result nvarchar(MAX) = N'',
@StartDateOriginal datetime = @StartDate,
@EndDateOriginal datetime = @EndDate,
@StartDateUTC datetime,
@EndDateUTC datetime;;
/*Temporary objects used in the procedure*/
DECLARE
@sysAssObjId AS table
(
database_id int,
partition_id bigint,
schema_name sysname,
table_name sysname
);
CREATE TABLE
#x
(
x xml NOT NULL
DEFAULT N'<x>x</x>'
);
CREATE TABLE
#deadlock_data
(
deadlock_xml xml NOT NULL
DEFAULT N'<x>x</x>'
);
CREATE TABLE
#t
(
id int NOT NULL
);
CREATE TABLE
#deadlock_findings
(
id int IDENTITY PRIMARY KEY,
check_id int NOT NULL,
database_name nvarchar(256),
object_name nvarchar(1000),
finding_group nvarchar(100),
finding nvarchar(4000),
sort_order bigint
);
/*Set these to some sane defaults if NULLs are passed in*/
/*Normally I'd hate this, but we RECOMPILE everything*/
SELECT
@StartDate =
CASE
WHEN @StartDate IS NULL
THEN
DATEADD
(
MINUTE,
DATEDIFF
(
MINUTE,
SYSDATETIME(),
GETUTCDATE()
),
DATEADD
(
DAY,
-7,
SYSDATETIME()
)
)
ELSE
DATEADD
(
MINUTE,
DATEDIFF
(
MINUTE,
SYSDATETIME(),
GETUTCDATE()
),
@StartDate
)
END,
@EndDate =
CASE
WHEN @EndDate IS NULL
THEN
DATEADD
(
MINUTE,
DATEDIFF
(
MINUTE,
SYSDATETIME(),
GETUTCDATE()
),
SYSDATETIME()
)
ELSE
DATEADD
(
MINUTE,
DATEDIFF
(
MINUTE,
SYSDATETIME(),
GETUTCDATE()
),
@EndDate
)
END;
SELECT
@StartDateUTC = @StartDate,
@EndDateUTC = @EndDate;
IF
(
@MI = 1
AND @EventSessionName = N'system_health'
AND @TargetSessionType IS NULL
)
BEGIN
SET
@TargetSessionType = N'ring_buffer';
END;
IF @Azure = 0
BEGIN
IF NOT EXISTS
(
SELECT
1/0
FROM sys.server_event_sessions AS ses
JOIN sys.dm_xe_sessions AS dxs
ON dxs.name = ses.name
WHERE ses.name = @EventSessionName
AND dxs.create_time IS NOT NULL
)
BEGIN
RAISERROR('A session with the name %s does not exist or is not currently active.', 11, 1, @EventSessionName) WITH NOWAIT;
RETURN;
END;
END;
IF @Azure = 1
BEGIN
IF NOT EXISTS
(
SELECT
1/0
FROM sys.database_event_sessions AS ses
JOIN sys.dm_xe_database_sessions AS dxs
ON dxs.name = ses.name
WHERE ses.name = @EventSessionName
AND dxs.create_time IS NOT NULL
)
BEGIN
RAISERROR('A session with the name %s does not exist or is not currently active.', 11, 1, @EventSessionName) WITH NOWAIT;
RETURN;
END;
END;
IF @OutputDatabaseName IS NOT NULL
BEGIN /*IF databaseName is set, do some sanity checks and put [] around def.*/
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('@OutputDatabaseName set to %s, checking validity at %s', 0, 1, @OutputDatabaseName, @d) WITH NOWAIT;
IF NOT EXISTS
(
SELECT
1/0
FROM sys.databases AS d
WHERE d.name = @OutputDatabaseName
) /*If database is invalid raiserror and set bitcheck*/
BEGIN
RAISERROR('Database Name (%s) for output of table is invalid please, Output to Table will not be performed', 0, 1, @OutputDatabaseName) WITH NOWAIT;
SET @OutputDatabaseCheck = -1; /* -1 invalid/false, 0 = good/true */
END;
ELSE
BEGIN
SET @OutputDatabaseCheck = 0;
SELECT
@StringToExecute =
N'SELECT @r = o.name FROM ' +
@OutputDatabaseName +
N'.sys.objects AS o WHERE o.type_desc = N''USER_TABLE'' AND o.name = ' +
QUOTENAME
(
@OutputTableName,
N''''
) +
N' AND o.schema_id = SCHEMA_ID(' +
QUOTENAME
(
@OutputSchemaName,
N''''
) +
N');',
@StringToExecuteParams =
N'@r sysname OUTPUT';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute,
@StringToExecuteParams,
@r OUTPUT;
IF @Debug = 1
BEGIN
RAISERROR('@r is set to: %s for schema name %s and table name %s', 0, 1, @r, @OutputSchemaName, @OutputTableName) WITH NOWAIT;
END;
/*protection spells*/
SELECT
@ObjectFullName =
QUOTENAME(@OutputDatabaseName) +
N'.' +
QUOTENAME(@OutputSchemaName) +
N'.' +
QUOTENAME(@OutputTableName),
@OutputDatabaseName =
QUOTENAME(@OutputDatabaseName),
@OutputTableName =
QUOTENAME(@OutputTableName),
@OutputSchemaName =
QUOTENAME(@OutputSchemaName);
IF (@r IS NOT NULL) /*if it is not null, there is a table, so check for newly added columns*/
BEGIN
/* If the table doesn't have the new spid column, add it. See Github #3101. */
SET @StringToExecute =
N'IF NOT EXISTS (SELECT 1/0 FROM ' +
@OutputDatabaseName +
N'.sys.all_columns AS o WHERE o.object_id = (OBJECT_ID(''' +
@ObjectFullName +
N''')) AND o.name = N''spid'')
/*Add spid column*/
ALTER TABLE ' +
@ObjectFullName +
N' ADD spid smallint NULL;';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
/* If the table doesn't have the new wait_resource column, add it. See Github #3101. */
SET @StringToExecute =
N'IF NOT EXISTS (SELECT 1/0 FROM ' +
@OutputDatabaseName +
N'.sys.all_columns AS o WHERE o.object_id = (OBJECT_ID(''' +
@ObjectFullName +
N''')) AND o.name = N''wait_resource'')
/*Add wait_resource column*/
ALTER TABLE ' +
@ObjectFullName +
N' ADD wait_resource nvarchar(MAX) NULL;';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
/* If the table doesn't have the new client option column, add it. See Github #3101. */
SET @StringToExecute =
N'IF NOT EXISTS (SELECT 1/0 FROM ' +
@OutputDatabaseName +
N'.sys.all_columns AS o WHERE o.object_id = (OBJECT_ID(''' +
@ObjectFullName +
N''')) AND o.name = N''client_option_1'')
/*Add wait_resource column*/
ALTER TABLE ' +
@ObjectFullName +
N' ADD client_option_1 varchar(500) NULL;';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
/* If the table doesn't have the new client option column, add it. See Github #3101. */
SET @StringToExecute =
N'IF NOT EXISTS (SELECT 1/0 FROM ' +
@OutputDatabaseName +
N'.sys.all_columns AS o WHERE o.object_id = (OBJECT_ID(''' +
@ObjectFullName +
N''')) AND o.name = N''client_option_2'')
/*Add wait_resource column*/
ALTER TABLE ' +
@ObjectFullName +
N' ADD client_option_2 varchar(500) NULL;';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
/* If the table doesn't have the new lock mode column, add it. See Github #3101. */
SET @StringToExecute =
N'IF NOT EXISTS (SELECT 1/0 FROM ' +
@OutputDatabaseName +
N'.sys.all_columns AS o WHERE o.object_id = (OBJECT_ID(''' +
@ObjectFullName +
N''')) AND o.name = N''lock_mode'')
/*Add wait_resource column*/
ALTER TABLE ' +
@ObjectFullName +
N' ADD lock_mode nvarchar(256) NULL;';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
/* If the table doesn't have the new status column, add it. See Github #3101. */
SET @StringToExecute =
N'IF NOT EXISTS (SELECT 1/0 FROM ' +
@OutputDatabaseName +
N'.sys.all_columns AS o WHERE o.object_id = (OBJECT_ID(''' +
@ObjectFullName +
N''')) AND o.name = N''status'')
/*Add wait_resource column*/
ALTER TABLE ' +
@ObjectFullName +
N' ADD status nvarchar(256) NULL;';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
END;
ELSE /* end if @r is not null. if it is null there is no table, create it from above execution */
BEGIN
SELECT
@StringToExecute =
N'USE ' +
@OutputDatabaseName +
N';
CREATE TABLE ' +
@OutputSchemaName +
N'.' +
@OutputTableName +
N' (
ServerName nvarchar(256),
deadlock_type nvarchar(256),
event_date datetime,
database_name nvarchar(256),
spid smallint,
deadlock_group nvarchar(256),
query xml,
object_names xml,
isolation_level nvarchar(256),
owner_mode nvarchar(256),
waiter_mode nvarchar(256),
lock_mode nvarchar(256),
transaction_count bigint,
client_option_1 varchar(500),
client_option_2 varchar(500),
login_name nvarchar(256),
host_name nvarchar(256),
client_app nvarchar(1024),
wait_time bigint,
wait_resource nvarchar(max),
priority smallint,
log_used bigint,
last_tran_started datetime,
last_batch_started datetime,
last_batch_completed datetime,
transaction_name nvarchar(256),
status nvarchar(256),
owner_waiter_type nvarchar(256),
owner_activity nvarchar(256),
owner_waiter_activity nvarchar(256),
owner_merging nvarchar(256),
owner_spilling nvarchar(256),
owner_waiting_to_close nvarchar(256),
waiter_waiter_type nvarchar(256),
waiter_owner_activity nvarchar(256),
waiter_waiter_activity nvarchar(256),
waiter_merging nvarchar(256),
waiter_spilling nvarchar(256),
waiter_waiting_to_close nvarchar(256),
deadlock_graph xml
)';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
/*table created.*/
SELECT
@StringToExecute =
N'SELECT @r = o.name FROM ' +
@OutputDatabaseName +
N'.sys.objects AS o
WHERE o.type_desc = N''USER_TABLE''
AND o.name = N''BlitzLockFindings''',
@StringToExecuteParams =
N'@r sysname OUTPUT';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute,
@StringToExecuteParams,
@r OUTPUT;
IF (@r IS NULL) /*if table does not exist*/
BEGIN
SELECT
@OutputTableFindings =
QUOTENAME(N'BlitzLockFindings'),
@StringToExecute =
N'USE ' +
@OutputDatabaseName +
N';
CREATE TABLE ' +
@OutputSchemaName +
N'.' +
@OutputTableFindings +
N' (
ServerName nvarchar(256),
check_id INT,
database_name nvarchar(256),
object_name nvarchar(1000),
finding_group nvarchar(100),
finding nvarchar(4000)
);';
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
END;
END;
/*create synonym for deadlockfindings.*/
IF EXISTS
(
SELECT
1/0
FROM sys.objects AS o
WHERE o.name = N'DeadlockFindings'
AND o.type_desc = N'SYNONYM'
)
BEGIN
RAISERROR('Found synonym DeadlockFindings, dropping', 0, 1) WITH NOWAIT;
DROP SYNONYM DeadlockFindings;
END;
RAISERROR('Creating synonym DeadlockFindings', 0, 1) WITH NOWAIT;
SET @StringToExecute =
N'CREATE SYNONYM DeadlockFindings FOR ' +
@OutputDatabaseName +
N'.' +
@OutputSchemaName +
N'.' +
@OutputTableFindings;
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
/*create synonym for deadlock table.*/
IF EXISTS
(
SELECT
1/0
FROM sys.objects AS o
WHERE o.name = N'DeadLockTbl'
AND o.type_desc = N'SYNONYM'
)
BEGIN
RAISERROR('Found synonym DeadLockTbl, dropping', 0, 1) WITH NOWAIT;
DROP SYNONYM DeadLockTbl;
END;
RAISERROR('Creating synonym DeadLockTbl', 0, 1) WITH NOWAIT;
SET @StringToExecute =
N'CREATE SYNONYM DeadLockTbl FOR ' +
@OutputDatabaseName +
N'.' +
@OutputSchemaName +
N'.' +
@OutputTableName;
IF @Debug = 1 BEGIN PRINT @StringToExecute; END;
EXEC sys.sp_executesql
@StringToExecute;
END;
END;
/* WITH ROWCOUNT doesn't work on Amazon RDS - see: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2037 */
IF @RDS = 0
BEGIN;
BEGIN TRY;
RAISERROR('@RDS = 0, updating #t with high row and page counts', 0, 1) WITH NOWAIT;
UPDATE STATISTICS
#t
WITH
ROWCOUNT = 9223372036854775807,
PAGECOUNT = 9223372036854775807;
END TRY
BEGIN CATCH;
/* Misleading error returned, if run without permissions to update statistics the error returned is "Cannot find object".
Catching specific error, and returning message with better info. If any other error is returned, then throw as normal */
IF (ERROR_NUMBER() = 1088)
BEGIN;
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('Cannot run UPDATE STATISTICS on a #temp table without db_owner or sysadmin permissions', 0, 1) WITH NOWAIT;
END;
ELSE
BEGIN;
THROW;
END;
END CATCH;
END;
IF @DeadlockType IS NOT NULL
BEGIN
SELECT
@DeadlockType =
CASE
WHEN LOWER(@DeadlockType) LIKE 'regular%'
THEN N'Regular Deadlock'
WHEN LOWER(@DeadlockType) LIKE N'parallel%'
THEN N'Parallel Deadlock'
ELSE NULL
END;
END;
/*If @TargetSessionType, we need to figure out if it's ring buffer or event file*/
/*Azure has differently named views, so we need to separate. Thanks, Azure.*/
IF
(
@Azure = 0
AND @TargetSessionType IS NULL
)
BEGIN
RAISERROR('@TargetSessionType is NULL, assigning for non-Azure instance', 0, 1) WITH NOWAIT;
SELECT TOP (1)
@TargetSessionType = t.target_name
FROM sys.dm_xe_sessions AS s
JOIN sys.dm_xe_session_targets AS t
ON s.address = t.event_session_address
WHERE s.name = @EventSessionName
AND t.target_name IN (N'event_file', N'ring_buffer')
ORDER BY t.target_name
OPTION(RECOMPILE);
RAISERROR('@TargetSessionType assigned as %s for non-Azure', 0, 1, @TargetSessionType) WITH NOWAIT;
END;
IF
(
@Azure = 1
AND @TargetSessionType IS NULL
)
BEGIN
RAISERROR('@TargetSessionType is NULL, assigning for Azure instance', 0, 1) WITH NOWAIT;
SELECT TOP (1)
@TargetSessionType = t.target_name
FROM sys.dm_xe_database_sessions AS s
JOIN sys.dm_xe_database_session_targets AS t
ON s.address = t.event_session_address
WHERE s.name = @EventSessionName
AND t.target_name IN (N'event_file', N'ring_buffer')
ORDER BY t.target_name
OPTION(RECOMPILE);
RAISERROR('@TargetSessionType assigned as %s for Azure', 0, 1, @TargetSessionType) WITH NOWAIT;
END;
/*The system health stuff gets handled different from user extended events.*/
/*These next sections deal with user events, dependent on target.*/
/*If ring buffers*/
IF
(
@TargetSessionType LIKE N'ring%'
AND @EventSessionName NOT LIKE N'system_health%'
)
BEGIN
IF @Azure = 0
BEGIN
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('@TargetSessionType is ring_buffer, inserting XML for non-Azure at %s', 0, 1, @d) WITH NOWAIT;
INSERT
#x WITH(TABLOCKX)
(
x
)
SELECT
x = TRY_CAST(t.target_data AS xml)
FROM sys.dm_xe_session_targets AS t
JOIN sys.dm_xe_sessions AS s
ON s.address = t.event_session_address
WHERE s.name = @EventSessionName
AND t.target_name = N'ring_buffer'
OPTION(RECOMPILE);
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('Finished at %s', 0, 1, @d) WITH NOWAIT;
END;
IF @Azure = 1
BEGIN
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('@TargetSessionType is ring_buffer, inserting XML for Azure at %s', 0, 1, @d) WITH NOWAIT;
INSERT
#x WITH(TABLOCKX)
(
x
)
SELECT
x = TRY_CAST(t.target_data AS xml)
FROM sys.dm_xe_database_session_targets AS t
JOIN sys.dm_xe_database_sessions AS s
ON s.address = t.event_session_address
WHERE s.name = @EventSessionName
AND t.target_name = N'ring_buffer'
OPTION(RECOMPILE);
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('Finished at %s', 0, 1, @d) WITH NOWAIT;
END;
END;
/*If event file*/
IF
(
@TargetSessionType LIKE N'event%'
AND @EventSessionName NOT LIKE N'system_health%'
)
BEGIN
IF @Azure = 0
BEGIN
RAISERROR('@TargetSessionType is event_file, assigning XML for non-Azure', 0, 1) WITH NOWAIT;
SELECT
@SessionId = t.event_session_id,
@TargetSessionId = t.target_id
FROM sys.server_event_session_targets AS t
JOIN sys.server_event_sessions AS s
ON s.event_session_id = t.event_session_id
WHERE t.name = @TargetSessionType
AND s.name = @EventSessionName
OPTION(RECOMPILE);
/*We get the file name automatically, here*/
RAISERROR('Assigning @FileName...', 0, 1) WITH NOWAIT;
SELECT
@FileName =
CASE
WHEN f.file_name LIKE N'%.xel'
THEN REPLACE(f.file_name, N'.xel', N'*.xel')
ELSE f.file_name + N'*.xel'
END
FROM
(
SELECT
file_name =
CONVERT(nvarchar(4000), f.value)
FROM sys.server_event_session_fields AS f
WHERE f.event_session_id = @SessionId
AND f.object_id = @TargetSessionId
AND f.name = N'filename'
) AS f
OPTION(RECOMPILE);
END;
IF @Azure = 1
BEGIN
RAISERROR('@TargetSessionType is event_file, assigning XML for Azure', 0, 1) WITH NOWAIT;
SELECT
@SessionId =
t.event_session_address,
@TargetSessionId =
t.target_name
FROM sys.dm_xe_database_session_targets t
JOIN sys.dm_xe_database_sessions s
ON s.address = t.event_session_address
WHERE t.target_name = @TargetSessionType
AND s.name = @EventSessionName
OPTION(RECOMPILE);
/*We get the file name automatically, here*/
RAISERROR('Assigning @FileName...', 0, 1) WITH NOWAIT;
SELECT
@FileName =
CASE
WHEN f.file_name LIKE N'%.xel'
THEN REPLACE(f.file_name, N'.xel', N'*.xel')
ELSE f.file_name + N'*.xel'
END
FROM
(
SELECT
file_name =
CONVERT(nvarchar(4000), f.value)
FROM sys.server_event_session_fields AS f
WHERE f.event_session_id = @SessionId
AND f.object_id = @TargetSessionId
AND f.name = N'filename'
) AS f
OPTION(RECOMPILE);
END;
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('Reading for event_file %s', 0, 1, @FileName) WITH NOWAIT;
INSERT
#x WITH(TABLOCKX)
(
x
)
SELECT
x = TRY_CAST(f.event_data AS xml)
FROM sys.fn_xe_file_target_read_file(@FileName, NULL, NULL, NULL) AS f
LEFT JOIN #t AS t
ON 1 = 1
OPTION(RECOMPILE);
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('Finished at %s', 0, 1, @d) WITH NOWAIT;
END;
/*The XML is parsed differently if it comes from the event file or ring buffer*/
/*If ring buffers*/
IF
(
@TargetSessionType LIKE N'ring%'
AND @EventSessionName NOT LIKE N'system_health%'
)
BEGIN
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('Inserting to #deadlock_data for ring buffer data', 0, 1) WITH NOWAIT;
INSERT
#deadlock_data WITH(TABLOCKX)
(
deadlock_xml
)
SELECT
deadlock_xml =
e.x.query(N'.')
FROM #x AS x
LEFT JOIN #t AS t
ON 1 = 1
CROSS APPLY x.x.nodes('/RingBufferTarget/event') AS e(x)
WHERE
(
e.x.exist('@name[ .= "xml_deadlock_report"]') = 1
OR e.x.exist('@name[ .= "database_xml_deadlock_report"]') = 1
OR e.x.exist('@name[ .= "xml_deadlock_report_filtered"]') = 1
)
AND e.x.exist('@timestamp[. >= sql:variable("@StartDate") and .< sql:variable("@EndDate")]') = 1
OPTION(RECOMPILE);
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('Finished at %s', 0, 1, @d) WITH NOWAIT;
END;
/*If event file*/
IF
(
@TargetSessionType LIKE N'event_file%'
AND @EventSessionName NOT LIKE N'system_health%'
)
BEGIN
SET @d = CONVERT(varchar(40), GETDATE(), 109);
RAISERROR('Inserting to #deadlock_data for event file data', 0, 1) WITH NOWAIT;
IF @Debug = 1 BEGIN SET STATISTICS XML ON; END;
INSERT
#deadlock_data WITH(TABLOCKX)
(
deadlock_xml
)
SELECT
deadlock_xml =
e.x.query('.')
FROM #x AS x
LEFT JOIN #t AS t
ON 1 = 1
CROSS APPLY x.x.nodes('/event') AS e(x)
WHERE
(
e.x.exist('@name[ .= "xml_deadlock_report"]') = 1
OR e.x.exist('@name[ .= "database_xml_deadlock_report"]') = 1
OR e.x.exist('@name[ .= "xml_deadlock_report_filtered"]') = 1
)
AND e.x.exist('@timestamp[. >= sql:variable("@StartDate") and .< sql:variable("@EndDate")]') = 1
OPTION(RECOMPILE);
IF @Debug = 1 BEGIN SET STATISTICS XML OFF; END;
SET @d = CONVERT(varchar(40), GETDATE(), 109);