最近發現一個非常奇怪的阻塞問題,如下截圖所示(來自監控工具DPA),會話583被會話1036阻塞,而且阻塞發生在tempdb,被阻塞的SQL如下截圖所示,會話等待類型為LCK_M_S 因為DPA工具不好截取全部信息,使用下麵SQL語句獲取了阻塞會話的詳細信息如下,來自Microsoft SQL Se... ...
最近發現一個非常奇怪的阻塞問題,如下截圖所示(來自監控工具DPA),會話583被會話1036阻塞,而且阻塞發生在tempdb,被阻塞的SQL如下截圖所示,會話等待類型為LCK_M_S
|
|
因為DPA工具不好截取全部信息,使用下麵SQL語句獲取了阻塞會話的詳細信息如下,來自Microsoft SQL Server Management Studio - Transact-SQL IntelliSense的的SQL被阻塞了
SELECT s.session_id ,
r.status ,
r.blocking_session_id 'Blk by' ,
r.wait_type ,
wait_resource ,
r.wait_time / ( 1000 * 60 ) 'Wait M' ,
r.cpu_time ,
r.logical_reads ,
r.reads ,
r.writes ,
r.total_elapsed_time / ( 1000 * 60 ) 'Elaps M' ,
SUBSTRING(st.text, ( r.statement_start_offset / 2 ) + 1,
( ( CASE r.statement_end_offset
WHEN -1 THEN DATALENGTH(st.text)
ELSE r.statement_end_offset
END - r.statement_start_offset ) / 2 ) + 1) AS statement_text ,
COALESCE(QUOTENAME(DB_NAME(st.dbid)) + N'.'
+ QUOTENAME(OBJECT_SCHEMA_NAME(st.objectid, st.dbid)) + N'.'
+ QUOTENAME(OBJECT_NAME(st.objectid, st.dbid)), '') AS command_text ,
r.command ,
s.login_name ,
s.host_name ,
s.program_name ,
s.last_request_end_time ,
s.login_time ,
r.open_transaction_count
FROM sys.dm_exec_sessions AS s
JOIN sys.dm_exec_requests AS r ON r.session_id = s.session_id
CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) AS st
WHERE r.session_id =583
ORDER BY r.cpu_time DESC;
而會話1036處於睡眠(sleeping)狀態,有一個Open的事務。通過wait_resource的值“KEY: 2:1125899909070848 (79c68d10aa42)”,我們定位到是一個系統表sysschobj.它是sys.triggers這個系統視圖的基表。如下所示:
SET QUOTED_IDENTIFIER ON
SET ANSI_NULLS ON
GO
CREATE VIEW sys.triggers AS
SELECT o.name,
object_id = o.id,
parent_class = o.pclass,
parent_class_desc = pc.name,
parent_id = o.pid,
type = o.type,
type_desc = n.name,
create_date = o.created,
modify_date = o.modified,
is_ms_shipped = sysconv(bit, o.status & 1), -- OBJALL_MSSHIPPED
is_disabled = sysconv(bit, o.status & 256), -- OBJTRG_DISABLED
is_not_for_replication = sysconv(bit, o.status & 512), -- OBJTRG_NOTFORREPL
is_instead_of_trigger = sysconv(bit, o.status & 1024) -- OBJTRG_INSTEADOF
FROM sys.sysschobjs o
LEFT JOIN sys.syspalnames n ON n.class = 'OBTY' AND n.value = o.type
LEFT JOIN sys.syspalvalues pc ON pc.class = 'UNCL' AND pc.value = o.pclass
WHERE o.type IN ('TA','TR') AND o.pclass <> 100
AND has_access('TR', o.id, o.pid, o.nsclass) = 1
GO
使用下麵腳本可以查到對應的鎖信息(其實,正確的做法應該是加上條件過濾spid),從而可以判斷,會話1036可能因為事務中,間接涉及對基表sysschobj的DML操作(有可能是衍生的系統視圖),而由於事務沒有提交也沒有釋放,導致在基表上的鎖沒有釋放,從而導致出現這樣一個阻塞。個人也很好奇是什麼樣的SQL會導致這樣一個阻塞出現,不過這種阻塞源頭是Sleeping狀態的會話,已經無法定位阻塞源頭SQL,只能通過Profile去跟蹤捕獲。但是這種阻塞出現時機和場景不清楚,很難一下子捕獲到。
USE tempdb
GO
SELECT request_session_id AS spid ,
DB_NAME(resource_database_id) AS dbname ,
CASE WHEN resource_type = 'OBJECT'
THEN OBJECT_NAME(resource_associated_entity_id)
WHEN resource_associated_entity_id = 0 THEN 'n/a'
ELSE OBJECT_NAME(p.object_id)
END AS entity_name ,
index_id ,
resource_type AS resource ,
resource_description AS description ,
request_mode AS mode ,
request_status AS status
FROM sys.dm_tran_locks t
LEFT JOIN sys.partitions p
ON p.partition_id = t.resource_associated_entity_id
WHERE resource_database_id = DB_ID()