Created
April 19, 2021 17:11
-
-
Save junalmeida/671596ddb3a8445d99506b7e19fee6a3 to your computer and use it in GitHub Desktop.
Find MSSQL Locks
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
WITH cteHead ( session_id,request_id,wait_type,wait_resource,last_wait_type,is_user_process,request_cpu_time | |
,request_logical_reads,request_reads,request_writes,wait_time,blocking_session_id,memory_usage | |
,session_cpu_time,session_reads,session_writes,session_logical_reads | |
,percent_complete,est_completion_time,request_start_time,request_status,command | |
,plan_handle,sql_handle,statement_start_offset,statement_end_offset,most_recent_sql_handle | |
,session_status,group_id,query_hash,query_plan_hash) | |
AS ( SELECT sess.session_id, req.request_id, LEFT (ISNULL (req.wait_type, ''), 50) AS 'wait_type' | |
, LEFT (ISNULL (req.wait_resource, ''), 40) AS 'wait_resource', LEFT (req.last_wait_type, 50) AS 'last_wait_type' | |
, sess.is_user_process, req.cpu_time AS 'request_cpu_time', req.logical_reads AS 'request_logical_reads' | |
, req.reads AS 'request_reads', req.writes AS 'request_writes', req.wait_time, req.blocking_session_id,sess.memory_usage | |
, sess.cpu_time AS 'session_cpu_time', sess.reads AS 'session_reads', sess.writes AS 'session_writes', sess.logical_reads AS 'session_logical_reads' | |
, CONVERT (decimal(5,2), req.percent_complete) AS 'percent_complete', req.estimated_completion_time AS 'est_completion_time' | |
, req.start_time AS 'request_start_time', LEFT (req.status, 15) AS 'request_status', req.command | |
, req.plan_handle, req.[sql_handle], req.statement_start_offset, req.statement_end_offset, conn.most_recent_sql_handle | |
, LEFT (sess.status, 15) AS 'session_status', sess.group_id, req.query_hash, req.query_plan_hash | |
FROM sys.dm_exec_sessions AS sess | |
LEFT OUTER JOIN sys.dm_exec_requests AS req ON sess.session_id = req.session_id | |
LEFT OUTER JOIN sys.dm_exec_connections AS conn on conn.session_id = sess.session_id | |
) | |
, cteBlockingHierarchy (head_blocker_session_id, session_id, blocking_session_id, wait_type, wait_duration_ms, | |
wait_resource, statement_start_offset, statement_end_offset, plan_handle, sql_handle, most_recent_sql_handle, [Level]) | |
AS ( SELECT head.session_id AS head_blocker_session_id, head.session_id AS session_id, head.blocking_session_id | |
, head.wait_type, head.wait_time, head.wait_resource, head.statement_start_offset, head.statement_end_offset | |
, head.plan_handle, head.sql_handle, head.most_recent_sql_handle, 0 AS [Level] | |
FROM cteHead AS head | |
WHERE (head.blocking_session_id IS NULL OR head.blocking_session_id = 0) | |
AND head.session_id IN (SELECT DISTINCT blocking_session_id FROM cteHead WHERE blocking_session_id != 0) | |
UNION ALL | |
SELECT h.head_blocker_session_id, blocked.session_id, blocked.blocking_session_id, blocked.wait_type, | |
blocked.wait_time, blocked.wait_resource, h.statement_start_offset, h.statement_end_offset, | |
h.plan_handle, h.sql_handle, h.most_recent_sql_handle, [Level] + 1 | |
FROM cteHead AS blocked | |
INNER JOIN cteBlockingHierarchy AS h ON h.session_id = blocked.blocking_session_id and h.session_id!=blocked.session_id --avoid infinite recursion for latch type of blocking | |
WHERE h.wait_type COLLATE Latin1_General_BIN NOT IN ('EXCHANGE', 'CXPACKET') or h.wait_type is null | |
) | |
SELECT 'KILL ' + CAST(bh.blocking_session_id as nvarchar(50)) , bh.*, txt.text AS blocker_query_or_most_recent_query | |
FROM cteBlockingHierarchy AS bh | |
OUTER APPLY sys.dm_exec_sql_text (ISNULL ([sql_handle], most_recent_sql_handle)) AS txt | |
ORDER BY bh.wait_duration_ms DESC |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment