forked from BrentOzarULTD/SQL-Server-First-Responder-Kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
sp_BlitzLock.sql
717 lines (604 loc) · 26.7 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
IF OBJECT_ID('dbo.sp_BlitzLock') IS NULL
EXEC ('CREATE PROCEDURE dbo.sp_BlitzLock AS RETURN 0;');
GO
ALTER PROCEDURE dbo.sp_BlitzLock
(
@Top INT = 2147483647,
@DatabaseName NVARCHAR(256) = NULL,
@StartDate DATETIME = '19000101',
@EndDate DATETIME = '99991231',
@ObjectName NVARCHAR(1000) = NULL,
@StoredProcName NVARCHAR(1000) = NULL,
@AppName NVARCHAR(256) = NULL,
@HostName NVARCHAR(256) = NULL,
@LoginName NVARCHAR(256) = NULL,
@EventSessionPath VARCHAR(256) = 'system_health*.xel',
@Debug BIT = 0,
@Help BIT = 0,
@VersionDate DATETIME = NULL OUTPUT
)
AS
BEGIN
SET NOCOUNT ON;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
DECLARE @Version VARCHAR(30);
SET @Version = '1.0';
SET @VersionDate = '20171201';
IF @Help = 1 PRINT '
/*
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:
@Top: Use if you want to limit the number of deadlocks to return.
This is ordered by event date ascending
@DatabaseName: If you want to filter to a specific database
@StartDate: The date you want to start searching on.
@EndDate: The date you want to stop searching on.
@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
@EventSessionPath: If you want to point this at an XE session rather than the system health session.
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.
Unknown limitations of this version:
- None. (If we knew them, they would be known. Duh.)
Changes - for the full list of improvements and fixes in this version, see:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/
MIT License
All other copyright for sp_BlitzLock are held by Brent Ozar Unlimited, 2017.
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.
*/';
DECLARE @ProductVersion NVARCHAR(128);
DECLARE @ProductVersionMajor FLOAT;
DECLARE @ProductVersionMinor INT;
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 < 11.0
BEGIN
RAISERROR(
'sp_BlitzLock will throw a bunch of angry errors on versions of SQL Server earlier than 2012.',
0,
1) WITH NOWAIT;
RETURN;
END;
IF @Top IS NULL
SET @Top = 2147483647;
IF @StartDate IS NULL
SET @StartDate = '19000101';
IF @EndDate IS NULL
SET @EndDate = '99991231';
IF OBJECT_ID('tempdb..#deadlock_data') IS NOT NULL
DROP TABLE #deadlock_data;
IF OBJECT_ID('tempdb..#deadlock_process') IS NOT NULL
DROP TABLE #deadlock_process;
IF OBJECT_ID('tempdb..#deadlock_stack') IS NOT NULL
DROP TABLE #deadlock_stack;
IF OBJECT_ID('tempdb..#deadlock_resource') IS NOT NULL
DROP TABLE #deadlock_resource;
IF OBJECT_ID('tempdb..#deadlock_owner_waiter') IS NOT NULL
DROP TABLE #deadlock_owner_waiter;
IF OBJECT_ID('tempdb..#deadlock_findings') IS NOT NULL
DROP TABLE #deadlock_findings;
CREATE TABLE #deadlock_findings
(
id INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
check_id INT NOT NULL,
database_name NVARCHAR(256),
object_name NVARCHAR(1000),
finding_group NVARCHAR(100),
finding NVARCHAR(4000)
);
/*Grab the initial set of XML to parse*/
WITH xml
AS ( SELECT CONVERT(XML, event_data) AS deadlock_xml
FROM sys.fn_xe_file_target_read_file(@EventSessionPath, NULL, NULL, NULL) )
SELECT TOP ( @Top ) xml.deadlock_xml
INTO #deadlock_data
FROM xml
WHERE xml.deadlock_xml.value('(/event/@name)[1]', 'VARCHAR(256)') = 'xml_deadlock_report'
AND xml.deadlock_xml.value('(/event/@timestamp)[1]', 'datetime') >= @StartDate
AND xml.deadlock_xml.value('(/event/@timestamp)[1]', 'datetime') < @EndDate
ORDER BY xml.deadlock_xml.value('(/event/@timestamp)[1]', 'datetime')
OPTION ( RECOMPILE );
/*Parse process and input buffer XML*/
SELECT dd.deadlock_xml.value('(event/@timestamp)[1]', 'DATETIME2') AS event_date,
dd.deadlock_xml.value('(//deadlock/victim-list/victimProcess/@id)[1]', 'NVARCHAR(256)') AS victim_id,
ca.dp.value('@id', 'NVARCHAR(256)') AS id,
ca.dp.value('@currentdb', 'BIGINT') AS database_id,
ca.dp.value('@logused', 'BIGINT') AS log_used,
ca.dp.value('@waitresource', 'NVARCHAR(256)') AS wait_resource,
ca.dp.value('@waittime', 'BIGINT') AS wait_time,
ca.dp.value('@transactionname', 'NVARCHAR(256)') AS transaction_name,
ca.dp.value('@lasttranstarted', 'DATETIME2(7)') AS last_tran_started,
ca.dp.value('@lastbatchstarted', 'DATETIME2(7)') AS last_batch_started,
ca.dp.value('@lastbatchcompleted', 'DATETIME2(7)') AS last_batch_completed,
ca.dp.value('@lockMode', 'NVARCHAR(256)') AS lock_mode,
ca.dp.value('@trancount', 'BIGINT') AS transaction_count,
ca.dp.value('@clientapp', 'NVARCHAR(256)') AS client_app,
ca.dp.value('@hostname', 'NVARCHAR(256)') AS host_name,
ca.dp.value('@loginname', 'NVARCHAR(256)') AS login_name,
ca.dp.value('@isolationlevel', 'NVARCHAR(256)') AS isolation_level,
ca2.ib.query('.') AS input_buffer,
ca.dp.query('.') AS process_xml
INTO #deadlock_process
FROM #deadlock_data AS dd
CROSS APPLY dd.deadlock_xml.nodes('//deadlock/process-list/process') AS ca(dp)
CROSS APPLY dd.deadlock_xml.nodes('//deadlock/process-list/process/inputbuf') AS ca2(ib)
WHERE (ca.dp.value('@currentdb', 'BIGINT') = DB_ID(@DatabaseName) OR @DatabaseName IS NULL)
AND (ca.dp.value('@clientapp', 'NVARCHAR(256)') = @AppName OR @AppName IS NULL)
AND (ca.dp.value('@hostname', 'NVARCHAR(256)') = @HostName OR @HostName IS NULL)
AND (ca.dp.value('@loginname', 'NVARCHAR(256)') = @LoginName OR @LoginName IS NULL)
OPTION ( RECOMPILE );
/*Parse execution stack XML*/
SELECT dp.id,
dp.event_date,
ca.dp.value('@procname', 'NVARCHAR(1000)') AS proc_name,
ca.dp.value('@sqlhandle', 'NVARCHAR(128)') AS sql_handle
INTO #deadlock_stack
FROM #deadlock_process AS dp
CROSS APPLY dp.process_xml.nodes('//executionStack/frame') AS ca(dp)
WHERE (ca.dp.value('@procname', 'NVARCHAR(256)') = @StoredProcName OR @StoredProcName IS NULL)
OPTION ( RECOMPILE );
/*Grab the full resource list*/
SELECT dd.deadlock_xml.value('(event/@timestamp)[1]', 'DATETIME2') AS event_date,
dd.deadlock_xml.value('(//deadlock/victim-list/victimProcess/@id)[1]', 'NVARCHAR(256)') AS victim_id,
ca.dp.query('.') AS resource_xml
INTO #deadlock_resource
FROM #deadlock_data AS dd
CROSS APPLY dd.deadlock_xml.nodes('//deadlock/resource-list') AS ca(dp)
OPTION ( RECOMPILE );
/*This parses object locks*/
SELECT dr.event_date,
ca.dr.value('@dbid', 'BIGINT') AS database_id,
ca.dr.value('@objectname', 'NVARCHAR(1000)') AS object_name,
ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode,
w.l.value('@id', 'NVARCHAR(256)') AS waiter_id,
w.l.value('@mode', 'NVARCHAR(256)') AS waiter_mode,
o.l.value('@id', 'NVARCHAR(256)') AS owner_id,
o.l.value('@mode', 'NVARCHAR(256)') AS owner_mode
INTO #deadlock_owner_waiter
FROM #deadlock_resource AS dr
CROSS APPLY dr.resource_xml.nodes('//resource-list/objectlock') AS ca(dr)
CROSS APPLY ca.dr.nodes('//waiter-list/waiter') AS w(l)
CROSS APPLY ca.dr.nodes('//owner-list/owner') AS o(l)
WHERE (ca.dr.value('@objectname', 'NVARCHAR(1000)') = @ObjectName OR @ObjectName IS NULL)
OPTION ( RECOMPILE );
/*This parses page locks*/
INSERT #deadlock_owner_waiter
SELECT dr.event_date,
ca.dr.value('@dbid', 'BIGINT') AS database_id,
ca.dr.value('@objectname', 'NVARCHAR(256)') AS object_name,
ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode,
w.l.value('@id', 'NVARCHAR(256)') AS waiter_id,
w.l.value('@mode', 'NVARCHAR(256)') AS waiter_mode,
o.l.value('@id', 'NVARCHAR(256)') AS owner_id,
o.l.value('@mode', 'NVARCHAR(256)') AS owner_mode
FROM #deadlock_resource AS dr
CROSS APPLY dr.resource_xml.nodes('//resource-list/pagelock') AS ca(dr)
CROSS APPLY ca.dr.nodes('//waiter-list/waiter') AS w(l)
CROSS APPLY ca.dr.nodes('//owner-list/owner') AS o(l)
OPTION ( RECOMPILE );
/*This parses key locks*/
INSERT #deadlock_owner_waiter
SELECT dr.event_date,
ca.dr.value('@dbid', 'BIGINT') AS database_id,
ca.dr.value('@objectname', 'NVARCHAR(256)') AS object_name,
ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode,
w.l.value('@id', 'NVARCHAR(256)') AS waiter_id,
w.l.value('@mode', 'NVARCHAR(256)') AS waiter_mode,
o.l.value('@id', 'NVARCHAR(256)') AS owner_id,
o.l.value('@mode', 'NVARCHAR(256)') AS owner_mode
FROM #deadlock_resource AS dr
CROSS APPLY dr.resource_xml.nodes('//resource-list/keylock') AS ca(dr)
CROSS APPLY ca.dr.nodes('//waiter-list/waiter') AS w(l)
CROSS APPLY ca.dr.nodes('//owner-list/owner') AS o(l)
OPTION ( RECOMPILE );
/*This parses rid locks*/
INSERT #deadlock_owner_waiter
SELECT dr.event_date,
ca.dr.value('@dbid', 'BIGINT') AS database_id,
ca.dr.value('@objectname', 'NVARCHAR(256)') AS object_name,
ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode,
w.l.value('@id', 'NVARCHAR(256)') AS waiter_id,
w.l.value('@mode', 'NVARCHAR(256)') AS waiter_mode,
o.l.value('@id', 'NVARCHAR(256)') AS owner_id,
o.l.value('@mode', 'NVARCHAR(256)') AS owner_mode
FROM #deadlock_resource AS dr
CROSS APPLY dr.resource_xml.nodes('//resource-list/ridlock') AS ca(dr)
CROSS APPLY ca.dr.nodes('//waiter-list/waiter') AS w(l)
CROSS APPLY ca.dr.nodes('//owner-list/owner') AS o(l)
OPTION ( RECOMPILE );
/*Get rid of nonsense*/
DELETE dow
FROM #deadlock_owner_waiter AS dow
WHERE dow.owner_id = dow.waiter_id;
/*Add some nonsense*/
ALTER TABLE #deadlock_process
ADD waiter_mode NVARCHAR(256),
owner_mode NVARCHAR(256),
is_victim AS CONVERT(BIT, CASE WHEN id = victim_id THEN 1 ELSE 0 END);
/*Update some nonsense*/
UPDATE dp
SET dp.owner_mode = dow.owner_mode
FROM #deadlock_process AS dp
JOIN #deadlock_owner_waiter AS dow
ON dp.id = dow.owner_id
AND dp.event_date = dow.event_date
WHERE dp.is_victim = 0;
UPDATE dp
SET dp.waiter_mode = dow.waiter_mode
FROM #deadlock_process AS dp
JOIN #deadlock_owner_waiter AS dow
ON dp.victim_id = dow.waiter_id
AND dp.event_date = dow.event_date
WHERE dp.is_victim = 1;
/*Begin checks based on parsed values*/
/*Check 1 is deadlocks by database*/
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 1 AS check_id,
DB_NAME(dp.database_id) AS database_name,
'-' AS object_name,
'Total database locks' AS finding_group,
'This database had '
+ CONVERT(NVARCHAR(20), COUNT_BIG(DISTINCT dp.event_date))
+ ' deadlocks.'
FROM #deadlock_process AS dp
GROUP BY DB_NAME(dp.database_id)
OPTION ( RECOMPILE );
/*Check 2 is deadlocks by object*/
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 2 AS check_id,
DB_NAME(dow.database_id) AS database_name,
dow.object_name AS object_name,
'Total object deadlocks' AS finding_group,
'This object was involved in '
+ CONVERT(NVARCHAR(20), COUNT_BIG(DISTINCT dow.object_name))
+ ' deadlock(s).'
FROM #deadlock_owner_waiter AS dow
GROUP BY DB_NAME(dow.database_id), dow.object_name
OPTION ( RECOMPILE );
/*Check 3 looks for Serializable locking*/
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 3 AS check_id,
DB_NAME(dp.database_id) AS database_name,
'-' AS object_name,
'Serializable locking' AS finding_group,
'This database has had ' +
CONVERT(NVARCHAR(20), COUNT_BIG(*)) +
' instances of serializable deadlocks.'
AS finding
FROM #deadlock_process AS dp
WHERE dp.isolation_level LIKE 'serializable%'
GROUP BY DB_NAME(dp.database_id)
OPTION ( RECOMPILE );
/*Check 4 looks for Repeatable Read locking*/
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 4 AS check_id,
DB_NAME(dp.database_id) AS database_name,
'-' AS object_name,
'Repeatable Read locking' AS finding_group,
'This database has had ' +
CONVERT(NVARCHAR(20), COUNT_BIG(*)) +
' instances of repeatable read deadlocks.'
AS finding
FROM #deadlock_process AS dp
WHERE dp.isolation_level LIKE 'repeatable read%'
GROUP BY DB_NAME(dp.database_id)
OPTION ( RECOMPILE );
/*Check 5 breaks down app, host, and login information*/
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 5 AS check_id,
DB_NAME(dp.database_id) AS database_name,
'-' AS object_name,
'Login, App, and Host locking' AS finding_group,
'This database has had ' +
CONVERT(NVARCHAR(20), COUNT_BIG(DISTINCT dp.event_date)) +
' instances of deadlocks involving the login ' +
ISNULL(dp.login_name, 'UNKNOWN') +
' from the application ' +
ISNULL(dp.client_app, 'UNKNOWN') +
' on host ' +
ISNULL(dp.host_name, 'UNKNOWN')
AS finding
FROM #deadlock_process AS dp
GROUP BY DB_NAME(dp.database_id), dp.login_name, dp.client_app, dp.host_name
OPTION ( RECOMPILE );
/*Check 6 breaks down the types of locks (object, page, key, etc.)*/
WITH lock_types AS (
SELECT DB_NAME(dp.database_id) AS database_name,
dow.object_name,
SUBSTRING(dp.wait_resource, 1, CHARINDEX(':', dp.wait_resource) -1) AS lock,
CONVERT(NVARCHAR(20), COUNT_BIG(DISTINCT dp.id)) AS lock_count
FROM #deadlock_process AS dp
JOIN #deadlock_owner_waiter AS dow
ON dp.id = dow.owner_id
AND dp.event_date = dow.event_date
GROUP BY DB_NAME(dp.database_id), SUBSTRING(dp.wait_resource, 1, CHARINDEX(':', dp.wait_resource) - 1), dow.object_name
)
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT DISTINCT 6 AS check_id,
lt.database_name,
lt.object_name,
'Types of locks by object' AS finding_group,
'This object has had ' +
STUFF((SELECT DISTINCT N', ' + lt2.lock_count + ' ' + lt2.lock
FROM lock_types AS lt2
WHERE lt2.database_name = lt.database_name
AND lt2.object_name = lt.object_name
FOR XML PATH(N''), TYPE).value(N'.[1]', N'NVARCHAR(MAX)'), 1, 1, N'')
+ ' locks'
FROM lock_types AS lt
OPTION ( RECOMPILE );
/*Check 7 gives you more info queries for sp_BlitzCache & BlitzQueryStore*/
WITH deadlock_stack AS (
SELECT DISTINCT
ds.id,
ds.proc_name,
ds.event_date,
PARSENAME(ds.proc_name, 3) AS database_name,
PARSENAME(ds.proc_name, 2) AS schema_name,
PARSENAME(ds.proc_name, 1) AS proc_only_name,
'''' + STUFF((SELECT DISTINCT N',' + ds2.sql_handle
FROM #deadlock_stack AS ds2
WHERE ds2.id = ds.id
AND ds2.event_date = ds.event_date
FOR XML PATH(N''), TYPE).value(N'.[1]', N'NVARCHAR(MAX)'), 1, 1, N'') + '''' AS sql_handle_csv
FROM #deadlock_stack AS ds
GROUP BY PARSENAME(ds.proc_name, 3),
PARSENAME(ds.proc_name, 2),
PARSENAME(ds.proc_name, 1),
ds.id,
ds.proc_name,
ds.event_date
)
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT DISTINCT 7 AS check_id,
DB_NAME(dow.database_id) AS database_name,
ds.proc_name AS object_name,
'More Info - Query' AS finding_group,
'EXEC sp_BlitzCache ' +
CASE WHEN ds.proc_name = 'adhoc'
THEN ' @OnlySqlHandles = ' + sql_handle_csv
ELSE '@StoredProcName = ' +
QUOTENAME(ds.proc_only_name, '''')
END +
';' AS finding
FROM deadlock_stack AS ds
JOIN #deadlock_owner_waiter AS dow
ON dow.owner_id = ds.id
AND dow.event_date = ds.event_date
OPTION ( RECOMPILE );
IF @ProductVersionMajor >= 13
BEGIN
WITH deadlock_stack AS (
SELECT DISTINCT
ds.id,
ds.sql_handle,
ds.proc_name,
ds.event_date,
PARSENAME(ds.proc_name, 3) AS database_name,
PARSENAME(ds.proc_name, 2) AS schema_name,
PARSENAME(ds.proc_name, 1) AS proc_only_name
FROM #deadlock_stack AS ds
)
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT DISTINCT 7 AS check_id,
DB_NAME(dow.database_id) AS database_name,
ds.proc_name AS object_name,
'More Info - Query' AS finding_group,
'EXEC sp_BlitzQueryStore '
+ '@DatabaseName = '
+ QUOTENAME(ds.database_name, '''')
+ ', '
+ '@StoredProcName = '
+ QUOTENAME(ds.proc_only_name, '''')
+ ';' AS finding
FROM deadlock_stack AS ds
JOIN #deadlock_owner_waiter AS dow
ON dow.owner_id = ds.id
AND dow.event_date = ds.event_date
WHERE ds.proc_name <> 'adhoc'
OPTION ( RECOMPILE );
END;
/*Check 8 gives you stored proc deadlock counts*/
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 8 AS check_id,
DB_NAME(dp.database_id) AS database_name,
ds.proc_name,
'Stored Procedure Deadlocks',
'The stored procedure '
+ PARSENAME(ds.proc_name, 2)
+ '.'
+ PARSENAME(ds.proc_name, 1)
+ ' has been involved in '
+ CONVERT(NVARCHAR(10), COUNT_BIG(DISTINCT ds.id))
+ ' deadlocks.'
FROM #deadlock_stack AS ds
JOIN #deadlock_process AS dp
ON dp.id = ds.id
AND ds.event_date = dp.event_date
WHERE ds.proc_name <> 'adhoc'
GROUP BY DB_NAME(dp.database_id), ds.proc_name
OPTION(RECOMPILE);
/*Check 9 gives you more info queries for sp_BlitzIndex */
WITH bi AS (
SELECT DISTINCT
dow.object_name,
PARSENAME(dow.object_name, 3) AS database_name,
PARSENAME(dow.object_name, 2) AS schema_name,
PARSENAME(dow.object_name, 1) AS table_name
FROM #deadlock_owner_waiter AS dow
)
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 9 AS check_id,
bi.database_name,
bi.schema_name + '.' + bi.table_name,
'More Info - Table' AS finding_group,
'EXEC sp_BlitzIndex ' +
'@DatabaseName = ' + QUOTENAME(bi.database_name, '''') +
', @SchemaName = ' + QUOTENAME(bi.schema_name, '''') +
', @TableName = ' + QUOTENAME(bi.table_name, '''') +
';' AS finding
FROM bi
OPTION ( RECOMPILE );
/*Check 10 gets total deadlock wait time per object*/
WITH chopsuey AS (
SELECT DISTINCT
PARSENAME(dow.object_name, 3) AS database_name,
dow.object_name,
CONVERT(VARCHAR(10), (SUM(DISTINCT dp.wait_time) / 1000) / 86400) AS wait_days,
CONVERT(VARCHAR(20), DATEADD(SECOND, (SUM(DISTINCT dp.wait_time) / 1000), 0), 108) AS wait_time_hms
FROM #deadlock_owner_waiter AS dow
JOIN #deadlock_process AS dp
ON (dp.id = dow.owner_id OR dp.victim_id = dow.waiter_id)
AND dp.event_date = dow.event_date
GROUP BY PARSENAME(dow.object_name, 3), dow.object_name
)
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 10 AS check_id,
cs.database_name,
cs.object_name,
'Total object deadlock wait time' AS finding_group,
'This object has had '
+ CONVERT(VARCHAR(10), cs.wait_days)
+ ':' + CONVERT(VARCHAR(20), cs.wait_time_hms, 108)
+ ' [d/h/m/s] of deadlock wait time.' AS finding
FROM chopsuey AS cs
WHERE cs.object_name IS NOT NULL
OPTION ( RECOMPILE );
/*Check 11 gets total deadlock wait time per database*/
WITH wait_time AS (
SELECT DB_NAME(dp.database_id) AS database_name,
SUM(CONVERT(BIGINT, dp.wait_time)) AS total_wait_time_ms
FROM #deadlock_process AS dp
GROUP BY DB_NAME(dp.database_id)
)
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
SELECT 11 AS check_id,
wt.database_name,
'-' AS object_name,
'Total database deadlock wait time' AS finding_group,
'This database has had '
+ CONVERT(VARCHAR(10), (SUM(DISTINCT wt.total_wait_time_ms) / 1000) / 86400)
+ ':' + CONVERT(VARCHAR(20), DATEADD(SECOND, (SUM(DISTINCT wt.total_wait_time_ms) / 1000), 0), 108)
+ ' [d/h/m/s] of deadlock wait time.'
FROM wait_time AS wt
GROUP BY wt.database_name
OPTION ( RECOMPILE );
/*Thank you goodnight*/
INSERT #deadlock_findings ( check_id, database_name, object_name, finding_group, finding )
VALUES ( -1,
N'sp_BlitzLock ' + CAST(CONVERT(DATETIME, @VersionDate, 102) AS VARCHAR(100)),
N'SQL Server First Responder Kit',
N'http://FirstResponderKit.org/',
N'To get help or add your own contributions, join us at http://FirstResponderKit.org.');
/*Results*/
WITH deadlocks
AS ( SELECT dp.event_date,
dp.id,
dp.victim_id,
dp.database_id,
dp.log_used,
dp.wait_resource,
CONVERT(
XML,
STUFF(( SELECT DISTINCT NCHAR(10)
+ N' <object>'
+ ISNULL(c.object_name, N'')
+ N'</object> ' AS object_name
FROM #deadlock_owner_waiter AS c
WHERE (dp.id = c.owner_id
OR dp.victim_id = c.waiter_id)
AND dp.event_date = c.event_date
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1, 1, N'')) AS object_names,
dp.wait_time,
dp.transaction_name,
dp.last_tran_started,
dp.last_batch_started,
dp.last_batch_completed,
dp.lock_mode,
dp.transaction_count,
dp.client_app,
dp.host_name,
dp.login_name,
dp.isolation_level,
dp.process_xml.value('(//process/inputbuf/text())[1]', 'NVARCHAR(MAX)') AS inputbuf,
ROW_NUMBER() OVER ( PARTITION BY dp.event_date, dp.id ORDER BY dp.event_date ) AS dn,
DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en,
ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn,
dp.is_victim,
ISNULL(dp.owner_mode, '-') AS owner_mode,
ISNULL(dp.waiter_mode, '-') AS waiter_mode
FROM #deadlock_process AS dp )
SELECT d.event_date,
DB_NAME(d.database_id) AS database_name,
'Deadlock #'
+ CONVERT(NVARCHAR(10), d.en)
+ ', Query #'
+ CASE WHEN d.qn = 0 THEN N'1' ELSE CONVERT(NVARCHAR(10), d.qn) END
+ CASE WHEN d.is_victim = 1 THEN ' - VICTIM' ELSE '' END
AS deadlock_group,
CONVERT(XML, N'<inputbuf>' + d.inputbuf + N'</inputbuf>') AS query,
d.object_names,
d.isolation_level,
d.owner_mode,
d.waiter_mode,
d.transaction_count,
d.login_name,
d.host_name,
d.client_app,
d.wait_time,
d.log_used,
d.last_tran_started,
d.last_batch_started,
d.last_batch_completed,
d.transaction_name
FROM deadlocks AS d
WHERE d.dn = 1
ORDER BY d.event_date, is_victim DESC;
SELECT df.check_id, df.database_name, df.object_name, df.finding_group, df.finding
FROM #deadlock_findings AS df
ORDER BY df.check_id
OPTION ( RECOMPILE );
IF @Debug = 1
BEGIN
SELECT '#deadlock_data' AS table_name, *
FROM #deadlock_data AS dd
OPTION ( RECOMPILE );
SELECT '#deadlock_resource' AS table_name, *
FROM #deadlock_resource AS dr
OPTION ( RECOMPILE );
SELECT '#deadlock_owner_waiter' AS table_name, *
FROM #deadlock_owner_waiter AS dow
OPTION ( RECOMPILE );
SELECT '#deadlock_process' AS table_name, *
FROM #deadlock_process AS dp
OPTION ( RECOMPILE );
SELECT '#deadlock_stack' AS table_name, *
FROM #deadlock_stack AS ds
OPTION ( RECOMPILE );
END; -- End debug
END; --Final End
GO