use master
go
declare @spid int,@bl int
DECLARE s_cur CURSOR FOR 
select  0 ,blocked
from (select * from sysprocesses where  blocked>0 ) a 
where not exists(select * from (select * from sysprocesses where  blocked>0 ) b 
where a.blocked=spid)
union select spid,blocked from sysprocesses where  blocked>0
OPEN s_cur
FETCH NEXT FROM s_cur INTO @spid,@bl
WHILE @@FETCH_STATUS = 0
begin
if @spid =0 
 select '引起数据库死锁的是: 
'+ CAST(@bl AS VARCHAR(10)) + '进程号,其执行的SQL语法如下'
else
select '进程号SPID:'+ CAST(@spid AS VARCHAR(10))+ '被' + '
进程号SPID:'+ CAST(@bl AS VARCHAR(10)) +'阻塞,其当前进程执行的SQL语法如下'
DBCC INPUTBUFFER (@bl )
FETCH NEXT FROM s_cur INTO @spid,@bl
end
CLOSE s_cur
DEALLOCATE s_cur


--死锁查询
select 标志,
进程ID=spid,线程ID=kpid,块进程ID=blocked,数据库ID=dbid,
数据库名=db_name(dbid),用户ID=uid,用户名=loginame,累计CPU时间=cpu,
登陆时间=login_time,打开事务数=open_tran, 进程状态=status,
工作站名=hostname,应用程序名=program_name,工作站进程ID=hostprocess,
域名=nt_domain,网卡地址=net_address
from(
select 标志='死锁的进程',
spid,kpid,a.blocked,dbid,uid,loginame,cpu,login_time,open_tran,
status,hostname,program_name,hostprocess,nt_domain,net_address,
s1=a.spid,s2=0
from master..sysprocesses a join (
select blocked from master..sysprocesses group by blocked
)b on a.spid=b.blocked where a.blocked=0
union all
select '|_牺牲品_>',
spid,kpid,blocked,dbid,uid,loginame,cpu,login_time,open_tran,
status,hostname,program_name,hostprocess,nt_domain,net_address,
s1=blocked,s2=1
from master..sysprocesses a where blocked<>0
)a order by s1,s2;

SELECT
    t1.resource_type [资源锁定类型],
    DB_NAME(resource_database_id) AS 数据库名,
    t1.resource_associated_entity_id 锁定对象,
    t1.request_mode AS 等待者请求的锁定模式,
    t1.request_session_id 等待者SID,
    t2.wait_duration_ms 等待时间,
    (
        SELECT
            TEXT
        FROM
            sys.dm_exec_requests r CROSS apply sys.dm_exec_sql_text (r.sql_handle)
        WHERE
            r.session_id = t1.request_session_id
    ) AS 等待者要执行的SQL,
    t2.blocking_session_id [锁定者SID],
    (
        SELECT
            TEXT
        FROM
            sys.sysprocesses p CROSS apply sys.dm_exec_sql_text (p.sql_handle)
        WHERE
            p.spid = t2.blocking_session_id
    ) 锁定者执行语句
FROM
    sys.dm_tran_locks t1,
    sys.dm_os_waiting_tasks t2
WHERE
    t1.lock_owner_address = t2.resource_address;

 SELECT TOP 10 
  [session_id], 
  [request_id], 
  [start_time] AS '开始时间', 
  [status] AS '状态', 
  [command] AS '命令', 
  dest.[text] AS 'sql语句',  
  DB_NAME([database_id]) AS '数据库名', 
  [blocking_session_id] AS '正在阻塞其他会话的会话ID', 
  [wait_type] AS '等待资源类型', 
  [wait_time] AS '等待时间', 
  [wait_resource] AS '等待的资源', 
  [reads] AS '物理读次数', 
  [writes] AS '写次数', 
  [logical_reads] AS '逻辑读次数', 
  [row_count] AS '返回结果行数' 
 FROM sys.[dm_exec_requests] AS der  CROSS APPLY  sys.[dm_exec_sql_text](der.[sql_handle]) AS dest  
 WHERE [session_id]>50 AND DB_NAME(der.[database_id])='SeedLandContractDB'   
 ORDER BY [cpu_time] DESC

发表评论