|
 |
|
Display SQL Server database waits
SQL Server Tips by Donald Burleson |
This is one of the many SQL
Server Windows scripts to display database waits from the book "High
Performance SQL Server DBA". See
code depot for full script
In SQL Server 2000, there are nearly eighty different wait
types , and in SQL Server 2005, that number grows to somewhere over 120. The
first piece of basic information that is received from the DBCC command is a
Wait Type, which identifies each kind of wait event. The
wait type or
name is fairly cryptic, but with
practice, the ability to identify each wait type will be realized.
After the wait type , the DBA will get a count of
requests
, which indicates how many times the
wait type has occurred. At first, one might gravitate toward this column as
being the most important, but this notion should be resisted and instead the
focus place on the next column, which is wait
time . wait time is the most
important indicator of how bad a wait event is in terms of actually being a
bottleneck .
In terms of an analogy, it can be compared to driving a car
and encountering red lights. If a person is driving down a road and approaches
a red light, but it turns green before the driver actually decelerates, the red
light really did not affect momentum at all. If, however, that person actually
has to stop and is delayed at a red light, the trip has become interrupted.
It's not uncommon to notice wait types that have a rather
high number of wait requests but have not logged any actual
wait time . Other wait types will have
accumulated quite a bit of wait time,
and it is these that need to bubble to the top as they are the ones that deserve
attention. It is best to break down wait time
into percentages because it becomes easier to troubleshoot issues when the DBA
knows, for example, that network I/O waits are responsible for 90% of all wait
time on the SQL Server.
Something else that needs to be done is bogus or idle waits
over which SQL Server has no control or that are not actually important in the
overall scheme of things should be eliminated. These wait types include:
waitfor waits
sleep waits
resource_queue waits
Including these wait events in diagnostic scripts will skew
the percentage numbers, so it is best to eliminate them.
The following up_bn_waits
procedure is a good one to use to get a handle on the SQL Server wait activity.
It allows idle wait events to be included or excluded, calculates wait time
percentages, and sorts the output so the DBA can know exactly what system
bottlenecks are responsible for the bulk of overall wait time on SQL Server.
IF
OBJECT_ID('up_bn_waits') IS NOT NULL
BEGIN
DROP PROCEDURE up_bn_waits
IF OBJECT_ID('up_bn_waits') IS NOT NULL
PRINT '<<< FAILED DROPPING PROCEDURE up_bn_waits >>>'
ELSE
PRINT '<<< DROPPED PROCEDURE up_bn_waits >>>'
END
go
create procedure up_bn_waits( @include_idle char(1) = 'N' )
AS
set nocount on
set ARITHABORT off
set ARITHIGNORE on
set ANSI_WARNINGS off
declare @sql varchar(1000)
create table #wait_info (wait_type varchar(100) NULL,
wait_requests float NULL,
wait_time float NULL,
signal_wait_time float NULL)
insert
into #wait_info
exec ('dbcc sqlperf(waitstats)')
if @include_idle = 'Y'
select
wait_type,
wait_requests,
pct_wait_total = convert(decimal(6,3),100 *
wait_requests / (select convert(float, case
sum(wait_requests)
when 0 then 1 else sum(wait_requests) end ) from #wait_info
where wait_type <>
'Total')),
wait_time_secs = convert(decimal(18,0), wait_time / 1000 ),
pct_wait_time = convert(decimal(6,3),100 * wait_time /
(select convert(float, case sum(wait_time) when 0 then 1
else
sum(wait_time) end )
from #wait_info where wait_type <> 'Total')),
signal_wait_time = convert( decimal(18,0), signal_wait_time),
pct_signal_wait_time = convert(decimal(6,3),100 *
signal_wait_time /
(select convert(float, case sum(signal_wait_time) when 0
then 1 else
sum(signal_wait_time)
end )
from #wait_info where wait_type <> 'Total'))
from
#wait_info
where
See
code depot for full script
else
select
wait_type,
wait_requests,
pct_wait_total = convert(decimal(6,3),100 * wait_requests /
(select convert(float, case sum(wait_requests) when 0 then 1
else
sum(wait_requests) end ) from #wait_info where wait_type <>
'Total' and
wait_type not in ('WAITFOR','SLEEP','RESOURCE_QUEUE'))),
wait_time_secs = convert(decimal(18,0), wait_time / 1000 ),
pct_wait_time = convert(decimal(6,3),100 * wait_time /
(select convert(float, case sum(wait_time) when 0 then 1
else
sum(wait_time) end )
from #wait_info where wait_type <> 'Total' and wait_type not
in
('WAITFOR','SLEEP','RESOURCE_QUEUE'))),
signal_wait_time = convert( decimal(18,0), signal_wait_time),
pct_signal_wait_time = convert(decimal(6,3),100 *
signal_wait_time /
(select convert(float, case sum(signal_wait_time) when 0
then 1 else
sum(signal_wait_time)
end )
from #wait_info where wait_type <> 'Total' and wait_type not
in
('WAITFOR','SLEEP','RESOURCE_QUEUE')))
from
#wait_info
where
See
code depot for full script
5 desc
drop table #wait_info
go
IF OBJECT_ID('up_bn_waits') IS NOT NULL
PRINT '<<< CREATED PROCEDURE up_bn_waits >>>'
ELSE
PRINT '<<< FAILED CREATING PROCEDURE up_bn_waits >>>'
go
Figure 5.8 is a partial representation of SQL Server wait
statistics.
This is one of the many SQL Server
Windows scripts to display wait statistics from the book "High
Performance SQL Server DBA".

|
|