Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

System-health extended-event session does not capture latest deadlocks Expand / Collapse
Author
Message
Posted Friday, December 21, 2012 4:04 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: 2 days ago @ 8:53 AM
Points: 1,861, Visits: 3,599
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' );



__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1399315
Posted Friday, December 21, 2012 5:12 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:48 AM
Points: 7,094, Visits: 12,581
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
Post #1399344
Posted Tuesday, March 5, 2013 3:32 PM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Yesterday @ 12:52 PM
Points: 72, Visits: 393
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!
Post #1427060
Posted Thursday, July 18, 2013 2:19 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: 2 days ago @ 8:53 AM
Points: 1,861, Visits: 3,599
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];



__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1475215
Posted Wednesday, August 14, 2013 12:41 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, December 26, 2013 1:14 PM
Points: 2, Visits: 41
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?

Post #1484456
Posted Thursday, August 15, 2013 7:38 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: 2 days ago @ 8:53 AM
Points: 1,861, Visits: 3,599
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?


__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1484761
Posted Thursday, August 15, 2013 7:51 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, December 26, 2013 1:14 PM
Points: 2, Visits: 41
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
Post #1484770
Posted Thursday, August 15, 2013 8:49 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: 2 days ago @ 8:53 AM
Points: 1,861, Visits: 3,599
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.


__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1484799
Posted Friday, August 16, 2013 3:00 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: 2 days ago @ 8:53 AM
Points: 1,861, Visits: 3,599
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...


__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1485040
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse