SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


DBA Tools:sp_whocpu


DBA Tools:sp_whocpu

Author
Message
Mircea
Mircea
SSC Rookie
SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)

Group: General Forum Members
Points: 47 Visits: 353
Comments posted to this topic are about the item DBA Tools: sp_whoCPU

Hi All,

Just a note to let you know that the issue with the TAB characters has been resolved, so you can just copy and paste the script if you would like to use it.


Thanks



hugericc
hugericc
SSC Journeyman
SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)

Group: General Forum Members
Points: 91 Visits: 39
Thanks for the script.
I've sucessfully run it and created the sp but when I run the sp itself in SS management studio (2005), I only get the colunm headers but no results.
Am I missing something?
Mircea
Mircea
SSC Rookie
SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)

Group: General Forum Members
Points: 47 Visits: 353
Hi,

This is possible, if there is no activity on the server, during the 3 seconds period when the sp_whocpu calculates the cpu_delta.

The spid that runs sp_whocpu is ignored.
None of the sleeping processes which do not consume cpu will show either, so it is possible that at a certain moment you don't get any output.

This is what differentiates sp_whocpu from sp_who2 for example. Running sp_who2 will show all processes, some with quite high cpu figures, when in fact they do not consume any resources at that moment in time.


Cheers,
Mircea



hugericc
hugericc
SSC Journeyman
SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)

Group: General Forum Members
Points: 91 Visits: 39
Outstanding.
This makes perfect sense as it was on my DEV server which had open connections but may not have been processing anything. :-)
Thanks!
GabyYYZ
GabyYYZ
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2965 Visits: 2336
Love this script. Hope you don't mind, I added one tweak, to pass a time parameter in (default to 3 seconds). Changes bolded below.


if exists (select * from master.dbo.sysobjects where id = object_id('dbo.sp_whocpu') )
Drop Procedure dbo.sp_whocpu
go

/*====================================================================
-- Mircea Anton Nita - 2010
-- https://www.mcpvirtualbusinesscard.com/VBCServer/Mircea/card
======================================================================*/
Create Procedure dbo.sp_whocpu
@samplingTime int = 3, -- seconds to pass, but maybe don't get carried away
@dbname sysname = null,
@loginame sysname = null
as

set nocount on

declare
@retcode int
,@sidlow varbinary(85)
,@sidhigh varbinary(85)
,@sid1 varbinary(85)
,@spidlow int
,@spidhigh int
,@seldbid varchar(10)
,@charMaxLenLoginName varchar(24)
,@charMaxLenDBName varchar(24)
,@charMaxLenCPUTime varchar(10)
,@charMaxLenCPUDelta varchar(10)
,@charMaxLenDiskIO varchar(10)
,@charMaxLenHostName varchar(24)
,@charMaxLenProgramName varchar(10)
,@charMaxLenLastBatch varchar(10)
,@charMaxLenCommand varchar(10)
,@charsidlow varchar(85)
,@charsidhigh varchar(85)
,@charspidlow varchar(11)
,@charspidhigh varchar(11)
,@command varchar(8000)
,@samplingTimeString varchar(10) -- string version of sampleTime to pass to WAITFOR DELAY


-- CHANGES TO TAKE VARIABLE SAMPLING TIME
if @samplingTime < 3 set @samplingTime = 3 -- use the acceptable minimum
SELECT @samplingTimeString = cast(
(
CASE WHEN @samplingTime/3600<10 THEN '0' ELSE '' END
+ RTRIM(@samplingTime/3600)
+ ':' + RIGHT('0'+RTRIM((@samplingTime % 3600) / 60),2)
+ ':' + RIGHT('0'+RTRIM((@samplingTime % 3600) % 60),2)
) as varchar(10))


-- set defaults
set @retcode = 0
set @sidlow = convert(varbinary(85), (replicate(char(0), 85)))
set @sidhigh = convert(varbinary(85), (replicate(char(1), 85)))
set @spidlow = 0
set @spidhigh = 32767

if (@dbname is not null)
set @seldbid = cast((select top 1 dbid from master.dbo.sysdatabases where name like '%'+@dbname+'%') as varchar(10))
else
set @seldbid = '0'

if (@loginame is null) -- Simple default to all LoginNames.
GOTO LABEL_PARAM

select @sid1 = null
if exists(select * from sys.syslogins where loginname = @loginame)
select @sid1 = sid from sys.syslogins where loginname = @loginame

if (@sid1 is not null) -- The parameter is a recognized login name.
begin
select @sidlow = suser_sid(@loginame)
,@sidhigh = suser_sid(@loginame)
GOTO LABEL_PARAM
end

if (lower(@loginame collate Latin1_General_CI_AS) in ('Active')) -- Special action, not sleeping.
begin
select @loginame = lower(@loginame collate Latin1_General_CI_AS)
GOTO LABEL_PARAM
end

if (patindex ('%[^0-9]%' , isnull(@loginame,'z')) = 0) -- Is a number.
begin
select
@spidlow = convert(int, @loginame)
,@spidhigh = convert(int, @loginame)
GOTO LABEL_PARAM
end

raiserror(15007,-1,-1,@loginame)
select @retcode = 1
GOTO LABEL_RETURN

LABEL_PARAM:

-- Getting data over a time window to allow the cpu_delta metric calculation
if object_id('tempdb.dbo.#cpu1') is not null drop table #cpu1
if object_id('tempdb.dbo.#cpu2') is not null drop table #cpu2
select spid, cpu into #cpu1 from master.dbo.sysprocesses with (nolock) order by cpu desc
waitfor delay @sampling_time_string
select spid, cpu into #cpu2 from master.dbo.sysprocesses with (nolock) order by cpu desc

-------------------- Capture consistent sysprocesses. -------------------

select
sp.spid
,status
,sid
,hostname
,program_name
,cmd
,sp.cpu
,c2.cpu-c1.cpu as 'cpu_delta'
,physical_io
,blocked
,dbid
,convert(sysname, rtrim(loginame)) as loginname
,sp.spid as 'spid_sort'
, substring( convert(varchar,last_batch,111) ,6 ,5 ) + ' '
+ substring( convert(varchar,last_batch,113) ,13 ,8 ) as 'last_batch_char'

into #tb1_sysprocesses
from #cpu2 c2 join #cpu1 c1 on c2.spid = c1.spid join master.dbo.sysprocesses sp with (nolock) on sp.spid = c2.spid
where c2.cpu-c1.cpu > 0

if @@error <> 0
begin
select @retcode = @@error
GOTO LABEL_RETURN
end

if (@loginame in ('active'))
delete #tb1_sysprocesses
where lower(status) = 'sleeping'
and upper(cmd) in (
'AWAITING COMMAND'
,'LAZY WRITER'
,'CHECKPOINT SLEEP'
)
and blocked = 0
and dbid <> @seldbid

-- Prepare to dynamically optimize column widths.
select
@charsidlow = convert(varchar(85),@sidlow)
,@charsidhigh = convert(varchar(85),@sidhigh)
,@charspidlow = convert(varchar,@spidlow)
,@charspidhigh = convert(varchar,@spidhigh)

select
@charMaxLenLoginName =
convert( varchar
,isnull( max( datalength(loginname)) ,16)
)

,@charMaxLenDBName =
convert( varchar
,isnull( max( datalength( rtrim(convert(varchar(128),db_name(dbid))))) ,20)
)

,@charMaxLenCPUTime =
convert( varchar
,isnull( max( datalength( rtrim(convert(varchar(128),cpu)))) ,10)
)

,@charMaxLenCPUDelta =
convert( varchar
,isnull( max( datalength( rtrim(convert(varchar(128),cpu_delta)))) ,10)
)

,@charMaxLenDiskIO =
convert( varchar
,isnull( max( datalength( rtrim(convert(varchar(128),physical_io)))) ,6)
)

,@charMaxLenCommand =
convert( varchar
,isnull( max( datalength( rtrim(convert(varchar(128),cmd)))) ,7)
)

,@charMaxLenHostName =
convert( varchar
,isnull( max( datalength( rtrim(convert(varchar(128),hostname)))) ,16)
)

,@charMaxLenProgramName =
convert( varchar
,isnull( max( datalength( rtrim(convert(varchar(128),program_name)))) ,11)
)

,@charMaxLenLastBatch =
convert( varchar
,isnull( max( datalength( rtrim(convert(varchar(128),last_batch_char)))) ,9)
)
from
#tb1_sysprocesses
where
spid >= @spidlow
and spid <= @spidhigh



-- Output the report.
set @command = '
set nocount off

select
SPID = convert(char(5),spid)

,Status =
CASE lower(status)
When ''sleeping'' Then lower(status)
Else upper(status)
END

,Login = substring(loginname,1,' + @charMaxLenLoginName + ')

,HostName =
CASE hostname
When Null Then '' .''
When '' '' Then '' .''
Else substring(hostname,1,' + @charMaxLenHostName + ')
END

,BlkBy =
CASE isnull(convert(char(5),blocked),''0'')
When ''0'' Then '' .''
Else isnull(convert(char(5),blocked),''0'')
END

,DBName = substring(case when dbid = 0 then null when dbid <> 0 then db_name(dbid) end,1,' + @charMaxLenDBName + ')
,Command = substring(cmd,1,' + @charMaxLenCommand + ')

,CPU_Total = substring(convert(varchar,cpu),1,' + @charMaxLenCPUTime + ')
,CPU_Delta = substring(convert(varchar,cpu_delta),1,' + @charMaxLenCPUDelta + ')
,DiskIO = substring(convert(varchar,physical_io),1,' + @charMaxLenDiskIO + ')

,LastBatch = substring(last_batch_char,1,' + @charMaxLenLastBatch + ')

,ProgramName = substring(program_name,1,' + @charMaxLenProgramName + ')
,SPID = convert(char(5),spid) -- Handy extra for right-scrolling users.
from
#tb1_sysprocesses
where spid > 50 -- filter out system spids
and spid <> @@spid -- and current process spid
and spid >= ' + @charspidlow + '
and spid <= ' + @charspidhigh + '
'
if @seldbid > 0
set @command = @command +
'
and dbid = ' + @seldbid + '
'

set @command = @command +
' order by cast(cpu_delta as int) desc, cast(cpu as int) desc

set nocount on
'
exec (@command)

LABEL_RETURN:

if object_id('tempdb.dbo.#tb1_sysprocesses') is not null drop table #tb1_sysprocesses
if object_id('tempdb.dbo.#cpu1') is not null drop table #cpu1
if object_id('tempdb.dbo.#cpu2') is not null drop table #cpu2

return @retcode -- sp_whocpu
go


if exists (select * from sysobjects
where id = object_id('dbo.sp_whocpu')
and sysstat & 0xf = 4)
grant exec on dbo.sp_whocpu to public
go



Gaby
________________________________________________________________
"In theory, theory and practice are the same. In practice, they are not."
- Albert Einstein

Mircea
Mircea
SSC Rookie
SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)

Group: General Forum Members
Points: 47 Visits: 353
Hi,

Thank you very much for your comments and your suggestion.

The stored procedure did have an interval parameter in the design phase, however, I found in the past two years since using it that 2 seconds is the minimum time to get meaningful figures, and from 4 or 5 seconds onwards the wait until you get results is too long.

You can certainly use a parameter for the interval, however, this opens new possibilities for things to go astray, as many DBAs including me think of time in milliseconds, and it would be easy to pass by mistake 4000 instead of 4 as parameter if you have four seconds in mind. This would be less than ideal.

The main use for this stored procedure is as a very fast tool to get the top processes consuming cpu, so although I am generally against hard coding, I decided not to use parameters - just call sp_whocpu and get the results.

Thanks,
Mircea



RimonTL
RimonTL
SSC Journeyman
SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)

Group: General Forum Members
Points: 76 Visits: 84
Hello,

You are deleting sleeping processes if the @loginame is in 'Active'. But what happens if I don't give any login name, which means @loginame would be null? Does the procedure still delete the sleeping processes from the temporary table?

Thanks.
Alexander Suprun
Alexander Suprun
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2337 Visits: 1516
The query has no sense at all! I urge everyone not to use it.

This join based on spid is simply wrong
    from #cpu2 c2 join #cpu1 c1 on c2.spid = c1.spid join master.dbo.sysprocesses sp with (nolock) on sp.spid = c2.spid




Alex Suprun
Mircea
Mircea
SSC Rookie
SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)

Group: General Forum Members
Points: 47 Visits: 353
Hi Alex,

Thank you for looking into this script.

Can you please substantiate your claim and explain why it doesn't make sense?
We are always willing to improve the quality of our scrips.

It was not the purpose of the post to explain how this works, since the full source code was published for you to analyse.
There are comments within the script which explain the idea of two sysprocesses snapshots at 3 seconds interval, comments which we thought are sufficient for all T-SQL users.

I did not urge anyone to use the script, so please short of explaining exactly why - do not urge anyone to do anything else but analyse the script and decide for themselves whether to use it or not.



Alexander Suprun
Alexander Suprun
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2337 Visits: 1516
Mircea (5/21/2015)
I did not urge anyone to use the script, so please short of explaining exactly why - do not urge anyone to do anything else but analyse the script and decide for themselves whether to use it or not.

I thought that the whole purpose of posting ready-to-use scripts is that other people don't have to spend a lot of time doing code review and making sure that script does what is was designed to do.

To name a few:
1. spid is not unique in sysprocesses
2. spid can be easily assigned to another connection from different user during 3 seconds interval
3. cpu in sysprocesses will show only cpu consumed by main thread in multi-threaded plan


Alex Suprun
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum







































































































































































SQLServerCentral


Search