问题引入
在前面三篇文章,我们分别谈到了使用DBCC命令捕获死锁;使用Profiler界面跟踪Deadlock Graph事件捕获死锁和使用脚本自动部署Profiler Trace捕获死锁。这篇文章介绍一个非常有意思的捕获死锁的方法:使用SQL Server Service Broker Event Notification来捕获死锁。
Service Broker Event Notification
Service Broker Event Notification即使用SQL Server引擎内置的异步消息通讯机制加上SQL Server的事件通知机制来捕获死锁信息,这个方法非常简单,对SQL Server数据库本身影响非常小。一个简单的模型是将捕获到的死锁xml信息存放在队里中,然后分析队列,重现详细的死锁场景。代码如下:
USE [master]
GO
IF DB_ID('DeadlockCapture') IS NULL
CREATE DATABASE [DeadlockCapture];
GO
ALTER DATABASE [DeadlockCapture]
SET ENABLE_BROKER
GO
USE [DeadlockCapture]
GO
--Create Event Notification Queue to save Deadlock Info
CREATE QUEUE QueueDeadLockNotification
;
--Create Event Notification Services
CREATE SERVICE ServiceDeadlockNotification
ON QUEUE QueueDeadLockNotification ([http://schemas.microsoft.com/SQL/Notifications/PostEventNotification]);
GO
-- Create route for the DeadlockNotificationSvc
CREATE ROUTE RouteDeadLockNotification
WITH SERVICE_NAME = 'ServiceDeadlockNotification',
ADDRESS = 'LOCAL';
GO
-- Create Event Notification for the deadlock_graph event.
CREATE EVENT NOTIFICATION DeadLockNotificationEvent
ON SERVER
FOR DEADLOCK_GRAPH
TO SERVICE
'ServiceDeadlockNotification',
'current database'
GO
死锁测试的方法和过程参见文章RDS SQL Server死锁(Deadlock)系列之一使用DBCC捕获死锁中死锁测试部分,在此不再累述。
分析死锁
当死锁发生后,死锁信息会被异步的记录到Service Broker队列中。
USE [DeadlockCapture]
GO
select CAST(message_body as xml),* from QueueDeadLockNotification
查询结果展示如下:
接下来的工作就是分析队里中的死锁信息,分析方法和前面几篇文章的分析方法大同小异,只是在公用表达式的初始化部分稍有差异。方法如下:
use master
go
;WITH DATA
AS
(
-- Analysis deadlock when saving into Service Broker Event Notification
select
RowNumber = row_number() OVER (ORDER BY queuing_order)
,DeadlockGraph = CAST(message_body as xml).query('./EVENT_INSTANCE/TextData/deadlock-list')
from [DeadlockCapture].[dbo].[QueueDeadLockNotification] WITH(NOLOCK)
)
,
deadlock
AS
(
SELECT
RowNumber
,OwnerID = T.C.value('@id', 'varchar(50)')
,SPid = T.C.value('(./@spid)[1]','int')
,status = T.C.value('(./@status)[1]','varchar(10)')
,Victim = case when T.C.value('@id', 'varchar(50)') = T.C.value('./../../@victim','varchar(50)') then 1 else 0 end
,LockMode = T.C.value('@lockMode', 'varchar(20)')
,DeadlockGraph
,Inputbuf = T.C.value('(./inputbuf/text())[1]','varchar(max)')
,Code = T.C.value('(./executionStack/frame/text())[1]','VARCHAR(max)')
,SPName = T.C.value('(./executionStack/frame/@procname)[1]','sysname')
,Hostname = T.C.value('(./@hostname)[1]','sysname')
,Clientapp = T.C.value('(./@clientapp)[1]','varchar(max)')
,LoginName = T.C.value('@loginname', 'varchar(20)')
,Action = T.C.value('(./@transactionname)[1]','varchar(max)')
,TransactionTime = T.C.value('@lasttranstarted', 'datetime')
FROM DATA AS A
CROSS APPLY DeadlockGraph.nodes('deadlock-list/deadlock/process-list/process') AS T(C)
)
,
keylock
AS
(
SELECT
OwnerID = T.C.value('./owner[1]/@id', 'varchar(50)')
,KeylockObject = T.C.value('./../@objectname', 'varchar(200)')
,Indexname = T.C.value('./../@indexname', 'varchar(200)')
,IndexLockMode = T.C.value('./../@mode', 'varchar(20)')
FROM DATA AS A
CROSS APPLY DeadlockGraph.nodes('deadlock-list/deadlock/resource-list/keylock/owner-list') AS T(C)
)
SELECT
A.SPid
,is_Vitim = A.Victim
,A.SPName
,A.Code
,A.LockMode
,B.Indexname
,B.KeylockObject
,B.IndexLockMode
,A.Inputbuf
,A.Hostname
,A.LoginName
,A.Clientapp
,A.Action
,status
,A.TransactionTime
FROM deadlock AS A
LEFT JOIN keylock AS B
ON A.OwnerID = B.OwnerID
ORDER BY A.RowNumber,A.Victim
展示结果如下图所示:
最后总结
使用Service Broker Event Notification来捕获死锁信息,是一个比较新颖的选择,由于采用异步消息通讯的方式,对SQL Server影响非常小。个人建议使用该方法来捕获、分析死锁。