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

What queries are getting blocked?

Monday Grant Fritchey (b/t) put up a great post EXTENDED EVENTS, THE SYSTEM_HEALTH SESSION, AND WAITS that talks about how the system health extended event session pulls, among other things, queries that have to wait for more than 30 seconds for a resource. He shows us how to pull the XML information out of the system health session but decided to leave the XML parsing to someone else. As it happens I’ve had a couple of requests for this type of information so, well, here’s my attempt.

SELECT 
	xed.event_data.value('(@timestamp)[1]', 'datetime2') AS [timestamp],
	xed.event_data.value('(data[@name="wait_type"]/text)[1]', 'varchar(25)') AS wait_type, 
	xed.event_data.value('(data[@name="duration"]/value)[1]', 'int')/1000/60.0 AS wait_time_in_min, 
	xed.event_data.value('(action[@name="sql_text"]/value)[1]', 'varchar(max)') AS sql_text, 
	xed.event_data.value('(action[@name="session_id"]/value)[1]', 'varchar(25)') AS session_id, 
	xData.Event_Data,
	fx.object_name
FROM sys.fn_xe_file_target_read_file ('system_health*.xel','system_health*.xem',null,null) fx
CROSS APPLY (SELECT CAST(fx.event_data AS XML) AS Event_Data) AS xData
CROSS APPLY xData.Event_Data.nodes('//event') AS xed (event_data)
WHERE fx.object_name = 'wait_info';

This is some amazing information, made better by the fact that it’s automatically collected. There are however a couple of downsides.

  • The system health session only keeps so much information so on a busy system stuff can disappear pretty quickly.
  • In the case of blocking it only shows the query that was blocked and the type of lock it was trying to get. It doesn’t tell you what query was actually blocking it, which somewhat limits resolving it.

 
Personally, I’m thinking about putting a process in place to store this information over time and summarize it. I can then use this as another place to look for low hanging fruit that needs to be fixed.

SQLStudies

My name is Kenneth Fisher and I am Senior DBA for a large (multi-national) insurance company. I have been working with databases for over 20 years starting with Clarion and Foxpro. I’ve been working with SQL Server for 12 years but have only really started “studying” the subject for the last 3. I don’t have any real "specialities" but I enjoy trouble shooting and teaching. Thus far I’ve earned by MCITP Database Administrator 2008, MCTS Database Administrator 2005, and MCTS Database Developer 2008. I’m currently studying for my MCITP Database Developer 2008 and should start in on the 2012 exams next year. My blog is at www.sqlstudies.com.

Comments

Leave a comment on the original post [sqlstudies.com, opens in a new window]

Loading comments...