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


Find Locked objects with high waitstats


Find Locked objects with high waitstats

Author
Message
Sanz
Sanz
Old Hand
Old Hand (339 reputation)Old Hand (339 reputation)Old Hand (339 reputation)Old Hand (339 reputation)Old Hand (339 reputation)Old Hand (339 reputation)Old Hand (339 reputation)Old Hand (339 reputation)

Group: General Forum Members
Points: 339 Visits: 982
Hi,

I have a SQL JOB that takes almost 8 hours to complete. I could find that when this runs there are a lot of waits. Screenshot is attached.
I would like to know on which objects these locks and latches are occurring and if possible the SQL statement involved.
These locks and latches are not being kept for a long duration, so it is hard to track from sysprocesses.

Thanks in Advance !

Sanz
Attachments
Capture.JPG (10 views, 27.00 KB)
Grant Fritchey
Grant Fritchey
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39665 Visits: 32639
The options are, query the dynamic management objects (DMO) such as sys.dm_exec_requests while the query is running in order to see which locks are taking a long time during execution. You can combine that DMO with others to see the query, the locked objects and the execution plan. The other option would be to set up extended events to capture information. That one is going to be much tougher. What you would need to do is start with the lock_acquired event. You can combine that with lock_released and look for pairings that exceed a certain value. It's going to be a bit of work to set up, but you can narrow right down to specific events that way. You should be able to combine that data with rpc_completed and sql_batch_completed to also capture the queries involved.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
Igor Micev
Igor Micev
SSCertifiable
SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)

Group: General Forum Members
Points: 5888 Visits: 5080
Hi,

It's easy with extended events (XE) in sql server 2012 by help of its GUI. It should be possible with XE 2008 R2, but you'll have to write some code (easier if you can find a gui for sql 2008 r2).
Another option is to use some code in a scheduled job and collect data for a certain period.

I use the following code to catch locks:


SELECT
L1.resource_type ,
DB_NAME(L1.resource_database_id) AS DatabaseName ,
CASE L1.resource_type
WHEN 'OBJECT' THEN OBJECT_NAME(L1.resource_associated_entity_id,L1.resource_database_id)
WHEN 'DATABASE' THEN 'DATABASE'
ELSE CASE
WHEN L1.resource_database_id = DB_ID() THEN
(SELECT
OBJECT_NAME(object_id, L1.resource_database_id)
FROM sys.partitions
WHERE hobt_id = L1.resource_associated_entity_id
)
ELSE NULL
END
END AS ObjectName ,
L1.resource_description ,
L1.request_session_id ,
L1.request_mode ,
L1.request_status
FROM
sys.dm_tran_locks AS L1
JOIN sys.dm_tran_locks AS L2 ON L1.resource_associated_entity_id = L2.resource_associated_entity_id
WHERE
L1.request_status <> L2.request_status
AND ( L1.resource_description = L2.resource_description
OR ( L1.resource_description IS NULL AND L2.resource_description IS NULL)
)
ORDER BY
L1.resource_database_id ,
L1.resource_associated_entity_id ,
L1.request_status ASC;






Regards,
IgorMi

Igor Micev,
SQL Server developer at Seavus
My blog: www.igormicev.com
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