Extracting Deadlock information using SYSTEM_HEALTH Extended Events

, 2017-10-12 (first published: )

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 .

Rate

Share

Share

Rate

Related content

Database Mirroring FAQ: Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup?

Question: Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup? This question was sent to me via email. My reply follows. Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup? Databases to be mirrored are currently running on 2005 SQL instances but will be upgraded to 2008 SQL in the near future.

2009-02-23

1,567 reads

Networking - Part 4

You may want to read Part 1 , Part 2 , and Part 3 before continuing. This time around I'd like to talk about social networking. We'll start with social networking. Facebook, MySpace, and Twitter are all good examples of using technology to let...

2009-02-17

1,530 reads

Speaking at Community Events - More Thoughts

Last week I posted Speaking at Community Events - Time to Raise the Bar?, a first cut at talking about to what degree we should require experience for speakers at events like SQLSaturday as well as when it might be appropriate to add additional focus/limitations on the presentations that are accepted. I've got a few more thoughts on the topic this week, and I look forward to your comments.

2009-02-13

360 reads