Skip to content

Commit 4ed2a6e

Browse files
authored
Merge pull request #2825 from erikdarlingdata/2800_2824
Update sp_BlitzLock.sql
2 parents f39639b + 8fc2bd1 commit 4ed2a6e

File tree

1 file changed

+118
-63
lines changed

1 file changed

+118
-63
lines changed

sp_BlitzLock.sql

Lines changed: 118 additions & 63 deletions
Original file line numberDiff line numberDiff line change
@@ -735,6 +735,7 @@ You need to use an Azure storage account, and the path has to look like this: ht
735735
) AS step_id
736736
FROM #deadlock_process AS dp
737737
WHERE dp.client_app LIKE 'SQLAgent - %'
738+
AND dp.client_app <> 'SQLAgent - Initial Boot Probe'
738739
) AS x
739740
OPTION ( RECOMPILE );
740741

@@ -1288,18 +1289,18 @@ You need to use an Azure storage account, and the path has to look like this: ht
12881289
dp.priority,
12891290
dp.log_used,
12901291
dp.wait_resource COLLATE DATABASE_DEFAULT AS wait_resource,
1291-
CONVERT(
1292-
XML,
1293-
STUFF(( SELECT DISTINCT NCHAR(10)
1292+
CONVERT(
1293+
XML,
1294+
STUFF(( SELECT DISTINCT NCHAR(10)
12941295
+ N' <object>'
12951296
+ ISNULL(c.object_name, N'')
12961297
+ N'</object> ' COLLATE DATABASE_DEFAULT AS object_name
1297-
FROM #deadlock_owner_waiter AS c
1298+
FROM #deadlock_owner_waiter AS c
12981299
WHERE ( dp.id = c.owner_id
1299-
OR dp.victim_id = c.waiter_id )
1300-
AND CONVERT(DATE, dp.event_date) = CONVERT(DATE, c.event_date)
1301-
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1302-
1, 1, N'')) AS object_names,
1300+
OR dp.victim_id = c.waiter_id )
1301+
AND dp.event_date = c.event_date
1302+
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1303+
1, 1, N'')) AS object_names,
13031304
dp.wait_time,
13041305
dp.transaction_name,
13051306
dp.last_tran_started,
@@ -1312,7 +1313,6 @@ You need to use an Azure storage account, and the path has to look like this: ht
13121313
dp.login_name,
13131314
dp.isolation_level,
13141315
dp.process_xml.value('(//process/inputbuf/text())[1]', 'NVARCHAR(MAX)') AS inputbuf,
1315-
ROW_NUMBER() OVER ( PARTITION BY dp.event_date, dp.id ORDER BY dp.event_date ) AS dn,
13161316
DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en,
13171317
ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn,
13181318
dp.is_victim,
@@ -1345,20 +1345,18 @@ You need to use an Azure storage account, and the path has to look like this: ht
13451345
dp.priority,
13461346
dp.log_used,
13471347
dp.wait_resource COLLATE DATABASE_DEFAULT,
1348-
CASE WHEN @ExportToExcel = 0 THEN
1349-
CONVERT(
1350-
XML,
1351-
STUFF(( SELECT DISTINCT NCHAR(10)
1352-
+ N' <object>'
1353-
+ ISNULL(c.object_name, N'')
1354-
+ N'</object> ' COLLATE DATABASE_DEFAULT AS object_name
1355-
FROM #deadlock_owner_waiter AS c
1356-
WHERE ( dp.id = c.owner_id
1357-
OR dp.victim_id = c.waiter_id )
1358-
AND CONVERT(DATE, dp.event_date) = CONVERT(DATE, c.event_date)
1359-
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1360-
1, 1, N''))
1361-
ELSE NULL END AS object_names,
1348+
CONVERT(
1349+
XML,
1350+
STUFF(( SELECT DISTINCT NCHAR(10)
1351+
+ N' <object>'
1352+
+ ISNULL(c.object_name, N'')
1353+
+ N'</object> ' COLLATE DATABASE_DEFAULT AS object_name
1354+
FROM #deadlock_owner_waiter AS c
1355+
WHERE ( dp.id = c.owner_id
1356+
OR dp.victim_id = c.waiter_id )
1357+
AND dp.event_date = c.event_date
1358+
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1359+
1, 1, N'')) AS object_names,
13621360
dp.wait_time,
13631361
dp.transaction_name,
13641362
dp.last_tran_started,
@@ -1371,7 +1369,6 @@ You need to use an Azure storage account, and the path has to look like this: ht
13711369
dp.login_name,
13721370
dp.isolation_level,
13731371
dp.process_xml.value('(//process/inputbuf/text())[1]', 'NVARCHAR(MAX)') AS inputbuf,
1374-
ROW_NUMBER() OVER ( PARTITION BY dp.event_date, dp.id ORDER BY dp.event_date ) AS dn,
13751372
DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en,
13761373
ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn,
13771374
1 AS is_victim,
@@ -1473,7 +1470,7 @@ You need to use an Azure storage account, and the path has to look like this: ht
14731470
FROM deadlocks AS d
14741471
WHERE d.dn = 1
14751472
AND (is_victim = @VictimsOnly OR @VictimsOnly = 0)
1476-
AND d.en < CASE WHEN d.deadlock_type = N'Parallel Deadlock' THEN 2 ELSE 2147483647 END
1473+
AND d.qn < CASE WHEN d.deadlock_type = N'Parallel Deadlock' THEN 2 ELSE 2147483647 END
14771474
AND (DB_NAME(d.database_id) = @DatabaseName OR @DatabaseName IS NULL)
14781475
AND (d.event_date >= @StartDate OR @StartDate IS NULL)
14791476
AND (d.event_date < @EndDate OR @EndDate IS NULL)
@@ -1513,20 +1510,18 @@ ELSE --Output to database is not set output to client app
15131510
dp.priority,
15141511
dp.log_used,
15151512
dp.wait_resource COLLATE DATABASE_DEFAULT AS wait_resource,
1516-
CASE WHEN @ExportToExcel = 0 THEN
1517-
CONVERT(
1518-
XML,
1519-
STUFF(( SELECT DISTINCT NCHAR(10)
1520-
+ N' <object>'
1521-
+ ISNULL(c.object_name, N'')
1522-
+ N'</object> ' COLLATE DATABASE_DEFAULT AS object_name
1523-
FROM #deadlock_owner_waiter AS c
1524-
WHERE ( dp.id = c.owner_id
1525-
OR dp.victim_id = c.waiter_id )
1526-
AND CONVERT(DATE, dp.event_date) = CONVERT(DATE, c.event_date)
1527-
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1528-
1, 1, N''))
1529-
ELSE NULL END AS object_names,
1513+
CONVERT(
1514+
XML,
1515+
STUFF(( SELECT DISTINCT NCHAR(10)
1516+
+ N' <object>'
1517+
+ ISNULL(c.object_name, N'')
1518+
+ N'</object> ' COLLATE DATABASE_DEFAULT AS object_name
1519+
FROM #deadlock_owner_waiter AS c
1520+
WHERE ( dp.id = c.owner_id
1521+
OR dp.victim_id = c.waiter_id )
1522+
AND dp.event_date = c.event_date
1523+
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1524+
1, 1, N'')) AS object_names,
15301525
dp.wait_time,
15311526
dp.transaction_name,
15321527
dp.last_tran_started,
@@ -1539,7 +1534,6 @@ ELSE --Output to database is not set output to client app
15391534
dp.login_name,
15401535
dp.isolation_level,
15411536
dp.process_xml.value('(//process/inputbuf/text())[1]', 'NVARCHAR(MAX)') AS inputbuf,
1542-
ROW_NUMBER() OVER ( PARTITION BY dp.event_date, dp.id ORDER BY dp.event_date ) AS dn,
15431537
DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en,
15441538
ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn,
15451539
dp.is_victim,
@@ -1572,20 +1566,18 @@ ELSE --Output to database is not set output to client app
15721566
dp.priority,
15731567
dp.log_used,
15741568
dp.wait_resource COLLATE DATABASE_DEFAULT,
1575-
CASE WHEN @ExportToExcel = 0 THEN
1576-
CONVERT(
1577-
XML,
1578-
STUFF(( SELECT DISTINCT NCHAR(10)
1579-
+ N' <object>'
1580-
+ ISNULL(c.object_name, N'')
1581-
+ N'</object> ' COLLATE DATABASE_DEFAULT AS object_name
1582-
FROM #deadlock_owner_waiter AS c
1583-
WHERE ( dp.id = c.owner_id
1584-
OR dp.victim_id = c.waiter_id )
1585-
AND CONVERT(DATE, dp.event_date) = CONVERT(DATE, c.event_date)
1586-
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1587-
1, 1, N''))
1588-
ELSE NULL END AS object_names,
1569+
CONVERT(
1570+
XML,
1571+
STUFF(( SELECT DISTINCT NCHAR(10)
1572+
+ N' <object>'
1573+
+ ISNULL(c.object_name, N'')
1574+
+ N'</object> ' COLLATE DATABASE_DEFAULT AS object_name
1575+
FROM #deadlock_owner_waiter AS c
1576+
WHERE ( dp.id = c.owner_id
1577+
OR dp.victim_id = c.waiter_id )
1578+
AND dp.event_date = c.event_date
1579+
FOR XML PATH(N''), TYPE ).value(N'.[1]', N'NVARCHAR(4000)'),
1580+
1, 1, N'')) AS object_names,
15891581
dp.wait_time,
15901582
dp.transaction_name,
15911583
dp.last_tran_started,
@@ -1598,7 +1590,6 @@ ELSE --Output to database is not set output to client app
15981590
dp.login_name,
15991591
dp.isolation_level,
16001592
dp.process_xml.value('(//process/inputbuf/text())[1]', 'NVARCHAR(MAX)') AS inputbuf,
1601-
ROW_NUMBER() OVER ( PARTITION BY dp.event_date, dp.id ORDER BY dp.event_date ) AS dn,
16021593
DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en,
16031594
ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn,
16041595
1 AS is_victim,
@@ -1631,8 +1622,8 @@ ELSE --Output to database is not set output to client app
16311622
+ CASE WHEN d.qn = 0 THEN N'1' ELSE CONVERT(NVARCHAR(10), d.qn) END
16321623
+ CASE WHEN d.is_victim = 1 THEN ' - VICTIM' ELSE '' END
16331624
AS deadlock_group,
1634-
CASE WHEN @ExportToExcel = 0 THEN CONVERT(XML, N'<inputbuf><![CDATA[' + d.inputbuf + N']]></inputbuf>')
1635-
ELSE SUBSTRING(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(LTRIM(RTRIM(d.inputbuf)),' ','<>'),'><',''),NCHAR(10), ' '),NCHAR(13), ' '),'<>',' '), 1, 32000) END AS query,
1625+
CONVERT(XML, N'<inputbuf><![CDATA[' + d.inputbuf + N']]></inputbuf>') AS query_xml,
1626+
d.inputbuf AS query_string,
16361627
d.object_names,
16371628
d.isolation_level,
16381629
d.owner_mode,
@@ -1661,21 +1652,81 @@ ELSE --Output to database is not set output to client app
16611652
d.waiter_merging,
16621653
d.waiter_spilling,
16631654
d.waiter_waiting_to_close,
1664-
CASE WHEN @ExportToExcel = 0 THEN d.deadlock_graph ELSE NULL END AS deadlock_graph
1665-
FROM deadlocks AS d
1655+
d.deadlock_graph,
1656+
d.is_victim
1657+
INTO #deadlock_results
1658+
FROM deadlocks AS d
16661659
WHERE d.dn = 1
1667-
AND (is_victim = @VictimsOnly OR @VictimsOnly = 0)
1668-
AND d.en < CASE WHEN d.deadlock_type = N'Parallel Deadlock' THEN 2 ELSE 2147483647 END
1660+
AND (d.is_victim = @VictimsOnly OR @VictimsOnly = 0)
1661+
AND d.qn < CASE WHEN d.deadlock_type = N'Parallel Deadlock' THEN 2 ELSE 2147483647 END
16691662
AND (DB_NAME(d.database_id) = @DatabaseName OR @DatabaseName IS NULL)
16701663
AND (d.event_date >= @StartDate OR @StartDate IS NULL)
16711664
AND (d.event_date < @EndDate OR @EndDate IS NULL)
16721665
AND (CONVERT(NVARCHAR(MAX), d.object_names) LIKE '%' + @ObjectName + '%' OR @ObjectName IS NULL)
16731666
AND (d.client_app = @AppName OR @AppName IS NULL)
16741667
AND (d.host_name = @HostName OR @HostName IS NULL)
16751668
AND (d.login_name = @LoginName OR @LoginName IS NULL)
1676-
ORDER BY d.event_date, is_victim DESC
16771669
OPTION ( RECOMPILE );
16781670

1671+
1672+
DECLARE @deadlock_result NVARCHAR(MAX) = N''
1673+
1674+
SET @deadlock_result += N'
1675+
SELECT
1676+
dr.deadlock_type,
1677+
dr.event_date,
1678+
dr.database_name,
1679+
dr.deadlock_group,
1680+
'
1681+
+ CASE @ExportToExcel
1682+
WHEN 1
1683+
THEN N'dr.query_string AS query,
1684+
REPLACE(REPLACE(CONVERT(NVARCHAR(MAX), dr.object_names), ''<object>'', ''''), ''</object>'', '''') AS object_names,'
1685+
ELSE N'dr.query_xml AS query,
1686+
dr.object_names,'
1687+
END +
1688+
N'
1689+
dr.isolation_level,
1690+
dr.owner_mode,
1691+
dr.waiter_mode,
1692+
dr.transaction_count,
1693+
dr.login_name,
1694+
dr.host_name,
1695+
dr.client_app,
1696+
dr.wait_time,
1697+
dr.priority,
1698+
dr.log_used,
1699+
dr.last_tran_started,
1700+
dr.last_batch_started,
1701+
dr.last_batch_completed,
1702+
dr.transaction_name,
1703+
dr.owner_waiter_type,
1704+
dr.owner_activity,
1705+
dr.owner_waiter_activity,
1706+
dr.owner_merging,
1707+
dr.owner_spilling,
1708+
dr.owner_waiting_to_close,
1709+
dr.waiter_waiter_type,
1710+
dr.waiter_owner_activity,
1711+
dr.waiter_waiter_activity,
1712+
dr.waiter_merging,
1713+
dr.waiter_spilling,
1714+
dr.waiter_waiting_to_close'
1715+
+ CASE @ExportToExcel
1716+
WHEN 1
1717+
THEN N''
1718+
ELSE N',
1719+
dr.deadlock_graph'
1720+
END +
1721+
'
1722+
FROM #deadlock_results AS dr
1723+
ORDER BY dr.event_date, dr.is_victim DESC
1724+
OPTION(RECOMPILE);
1725+
'
1726+
1727+
EXEC sys.sp_executesql
1728+
@deadlock_result;
1729+
16791730
SET @d = CONVERT(VARCHAR(40), GETDATE(), 109);
16801731
RAISERROR('Findings %s', 0, 1, @d) WITH NOWAIT;
16811732
SELECT df.check_id, df.database_name, df.object_name, df.finding_group, df.finding
@@ -1715,7 +1766,11 @@ ELSE --Output to database is not set output to client app
17151766
SELECT '#deadlock_stack' AS table_name, *
17161767
FROM #deadlock_stack AS ds
17171768
OPTION ( RECOMPILE );
1718-
1769+
1770+
SELECT '#deadlock_results' AS table_name, *
1771+
FROM #deadlock_results AS dr
1772+
OPTION ( RECOMPILE );
1773+
17191774
END; -- End debug
17201775

17211776
END; --Final End

0 commit comments

Comments
 (0)