if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].[p_lockinfo]') and OBJECTPROPERTY(id, N'IsProcedure') = 1)
drop procedure [dbo].[p_lockinfo]
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_NULLS ON
GO
/*--處理死鎖
?查看當前進程,或死鎖進程,并能自動殺掉死進程
?因為是針對死的,所以如果有死鎖進程,只能查看死鎖進程
?當然,你可以通過參數控制,不管有沒有死鎖,都只查看死鎖進程
?感謝: caiyunxia,jiangopen 兩位提供的參考信息
--鄒建 2004.4--*/
/*--調用示例
?exec p_lockinfo
--*/
create proc p_lockinfo
@kill_lock_spid bit=1,? --是否殺掉死鎖的進程,1 殺掉, 0 僅顯示
@show_spid_if_nolock bit=1 --如果沒有死鎖的進程,是否顯示正常進程信息,1 顯示,0 不顯示
as
declare @count int,@s nvarchar(1000),@i int
select id=identity(int,1,1),標志,
?進程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
into #t 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 @count=@@rowcount,@i=1
if @count=0 and @show_spid_if_nolock=1
begin
?insert #t
?select 標志='正常的進程',
? spid,kpid,blocked,dbid,db_name(dbid),uid,loginame,cpu,login_time,
? open_tran,status,hostname,program_name,hostprocess,nt_domain,net_address
?from master..sysprocesses
?set @count=@@rowcount
end
if @count>0
begin
?create table #t1(id int identity(1,1),a nvarchar(30),b Int,EventInfo nvarchar(255))
?if @kill_lock_spid=1
?begin
? declare @spid varchar(10),@標志 varchar(10)
? while @i<=@count
? begin
?? select @spid=進程ID,@標志=標志 from #t where id=@i
?? insert #t1 exec('dbcc inputbuffer('+@spid+')')
?? if @標志='死鎖的進程' exec('kill '+@spid)
?? set @i=@i+1
? end
?end
?else
? while @i<=@count
? begin
?? select @s='dbcc inputbuffer('+cast(進程ID as varchar)+')' from #t where id=@i
?? insert #t1 exec(@s)
?? set @i=@i+1
? end
?select a.*,進程的SQL語句=b.EventInfo
?from #t a join #t1 b on a.id=b.id
end
GO
SET QUOTED_IDENTIFIER OFF
GO
SET ANSI_NULLS ON
GO
posted on 2007-10-15 16:12
無聲 閱讀(3802)
評論(6) 編輯 收藏 所屬分類:
職場生活