SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 

Extracting Deadlock information using SYSTEM_HEALTH Extended Events

Extended Events is a powerful feature that was introduced into SQL Server 2008 and onwards. It keeps historical system health information of the SQL Server instance. Today, we are going to explore how quickly we can read the Deadlock information using Extended Event – “Without passing the default location of the extended events trace files”

The system_health extended events session can be a gold mine for researching deadlocks and many issues.

We can directly query to SYSTEM_HEALTH trace .XEL files using the sys.fn_xe_file_target_read_file function to retrieve the deadlock information.

SELECT 
	CONVERT(xml, event_data).query('/event/data/value/child::*'),
	CONVERT(xml, event_data).value('(event[@name="xml_deadlock_report"]/@timestamp)[1]','datetime') 
	AS Execution_Time
FROM 
sys.fn_xe_file_target_read_file
('C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16DEV01\MSSQL\Log\system_health*.xel', null, null, null)
WHERE object_name like 'xml_deadlock_report'

But the problem with above query, you need to keep changing the location, if you are going to run it on the different – different servers as the path (C:\Program Files\…..)  may not be the same. To avoid this issue, you can run the below script;

Extracting Deadlock information without keying the path

CREATE TABLE #errorlog (
						LogDate DATETIME 
						, ProcessInfo VARCHAR(100)
						, [Text] VARCHAR(MAX)
						);

DECLARE @tag VARCHAR (MAX) , @path VARCHAR(MAX);

INSERT INTO #errorlog EXEC sp_readerrorlog;

SELECT @tag = text
FROM #errorlog 
WHERE [Text] LIKE 'Logging%MSSQL\Log%';

DROP TABLE #errorlog;

SET @path = SUBSTRING(@tag, 38, CHARINDEX('MSSQL\Log', @tag) - 29);

SELECT 
	CONVERT(xml, event_data).query('/event/data/value/child::*') AS DeadlockReport,
	CONVERT(xml, event_data).value('(event[@name="xml_deadlock_report"]/@timestamp)[1]', 'datetime') 
	AS Execution_Time
FROM sys.fn_xe_file_target_read_file(@path + '\system_health*.xel', NULL, NULL, NULL)
WHERE OBJECT_NAME like 'xml_deadlock_report';

It will give you output like this. To further analyze the deadlock, just click on the deadlock report link.

Happy Learning!!

The post Extracting Deadlock information using SYSTEM_HEALTH Extended Events appeared first on .

SQL Geek

Dharmendra is a SQL Server/Microsoft Data Platform professional with over eight years of experience. He enjoys helping others in the SQL Server community and does this by contributing on blogs, speaking at several SQL events. His passion and focus is to explore and share more and more on SQL Server.

Comments

Leave a comment on the original post [www.dharmendrakeshari.com, opens in a new window]

Loading comments...