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


System-health extended-event session does not capture latest deadlocks


System-health extended-event session does not capture latest deadlocks

Author
Message
Marios Philippopoulos
Marios Philippopoulos
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4484 Visits: 3755
While running the following query to capture the latest deadlocks recorded in the default system-health extended-event session, I noticed that the latest deadlock captured was 3 days ago. However, in the SQL ERRORLOG I see that several deadlocks have occurred as recently as today.

Has anyone else noticed this issue?


--http://www.quest.com/whitepaper/how-to-use-sql-servers-extended-events-and-notifications816315.aspx

;WITH SystemHealth
AS (
SELECT
CAST ( target_data AS xml ) AS SessionXML
FROM
sys.dm_xe_session_targets st
INNER JOIN
sys.dm_xe_sessions s
ON
s.[address] = st.event_session_address
WHERE
name = 'system_health'
)
SELECT
Deadlock.value ( '@timestamp', 'datetime' ) AS DeadlockDateTime
, CAST ( Deadlock.value ( '(data/value)[1]', 'Nvarchar(max)' ) AS XML ) AS DeadlockGraph
FROM
SystemHealth s
CROSS APPLY
SessionXML.nodes ( '//RingBufferTarget/event' ) AS t (Deadlock)
WHERE
Deadlock.value ( '@name', 'nvarchar(128)' ) = N'xml_deadlock_report'
ORDER BY
Deadlock.value ( '@timestamp', 'datetime' );



__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Orlando Colamatteo
Orlando Colamatteo
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14839 Visits: 14396
I have not seen deadlock events in the system_health session that I thought should have been there. The session is setup to 'allow single event loss' so it's possible that is the reason but I never tracked it down fully.

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
SQLSalas
SQLSalas
SSC-Enthusiastic
SSC-Enthusiastic (168 reputation)SSC-Enthusiastic (168 reputation)SSC-Enthusiastic (168 reputation)SSC-Enthusiastic (168 reputation)SSC-Enthusiastic (168 reputation)SSC-Enthusiastic (168 reputation)SSC-Enthusiastic (168 reputation)SSC-Enthusiastic (168 reputation)

Group: General Forum Members
Points: 168 Visits: 593
I am seeing this same issue. I was trying to evaluate to make a switch from using Event Notification and going through Extended Events due to the "multiple-victim" scenario that seems to be happening in our environment. However, I don't get the same amount of deadlocks and the last deadlock in the extended events happened more than a day ago.

It seems that the scenario you are seeing is the same that I am facing right now, have you ever find out what could the issue be?

Thanks a lot!
Marios Philippopoulos
Marios Philippopoulos
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4484 Visits: 3755
SQLSalas (3/5/2013)
I am seeing this same issue. I was trying to evaluate to make a switch from using Event Notification and going through Extended Events due to the "multiple-victim" scenario that seems to be happening in our environment. However, I don't get the same amount of deadlocks and the last deadlock in the extended events happened more than a day ago.

It seems that the scenario you are seeing is the same that I am facing right now, have you ever find out what could the issue be?

Thanks a lot!


Still no luck - I'm thinking of opening a case with MS on this.

Here is a similar query with the same issue:


--https://www.simple-talk.com/sql/database-administration/handling-deadlocks-in-sql-server/
select
DeadlockGraph
, [DbId] = DeadlockGraph.value ( '(/deadlock/resource-list//@dbid)[1]', 'int' )
, [DbName] = DB_NAME ( DeadlockGraph.value ( '(/deadlock/resource-list//@dbid)[1]', 'int' ) )
, [LastTranStarted] = DeadlockGraph.value ( '(/deadlock/process-list/process/@lasttranstarted)[1]', 'datetime' )
from
(
SELECT
CAST ( event_data.value ( '(event/data/value)[1]', 'varchar(max)' ) AS XML ) AS DeadlockGraph
FROM
(
SELECT
XEvent.query('.') AS event_data
FROM
( -- Cast the target_data to XML
SELECT
CAST( st.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'
AND target_name = 'ring_buffer'
) AS Data
CROSS APPLY -- Split out the Event Nodes
TargetData.nodes ( 'RingBufferTarget/event[@name="xml_deadlock_report"]' ) AS XEventData ( XEvent )
) AS tab ( event_data )
) AS A
ORDER BY [LastTranStarted];



__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
mthumphrey
mthumphrey
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 52
I just figured out that I am having this same issue. the system_health EE session has fewer deadlock events that what is logged by trace flags 1204, 1222.

Has anyone got more info on this?
Marios Philippopoulos
Marios Philippopoulos
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4484 Visits: 3755
mthumphrey (8/14/2013)
I just figured out that I am having this same issue. the system_health EE session has fewer deadlock events that what is logged by trace flags 1204, 1222.

Has anyone got more info on this?



I've opened a case with Microsoft, and I have gotten them to admit this is an issue.
They told me that they recommend me using the ERRORLOG info for troubleshooting deadlocks, but I am not letting them off the hook so easily. There is real value in being able to track this info programmatically and save it in a table for historic analysis, and doing that from the ERRORLOG just doesn't cut it. Besides, what is the use of the system_health session then, if it is not reliable? Might as well not have it running at all!

So I'm trying to get them to escalate this as a bug to their dev team.
Waiting to hear back...

Are you also seeing progressively newer deadlocks appearing on a day-by-day basis, but always a few days behind the current date?
It's as if the info is all in memory but the process writing to the system_health output is very slow and is not able to catch up.

Also, what version of SQL are you running?

__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
mthumphrey
mthumphrey
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 52
It's almost like the system_health EE session has stopped collecting deadlock events on this particular server. The last one i have is 5 days ago. Meanwhile, with the trace flags set, I've had a couple each day in the SQL Error log, the latest was just a few hours ago.

I agree this is a major disappointment. Extended events are great, but if you aren't confident you're capturing all the info, they become useless. I might try to set up a separate EE session that only collects deadlock events, just to see what it does.

Have you opened a Connect case with Microsoft? If so, let me know the ID and I will +1. I'm having this issue on 2008R2. I wonder if it is still an issue in 2012.

Thanks
-Matt
Marios Philippopoulos
Marios Philippopoulos
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4484 Visits: 3755
mthumphrey (8/15/2013)
It's almost like the system_health EE session has stopped collecting deadlock events on this particular server. The last one i have is 5 days ago. Meanwhile, with the trace flags set, I've had a couple each day in the SQL Error log, the latest was just a few hours ago.

I agree this is a major disappointment. Extended events are great, but if you aren't confident you're capturing all the info, they become useless. I might try to set up a separate EE session that only collects deadlock events, just to see what it does.

Have you opened a Connect case with Microsoft? If so, let me know the ID and I will +1. I'm having this issue on 2008R2. I wonder if it is still an issue in 2012.

Thanks
-Matt


The funny thing is, progressively later deadlocks do appear eventually on the system_health xml, so the info is somewhere in the system, just not recorded in the system_health quickly enough. So it is not as if the events are lost, more that the updating of the system_health ring_buffer repository is not current/fast enough. At least that is my observation.

I have never opened a connect item with MS before; will try to find out how, but I am currently in the process of a support case with them anyway. Will update this thread when I have more news.

I was looking at this on a SQL-2012 instance yesterday; in sql 2012 system_health has 2 targets by default: ring_buffer (memory) and a file target (.xel file in the ERRORLOG folder). Perhaps it is better extracting this info from the file target? (but there might be the same issue there.)

Not sure if this issue is version-specific, but so far I have found it to be an issue mostly on SQL-2008 servers.

__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Marios Philippopoulos
Marios Philippopoulos
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4484 Visits: 3755
There has already been a connect item on this - opened last year:

https://connect.microsoft.com/SQLServer/feedback/details/754115/xevents-system-health-does-not-catch-all-deadlocks#tabs

It was closed with no resolution though, as far as I can tell...

__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Simon Elms-339567
Simon Elms-339567
Forum Newbie
Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)

Group: General Forum Members
Points: 7 Visits: 39
Jonathan Kehayias has an useful blog post about what is causing this problem:

https://www.sqlskills.com/blogs/jonathan/why-i-hate-the-ring_buffer-target-in-extended-events/

It doesn't give any solutions but it does explain why it's happening.

tl;dr: The missing events may still exist in memory but cannot be displayed because the size of the XML output is limited to 4 MB. Looks like it's the most recent events that are left out. Presumably as new events are added and older ones removed, the "missing" events move down the list and eventually become visible.

This would be why there appears to be a two or three day delay in seeing the deadlock details.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search