What queries are getting blocked?

Kenneth Fisher, 2018-06-14 (first published: 2018-06-06)

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.

Rate

Share

Share

Rate

Related content

Database Mirroring FAQ: Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup?

Question: Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup? This question was sent to me via email. My reply follows. Can a 2008 SQL instance be used as the witness for a 2005 database mirroring setup? Databases to be mirrored are currently running on 2005 SQL instances but will be upgraded to 2008 SQL in the near future.

Robert Davis

2009-02-23

1,567 reads

Networking – Part 4

You may want to read Part 1 , Part 2 , and Part 3 before continuing. This time around I’d like to talk about social networking. We’ll start with social networking. Facebook, MySpace, and Twitter are all good examples of using technology to let…

Andy Warren

2009-02-17

1,530 reads

Speaking at Community Events – More Thoughts

Last week I posted Speaking at Community Events – Time to Raise the Bar?, a first cut at talking about to what degree we should require experience for speakers at events like SQLSaturday as well as when it might be appropriate to add additional focus/limitations on the presentations that are accepted. I’ve got a few more thoughts on the topic this week, and I look forward to your comments.

Andy Warren

2009-02-13

360 reads