It’s easy to query XEvents to see some of the basic info in deadlocks, including the system_health session which is already capturing this information by default.
This script will, by default, read from system_health. However, change the name of one parameter at the start to have it read from any active session. I pull the file name automatically, so the session has to be active to avoid many changes to the script.
The Script
DECLARE @SessionName SysName SELECT @SessionName = 'system_health' /* SELECT Session_Name = s.name, s.blocked_event_fire_time, s.dropped_buffer_count, s.dropped_event_count, s.pending_buffers FROM sys.dm_xe_session_targets t INNER JOIN sys.dm_xe_sessions s ON s.address = t.event_session_address WHERE target_name = 'event_file' --*/IF OBJECT_ID('tempdb..#Events') IS NOT NULL BEGIN DROP TABLE #Events END DECLARE @Target_File NVarChar(1000) , @Target_Dir NVarChar(1000) , @Target_File_WildCard NVarChar(1000) SELECT @Target_File = CAST(t.target_data as XML).value('EventFileTarget[1]/File[1]/@name', 'NVARCHAR(256)') FROM sys.dm_xe_session_targets t INNER JOIN sys.dm_xe_sessions s ON s.address = t.event_session_address WHERE s.name = @SessionName AND t.target_name = 'event_file' SELECT @Target_Dir = LEFT(@Target_File, Len(@Target_File) - CHARINDEX('', REVERSE(@Target_File))) SELECT @Target_File_WildCard = @Target_Dir + '' + @SessionName + '_*.xel' --Keep this as a separate table because it's called twice in the next query. You don't want this running twice. SELECT DeadlockGraph = CAST(event_data AS XML) , DeadlockID = Row_Number() OVER(ORDER BY file_name, file_offset) INTO #Events FROM sys.fn_xe_file_target_read_file(@Target_File_WildCard, null, null, null) AS F WHERE event_data like '<event name="xml_deadlock_report%' ;WITH Victims AS ( SELECT VictimID = Deadlock.Victims.value('@id', 'varchar(50)') , e.DeadlockID FROM #Events e CROSS APPLY e.DeadlockGraph.nodes('/event/data/value/deadlock/victim-list/victimProcess') as Deadlock(Victims) ) , DeadlockObjects AS ( SELECT DISTINCT e.DeadlockID , ObjectName = Deadlock.Resources.value('@objectname', 'nvarchar(256)') FROM #Events e CROSS APPLY e.DeadlockGraph.nodes('/event/data/value/deadlock/resource-list/*') as Deadlock(Resources) ) SELECT * FROM ( SELECT e.DeadlockID , TransactionTime = Deadlock.Process.value('@lasttranstarted', 'datetime') , DeadlockGraph , DeadlockObjects = substring((SELECT (', ' + o.ObjectName) FROM DeadlockObjects o WHERE o.DeadlockID = e.DeadlockID ORDER BY o.ObjectName FOR XML PATH ('') ), 3, 4000) , Victim = CASE WHEN v.VictimID IS NOT NULL THEN 1 ELSE 0 END , SPID = Deadlock.Process.value('@spid', 'int') , ProcedureName = Deadlock.Process.value('executionStack[1]/frame[1]/@procname[1]', 'varchar(200)') , LockMode = Deadlock.Process.value('@lockMode', 'char(1)') , Code = Deadlock.Process.value('executionStack[1]/frame[1]', 'varchar(1000)') , ClientApp = CASE LEFT(Deadlock.Process.value('@clientapp', 'varchar(100)'), 29) WHEN 'SQLAgent - TSQL JobStep (Job ' THEN 'SQLAgent Job: ' + (SELECT name FROM msdb..sysjobs sj WHERE substring(Deadlock.Process.value('@clientapp', 'varchar(100)'),32,32)=(substring(sys.fn_varbintohexstr(sj.job_id),3,100))) + ' - ' + SUBSTRING(Deadlock.Process.value('@clientapp', 'varchar(100)'), 67, len(Deadlock.Process.value('@clientapp', 'varchar(100)'))-67) ELSE Deadlock.Process.value('@clientapp', 'varchar(100)') END , HostName = Deadlock.Process.value('@hostname', 'varchar(20)') , LoginName = Deadlock.Process.value('@loginname', 'varchar(20)') , InputBuffer = Deadlock.Process.value('inputbuf[1]', 'varchar(1000)') FROM #Events e CROSS APPLY e.DeadlockGraph.nodes('/event/data/value/deadlock/process-list/process') as Deadlock(Process) LEFT JOIN Victims v ON v.DeadlockID = e.DeadlockID AND v.VictimID = Deadlock.Process.value('@id', 'varchar(50)') ) X --In a subquery to make filtering easier (use column names, not XML parsing), no other reason ORDER BY DeadlockID DESC
System_health session
The system_health XEvent by default is turned on, captures deadlocks, and is limited to four 5MB files. You can change all three of those, but it’s not common for people to do that.
Yes, you’re limited to more recent events, but the information is there. If you find the limitations are too much, you have a couple options that should be considered in this order.
- Is anything else capturing deadlocks? For me, I have Idera Diagnostic Manager capturing deadlocks as well for my production servers. This is my main source of looking at deadlocks, so I actually rarely use system_health for this purpose in production. The first goal is to avoid doing anything additional.
- Consider setting system_health to use bigger files (not too big) or have more rollover files. The more you do the more resources it will take to read it all at once, so don’t go crazy. However, if you have 5 days of data when you wish you had 7, it’s not horrible to double the size of data you retain. The second goal is to increase disk usage before you add more overhead.
- Consider a separate XEvent session. Ugh…I wish I didn’t have to throw this out there as an option. Love your servers, don’t add more overhead if you don’t have to. The last resort is to not end up here at your last resort.
Idera Diagnostic Manager
At the time of me writing this, I have a script to look at all of the deadlocks in Idera DM that I use quite regularly for my production servers. However, they just came out with a new major version and I want to make sure my query runs there before posting my script publically. If you don’t care and just want the script, email me.
Viewing the Deadlock
The details of this script give you a great overview of the deadlock. You know the code involved on each side, the tables and applications involved, etc. It’s enough to look for trends, know if a deadlock was one you expected, and other basics.
However, this is just a summary list of your recent deadlocks, it’s not the details. For me, I’m very happy just looking at the XML output to see the details. This is how I look at it from XEvents and my monitoring software. That makes me odd, and I’m ok with that.
Jonathan Kehayias (b|t) talks about viewing them in SQL Sentry Plan Explorer Pro in his post Graphically Viewing Extended Events Deadlock Graphs. There’s no single right answer on how to view deadlocks, so do what works best for you.
Troubleshooting Deadlocks
This topic goes well beyond what I’m going for in this post. Jonathan Kehayias gets into it some in his post The Accidental DBA (Day 29 of 30): Troubleshooting Deadlocks, which is just a start. The book he co-authored with Ted Krueger (b|t), Troubleshooting SQL Server – A Guide for the Accidental DBA, is available as a free PDF and has an entire chapter on this subject.