From 3b96469ff811fd4a0cd6cb7400927adcd413d464 Mon Sep 17 00:00:00 2001 From: Filip Cornelissen Date: Sat, 4 Jul 2020 22:37:21 +0200 Subject: [PATCH 1/2] get the associatedObjectId from XML and use it to find the table and schema name. --- sp_BlitzLock.sql | 32 ++++++++++++++++++++++++++------ 1 file changed, 26 insertions(+), 6 deletions(-) diff --git a/sp_BlitzLock.sql b/sp_BlitzLock.sql index 03389680d..601e0075a 100644 --- a/sp_BlitzLock.sql +++ b/sp_BlitzLock.sql @@ -418,6 +418,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.object_name, ca.lock_mode, ca.index_name, + ca.associatedObjectId, 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, @@ -430,6 +431,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.dr.value('@objectname', 'NVARCHAR(256)') AS object_name, ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode, ca.dr.value('@indexname', 'NVARCHAR(256)') AS index_name, + ca.dr.value('@associatedObjectId', 'BIGINT') AS associatedObjectId, ca.dr.query('.') AS dr FROM #deadlock_resource AS dr CROSS APPLY dr.resource_xml.nodes('//resource-list/objectlock') AS ca(dr) @@ -451,6 +453,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.object_name, ca.lock_mode, ca.index_name, + ca.associatedObjectId, 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, @@ -462,6 +465,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.dr.value('@objectname', 'NVARCHAR(256)') AS object_name, ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode, ca.dr.value('@indexname', 'NVARCHAR(256)') AS index_name, + ca.dr.value('@associatedObjectId', 'BIGINT') AS associatedObjectId, ca.dr.query('.') AS dr FROM #deadlock_resource AS dr CROSS APPLY dr.resource_xml.nodes('//resource-list/pagelock') AS ca(dr) @@ -481,6 +485,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.object_name, ca.lock_mode, ca.index_name, + ca.associatedObjectId, 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, @@ -492,6 +497,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.dr.value('@objectname', 'NVARCHAR(256)') AS object_name, ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode, ca.dr.value('@indexname', 'NVARCHAR(256)') AS index_name, + ca.dr.value('@associatedObjectId', 'BIGINT') AS associatedObjectId, ca.dr.query('.') AS dr FROM #deadlock_resource AS dr CROSS APPLY dr.resource_xml.nodes('//resource-list/keylock') AS ca(dr) @@ -511,6 +517,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.object_name, ca.lock_mode, ca.index_name, + ca.associatedObjectId, 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, @@ -522,6 +529,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.dr.value('@objectname', 'NVARCHAR(256)') AS object_name, ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode, ca.dr.value('@indexname', 'NVARCHAR(256)') AS index_name, + ca.dr.value('@associatedObjectId', 'BIGINT') AS associatedObjectId, ca.dr.query('.') AS dr FROM #deadlock_resource AS dr CROSS APPLY dr.resource_xml.nodes('//resource-list/ridlock') AS ca(dr) @@ -541,6 +549,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.object_name, ca.lock_mode, ca.index_name, + ca.associatedObjectId, 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, @@ -552,6 +561,7 @@ You need to use an Azure storage account, and the path has to look like this: ht ca.dr.value('@objectname', 'NVARCHAR(256)') AS object_name, ca.dr.value('@mode', 'NVARCHAR(256)') AS lock_mode, ca.dr.value('@indexname', 'NVARCHAR(256)') AS index_name, + ca.dr.value('@associatedObjectId', 'BIGINT') AS associatedObjectId, ca.dr.query('.') AS dr FROM #deadlock_resource AS dr CROSS APPLY dr.resource_xml.nodes('//resource-list/rowgrouplock') AS ca(dr) @@ -727,6 +737,15 @@ You need to use an Azure storage account, and the path has to look like this: ht AND dp.id = aj.id OPTION ( RECOMPILE ); + /*Get each and every table of all databases*/ + DECLARE @sysAssObjId AS TABLE (database_id bigint, partition_id bigint, schema_name varchar(255), table_name varchar(255)); + INSERT into @sysAssObjId EXECUTE sp_ineachdb @COMMAND = + N'SELECT DB_ID() as database_id, p.partition_id, s.name as schema_name, t.name as table_name + FROM sys.partitions p + LEFT JOIN sys.tables t ON t.object_id = p.object_id + LEFT JOIN sys.schemas s ON s.schema_id = t.schema_id + WHERE s.name is not NULL AND t.name is not NULL'; + /*Begin checks based on parsed values*/ /*Check 1 is deadlocks by database*/ @@ -1065,23 +1084,24 @@ You need to use an Azure storage account, and the path has to look like this: ht RAISERROR('Check 9 %s', 0, 1, @d) WITH NOWAIT; 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 + dow.object_name, + DB_NAME(dow.database_id) as database_name, + a.schema_name AS schema_name, + a.table_name AS table_name FROM #deadlock_owner_waiter AS dow + LEFT JOIN @sysAssObjId a ON a.database_id=dow.database_id AND a.partition_id = dow.associatedObjectId WHERE 1 = 1 AND (DB_NAME(dow.database_id) = @DatabaseName OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) AND dow.object_name IS NOT NULL - ) + ) INSERT #deadlock_findings WITH (TABLOCKX) ( check_id, database_name, object_name, finding_group, finding ) SELECT 9 AS check_id, bi.database_name, - bi.schema_name + '.' + bi.table_name, + bi.object_name, 'More Info - Table' AS finding_group, 'EXEC sp_BlitzIndex ' + '@DatabaseName = ' + QUOTENAME(bi.database_name, '''') + From 72282186712f0e3f373ca9a30c5b953920a1d077 Mon Sep 17 00:00:00 2001 From: Filip Cornelissen Date: Mon, 13 Jul 2020 16:02:32 +0200 Subject: [PATCH 2/2] Changed sp_ineachdb into sp_MSforeachdb --- sp_BlitzLock.sql | 6 ++++-- 1 file changed, 4 insertions(+), 2 deletions(-) diff --git a/sp_BlitzLock.sql b/sp_BlitzLock.sql index 3393a5569..c56677b62 100644 --- a/sp_BlitzLock.sql +++ b/sp_BlitzLock.sql @@ -739,13 +739,15 @@ You need to use an Azure storage account, and the path has to look like this: ht /*Get each and every table of all databases*/ DECLARE @sysAssObjId AS TABLE (database_id bigint, partition_id bigint, schema_name varchar(255), table_name varchar(255)); - INSERT into @sysAssObjId EXECUTE sp_ineachdb @COMMAND = - N'SELECT DB_ID() as database_id, p.partition_id, s.name as schema_name, t.name as table_name + INSERT into @sysAssObjId EXECUTE sp_MSforeachdb + N'USE [?]; + SELECT DB_ID() as database_id, p.partition_id, s.name as schema_name, t.name as table_name FROM sys.partitions p LEFT JOIN sys.tables t ON t.object_id = p.object_id LEFT JOIN sys.schemas s ON s.schema_id = t.schema_id WHERE s.name is not NULL AND t.name is not NULL'; + /*Begin checks based on parsed values*/ /*Check 1 is deadlocks by database*/