Vous êtes ici :
Une procédure pour afficher de manière lisible les block process reports que l’on aura capturé avec une session d’évènements étendus (appelée pour cet exemple « LocksReporting ».
Cette procédure présente une vue en clair des arborescences de verrous relevées depuis un nombre d’heure (paramètre). Elle fonctionne avec les dernières versions de SQL Server (2019, 2022) et nécessite des modifications pour fonctionner avec des versions antérieures.
Transact-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 |
CREATE OR ALTER PROC dbo.sp_blocked_process_report_viewer ( @Trace NVARCHAR(MAX) = 'LocksReporting' ,@Hours INT = 24 ) AS -- prepare tables DROP TABLE IF EXISTS #ReportsXML; CREATE TABLE #ReportsXML ( monitorloop NVARCHAR(100) NOT NULL , endTime DATETIME NULL , dbName NVARCHAR(128) NULL , blocking_spid INT NULL , blocking_ecid INT NULL , blocked_spid INT NOT NULL , blocked_ecid INT NOT NULL , blocked_hierarchy_string AS CAST(blocked_spid AS VARCHAR(20)) + '.' + CAST(blocked_ecid AS VARCHAR(20)) + '/' , blocking_hierarchy_string AS CAST(blocking_spid AS VARCHAR(20)) + '.' + CAST(blocking_ecid AS VARCHAR(20)) + '/' , bpReportXml XML NOT NULL , PRIMARY KEY CLUSTERED ( monitorloop , blocked_spid , blocked_ecid ) , UNIQUE NONCLUSTERED ( monitorloop , blocking_spid , blocking_ecid , blocked_spid , blocked_ecid ) ); DROP TABLE IF EXISTS #LockChain; CREATE TABLE #LockChain ( traceTime nvarchar(30) NOT NULL, blockingTree varchar(8000) NULL, XactId nvarchar(4000) NULL, ProcessStatus nvarchar(45) NULL, DBName nvarchar(128) NULL, SQLBuffer varchar(5000) NULL, BlockedResource nvarchar(45) NULL, BlockedLock nvarchar(45) NULL, Host nvarchar(45) NULL, Login nvarchar(45) NULL, AppName nvarchar(100) NULL, IsolationLevel nvarchar(45) NULL, bpReportXml xml NULL, monitorloop nvarchar(100) NULL, chain varchar(max) NULL ); DROP TABLE IF EXISTS #BlockedResources CREATE TABLE #BlockedResources ( BlockedResource nvarchar(45) NULL, --SchemaName sysname NULL, PossibleObjectName sysname NULL, PossibleIndexName sysname NULL); -- read bpr ------------------------------------------ WITH BPR AS (SELECT CONVERT(XML, event_data) AS EventData FROM sys.fn_xe_file_target_read_file(@Trace+'*.xel', NULL, NULL, NULL) WHERE CAST(timestamp_utc AS DATETIME2(7)) >= DATEADD(HOUR, -@Hours, GETUTCDATE())) -- WHERE CONVERT(XML, event_data).value('(event/@timestamp)1', 'datetime') >= DATEADD(HOUR, -24, GETUTCDATE())) --< SQL 2017 INSERT #ReportsXML ( blocked_ecid , blocked_spid , blocking_ecid , blocking_spid , monitorloop , bpReportXml , endTime , dbName ) SELECT EventData.value( '(event/data@name="blocked_process"/value/blocked-process-report/blocked-process/process/@ecid)1' , 'nvarchar(100)' ) AS blocked_ecid , EventData.value( '(event/data@name="blocked_process"/value/blocked-process-report/blocked-process/process/@spid)1' , 'nvarchar(100)' ) AS blocked_spid , EventData.value( '(event/data@name="blocked_process"/value/blocked-process-report/blocking-process/process/@ecid)1' , 'nvarchar(100)' ) AS blocking_ecid , EventData.value( '(event/data@name="blocked_process"/value/blocked-process-report/blocking-process/process/@spid)1' , 'nvarchar(100)' ) AS blocking_spid , EventData.value( '(event/data@name="blocked_process"/value/blocked-process-report//@monitorLoop)1' , 'nvarchar(100)' ) AS MonitorLoop , EventData.query('(event/data@name="blocked_process"/value/blocked-process-report)1') AS bpReportXml , DATEADD(hh, DATEDIFF(hh, GETUTCDATE(), CURRENT_TIMESTAMP), EventData.value('(event/@timestamp)1', 'datetime')) AS EndTime , EventData.value('(event/data@name="database_name"/value)1', 'nvarchar(128)') AS DBName FROM BPR; -- recursive block chain ----------------------- WITH Blockheads AS (SELECT blocking_spid , blocking_ecid , monitorloop , blocking_hierarchy_string FROM #ReportsXML EXCEPT SELECT blocked_spid , blocked_ecid , monitorloop , blocked_hierarchy_string FROM #ReportsXML) , Hierarchy AS (SELECT monitorloop , blocking_spid AS spid , blocking_ecid AS ecid , CAST('/' + blocking_hierarchy_string AS VARCHAR(MAX)) AS chain , 0 AS level FROM Blockheads UNION ALL SELECT irx.monitorloop , irx.blocked_spid , irx.blocked_ecid , CAST(h.chain + irx.blocked_hierarchy_string AS VARCHAR(MAX)) , h.level + 1 FROM #ReportsXML irx JOIN Hierarchy h ON irx.monitorloop = h.monitorloop AND irx.blocking_spid = h.spid AND irx.blocking_ecid = h.ecid) -- Store lockchain for decode INSERT #LockChain (traceTime ,blockingTree ,XactId ,ProcessStatus ,DBName ,SQLBuffer ,BlockedResource ,BlockedLock ,Host ,Login ,AppName ,IsolationLevel ,bpReportXml ,monitorloop ,chain ) SELECT ISNULL(CONVERT(NVARCHAR(30), irx.endTime, 120), 'Lead') AS traceTime , SPACE(4 * h.level) + CAST(h.spid AS VARCHAR(20)) + CASE h.ecid WHEN 0 THEN '' ELSE '(' + CAST(h.ecid AS VARCHAR(20)) + ')' END AS blockingTree , SPACE(4 * h.level) + COALESCE(Y.x.value('@xactid', 'nvarchar(45)'), X.x.value('@xactid', 'nvarchar(45)')) XactId , COALESCE(Y.x.value('@status', 'nvarchar(45)'), X.x.value('@status', 'nvarchar(45)')) ProcessStatus , COALESCE(irx.dbName, irx2.dbName) AS DBName , COALESCE(Y.x.value('data(.)', 'varchar(5000)'), X.x.value('data(.)', 'varchar(5000)')) AS SQLBuffer , X.x.value('@waitresource', 'nvarchar(45)') BlockedResource , X.x.value('@lockMode', 'nvarchar(45)') BlockedLock , COALESCE(Y.x.value('@hostname', 'nvarchar(45)'), X.x.value('@hostname', 'nvarchar(45)')) AS Host , COALESCE(Y.x.value('@loginname', 'nvarchar(45)'), X.x.value('@loginname', 'nvarchar(45)')) AS Login , COALESCE(Y.x.value('@clientapp', 'nvarchar(100)'), X.x.value('@clientapp', 'nvarchar(100)')) AS AppName , COALESCE(Y.x.value('@isolationlevel', 'nvarchar(45)'), X.x.value('@isolationlevel', 'nvarchar(45)')) AS IsolationLevel , irx.bpReportXml , h.monitorloop , h.chain FROM Hierarchy h LEFT JOIN #ReportsXML irx CROSS APPLY bpReportXml.nodes('blocked-process-report/blocked-process/process') AS X(x) ON irx.monitorloop = h.monitorloop AND irx.blocked_spid = h.spid AND irx.blocked_ecid = h.ecid LEFT JOIN #ReportsXML irx2 CROSS APPLY bpReportXml.nodes('blocked-process-report/blocking-process/process') AS Y(x) ON irx2.monitorloop = h.monitorloop AND irx2.blocking_spid = h.spid AND irx2.blocking_ecid = h.ecid -- Decode object names INSERT #BlockedResources (BlockedResource) SELECT DISTINCT BlockedResource FROM #LockChain WHERE BlockedResource IS NOT NULL UPDATE #BlockedResources SET PossibleObjectName = CASE WHEN LEFT(BlockedResource, CHARINDEX(':', BlockedResource) - 1) = 'OBJECT' THEN ( SELECT OBJECT_NAME( ( SELECT value FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) rn , LTRIM(value) AS value FROM STRING_SPLIT(BlockedResource, ':') ) rs WHERE rn = 3 ) , ( SELECT value FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) rn , LTRIM(value) AS value FROM STRING_SPLIT(BlockedResource, ':') ) rs WHERE rn = 2 ) ) ) WHEN LEFT(BlockedResource, CHARINDEX(':', BlockedResource) - 1) IN ( 'PAGE', 'RID' ) THEN ( SELECT OBJECT_NAME(object_id, database_id) FROM sys.dm_db_page_info( ( SELECT value FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) rn , LTRIM(value) AS value FROM STRING_SPLIT(BlockedResource, ':') ) rs WHERE rn = 2 ) , ( SELECT value FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) rn , LTRIM(value) AS value FROM STRING_SPLIT(BlockedResource, ':') ) rs WHERE rn = 3 ) , ( SELECT value FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) rn , LTRIM(value) AS value FROM STRING_SPLIT(BlockedResource, ':') ) rs WHERE rn = 4 ) , N'LIMITED' ) ) ELSE NULL END; DECLARE @key VARCHAR(100), @hobt VARCHAR(100), @db INT, @sql NVARCHAR(MAX) DECLARE @objid INT, @indexid INT, @objectname sysname, @indexname sysname ,@schemaname sysname DECLARE KeyCursor INSENSITIVE CURSOR FOR SELECT BlockedResource FROM #BlockedResources WHERE BlockedResource LIKE 'KEY%' OPEN KeyCursor; FETCH NEXT FROM KeyCursor INTO @key; WHILE (@@FETCH_STATUS >= 0) BEGIN SET @db = ( SELECT value FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) rn , LTRIM(value) AS value FROM STRING_SPLIT(@key, ':') ) rs WHERE rn = 2 ); SET @hobt = ( SELECT SUBSTRING(value , 0 , CHARINDEX('(' , ( SELECT value FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) rn , LTRIM(value) AS value FROM STRING_SPLIT(@key, ':') ) rs WHERE rn = 3 ) ) - 1 ) FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) rn , LTRIM(value) AS value FROM STRING_SPLIT(@key, ':') ) rs WHERE rn = 3 ); SET @sql = 'SELECT @objid = i.object_id , @indexid = i.index_id , @objectname = o.name , @indexname = i.name , @schemaname = SCHEMA_NAME(schema_id) FROM ' + DB_NAME(@db) + '.sys.partitions p JOIN ' + DB_NAME(@db) + '.sys.objects o ON p.object_id = o.object_id JOIN ' + DB_NAME(@db) + '.sys.indexes i ON p.object_id = i.object_id AND p.index_id = i.index_id WHERE p.hobt_id = '+ @hobt ; EXEC sp_executesql @sql, N'@objid INT OUT, @indexid INT OUT, @objectname sysname OUT, @indexname sysname OUT ,@schemaname sysname OUT', @objid OUT, @indexid OUT, @objectname OUT, @indexname OUT, @schemaname OUT; UPDATE #BlockedResources SET PossibleObjectName = @objectname, PossibleIndexName = @indexname WHERE BlockedResource = @key FETCH NEXT FROM KeyCursor INTO @key; END; CLOSE KeyCursor; DEALLOCATE KeyCursor; -- show results SELECT traceTime , blockingTree , XactId , ProcessStatus , DBName , SQLBuffer , C.BlockedResource , R.PossibleObjectName , R.PossibleIndexName , BlockedLock , Host , Login , AppName , IsolationLevel , bpReportXml , monitorloop , chain FROM #LockChain C LEFT JOIN #BlockedResources R ON C.BlockedResource = R.BlockedResource ORDER BY monitorloop DESC , chain; GO |
Table of Contents