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!!

5 thoughts on “Extracting Deadlock information using SYSTEM_HEALTH Extended Events

  • John Byars

    Hi,

    If the extended event is created in the default location sys.fn_xe_file_target_read_file works without the full path of the file, just the file name is required.

    This works fine;

    SELECT
    XEvent.value(‘(@timestamp)[1]’, ‘datetime’) as UTC_event_time,
    XEvent.query(‘(data/value/deadlock)’) AS deadlock_graph
    FROM
    (
    SELECT CAST(event_data AS XML) as [target_data]
    FROM sys.fn_xe_file_target_read_file(‘system_health_*.xel’,NULL,NULL,NULL)
    WHERE object_name like ‘xml_deadlock_report’
    ) AS [x]
    CROSS APPLY target_data.nodes(‘/event’) AS XEventData(XEvent)

    I’ve also created user sessions in the default location and can return the contents of those files without specifying the full path.

    If you wanted the paths to the files you could try something like this;

    SELECT es.name, ISNULL(cfn.CurrentFileName, ‘Not Running’) AS CurrentFileName, REPLACE(CAST(esf.value AS VARCHAR(256)), ‘.xel’, ‘*.xel’) AS FilePath
    FROM sys.server_event_sessions es
    INNER JOIN sys.server_event_session_fields esf ON es.event_session_id = esf.event_session_id
    LEFT JOIN ( SELECT s.name, CAST( t.target_data AS XML ).value(‘(EventFileTarget/File/@name)[1]’, ‘VARCHAR(MAX)’) AS CurrentFileName
    FROM sys.dm_xe_sessions s
    LEFT JOIN sys.dm_xe_session_targets t ON s.address = t.event_session_address
    WHERE t.target_name = ‘event_file’) cfn
    ON es.name = cfn.name
    WHERE esf.name = ‘filename’

    Reply
  • Dharmendra Keshari

    Hi John, Thank you so much for sharing this! I never notice that it can be done this way too. This is a great learning for….

    Reply
  • koti reddy

    Hi Dharmendra,

    Then their is no need of enabling the trace flags 1204 and 1222 ? above query will retrieves even if we do not enable mentioned trace flags?

    Reply
    • Dharmendra

      Yes, from SQL Server 2012, the “system heath” extended events by default captures the health of system ( includes, CPU, memory and deadlock, IO, etc) every 5 minutes. I don’t see any use to enable the trace flag 1204 and 1222 on the server unless you want to capture the deadlock data separately….

      Reply
      • koti reddy

        thanks for confirmation Dharmendra:)

        Reply

Leave a comment

Your email address will not be published. Required fields are marked *