Retrieving Deadlock Graphs with SQL Server 2008 Extended Events

  • Comments posted to this topic are about the item Retrieving Deadlock Graphs with SQL Server 2008 Extended Events

    Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
    My Blog | Twitter | MVP Profile
    Training | Consulting | Become a SQLskills Insider
    Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]

  • nice article.

    Is the deadlock info persisted after server/sql service restart.

    "Keep Trying"

  • Great question. Unfortunately, the answer is no. Since the ring_buffer target is memory resident, it does not persist the information after restart. You can however, alter the system_health session and add a asyncronous_file_target to it which will log the information to a file on disk which will survive service restarts.

    Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
    My Blog | Twitter | MVP Profile
    Training | Consulting | Become a SQLskills Insider
    Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]

  • Can you alter the default system_health default session?

  • Jonathan Kehayias (2/23/2009)


    You can however, alter the system_health session and add a asyncronous_file_target to it which will log the information to a file on disk which will survive service restarts.

    As I covered in my first response, yes you can alter the default system_health session, though beyond adding a file target, I personally wouldn't change it, I would instead create a new session to handle whatever events I am interested in looking at. You can also drop it if you don't want it to exist at all. If you mess it up, you won't be capturing the information that the CSS team may want in troubleshooting a problem which may cause delays in your support case if they request that you recreate the system_health session from script.

    The script that created this session is located in the InstallPath\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\Install folder in the u_tables.sql file. It is at the very bottom of the file. So if you do play with this session and screw it up, you can fix it by running the script from that file.

    Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
    My Blog | Twitter | MVP Profile
    Training | Consulting | Become a SQLskills Insider
    Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]

  • okay, thanks

  • Hi,

    you can use SQL Agent with WMI alert to capture and log deadlocks it works beautifully in SQL2005 and hope should work in SQL2008 see http://msdn.microsoft.com/en-us/library/ms186385.aspx for more details.

    Rama Mathanmohan

  • rama.mathanmohan (2/23/2009)


    Hi,

    you can use SQL Agent with WMI alert to capture and log deadlocks it works beautifully in SQL2005 and hope should work in SQL2008 see http://msdn.microsoft.com/en-us/library/ms186385.aspx for more details.

    Rama Mathanmohan

    WMI alerts are still there, but you have to turn them on, and they have a considerable cost when compared with Extended Events and the system_health session which is running by default. The cost to fire an event in Extended Events is 2 thousands of a millisecond (2us) which is insignificant when compared with the 2-3% CPU cost for the WMI deadlock monitor. The difference is that the event is buffered to the ring_buffer target asynchronously as the event fires instead of having to be read from the WMI Eventing and then processed by triggering a job. There is also consider problems with setting up WMI alerts in some environments for varying reasons. You can search the Administering forum on here and find a number of people having WMI namespace problems configuring the alerts like the following:

    "The @wmi_query could not be executed in the @wmi_namespace provided. Verify that an event class selected in the query exists in the namespace and that the query has the correct syntax."

    Extended Events are the future of troubleshooting SQL Server, so if you are on SQL Server 2008, I'd advise to utilize it over an older construct like WMI Alerts, Trace Flags, or Profiler Traces, all of which I have written about previously. They were all good methods of doing things in SQL 2005, but they don't compare to Extended Events in SQL 2008.

    Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
    My Blog | Twitter | MVP Profile
    Training | Consulting | Become a SQLskills Insider
    Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]

  • Jonathan Kehayias (2/23/2009)


    Great question. Unfortunately, the answer is no. Since the ring_buffer target is memory resident, it does not persist the information after restart. You can however, alter the system_health session and add a asyncronous_file_target to it which will log the information to a file on disk which will survive service restarts.

    Thankyou

    "Keep Trying"

  • I have and had quite a few issues with SQL Server integration with WMI especially with the Configuration Tools, so I am at the point that I think that regardless what might be the issues, the implementation of WMI is just unstable. To use WMI for anything would be a hard sale for me.

  • When I run your query on my server.... it never finishes! 🙂

    I have let it run for up to 13 minutes... still nothing.

    ----------

    select CAST(

    REPLACE(

    REPLACE(XEventData.XEvent.value('(data/value)[1]', 'varchar(max)'),

    '<victim-list>', '<deadlock><victim-list>'),

    '<process-list>','</victim-list><process-list>')

    as xml) as DeadlockGraph

    FROM

    (select CAST(target_data as xml) as TargetData

    from sys.dm_xe_session_targets st

    join sys.dm_xe_sessions s on s.address = st.event_session_address

    where name = 'system_health') AS Data

    CROSS APPLY TargetData.nodes ('//RingBufferTarget/event') AS XEventData (XEvent)

    where XEventData.XEvent.value('@name', 'varchar(4000)') = 'xml_deadlock_report'

    -----------

    When I run it against my dev server, it completes quickly, but with no results.

    Am I missing something obvious here or some additional step I need to attend to?

    Thank you

  • You probably have a lot of events in the ring_buffer target that is causing the XML parsing to be slow. What is the output of SELECT @@VERSION on the server, and how big is the XML document in the target_data?

    Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
    My Blog | Twitter | MVP Profile
    Training | Consulting | Become a SQLskills Insider
    Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]

  • Looking at the XQuery code a year later, I do see that there are some things that are not necessarily written well. Try this one out:

    select CAST(

    REPLACE(

    REPLACE(XEventData.XEvent.value('(data/value)[1]', 'varchar(max)'),

    '<victim-list>', '<deadlock><victim-list>'),

    '<process-list>','</victim-list><process-list>')

    as xml) as DeadlockGraph

    FROM

    (select CAST(target_data as xml) as TargetData

    from sys.dm_xe_session_targets st

    join sys.dm_xe_sessions s on s.address = st.event_session_address

    where name = 'system_health') AS Data

    CROSS APPLY TargetData.nodes ('RingBufferTarget/event[@name="xml_deadlock_report"]') AS XEventData (XEvent)

    If that doesn't quite get it, try pulling the target_data into a xml variable and then working off of that:

    declare @xml xml

    select @xml = target_data

    from sys.dm_xe_session_targets

    join sys.dm_xe_sessions on event_session_address = address

    where name = 'system_health'

    select CAST(

    REPLACE(

    REPLACE(XEventData.XEvent.value('(data/value)[1]', 'varchar(max)'),

    '<victim-list>', '<deadlock><victim-list>'),

    '<process-list>','</victim-list><process-list>')

    as xml) as DeadlockGraph

    FROM

    (select @xml as TargetData) AS Data

    CROSS APPLY TargetData.nodes ('RingBufferTarget/event[@name="xml_deadlock_report"]') AS XEventData (XEvent)

    Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
    My Blog | Twitter | MVP Profile
    Training | Consulting | Become a SQLskills Insider
    Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]

  • Thank you, that second set of queries executed almost immediately!

    It looks like they return zero rows though, so if I understand that correctly it means there have been no deadlocks since our last server restart?

  • Not necessarily, it means that there are none in the current data in the ring_buffer target. The ring_buffer is a in memory target and works in a FIFO manner once the 4MB of buffer space is full. Depending on how much data is in there it could mean that none have occured, I can't really tell you without seeing it.

    Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
    My Blog | Twitter | MVP Profile
    Training | Consulting | Become a SQLskills Insider
    Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]

Viewing 15 posts - 1 through 15 (of 83 total)

You must be logged in to reply to this topic. Login to reply