Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase «««1234»»

Top 10 Wait State Issues Reporter Expand / Collapse
Author
Message
Posted Monday, November 26, 2012 9:47 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 2:22 AM
Points: 2,422, Visits: 7,436
Why do you need the temporary tables?

SELECT TOP 10
[OS WAIT STATS - WAIT TYPE] = a.wait_type,
[TASKS WAITING COUNT] = a.waiting_tasks_count,
[TIME WAITING (MS)] = a.wait_time_ms,
[MAX TIME WAITING (MS)] = a.max_wait_time_ms,
[SIGNAL TIME WAITING (MS)] = a.signal_wait_time_ms,
[POSSIBLE ISSUES] = b.comment
FROM (SELECT wait_type, waiting_tasks_count,
wait_time_ms, max_wait_time_ms,
signal_wait_time_ms
FROM sys.dm_os_wait_stats
WHERE waiting_tasks_count <> 0
) a
INNER JOIN (SELECT wait_type, comment
FROM (SELECT 'SOS_SCHEDULER_YIELD',
'CPU - Execute this script: SELECT scheduler_id, current_tasks_count, runnable_tasks_count FROM sys.dm_os_schedulers WHERE scheduler_id < 255 ;If runnable tasks count > zero, CPU issues if double digits for any length of time, extreme CPU concern'
UNION ALL
SELECT 'CXPACKET',
'SETTINGS OR CODE - Wait stats shows more than 5% of your waits are on CXPackets, you may want to test lower (or non-zero) values of “max degree of parallelism”. Never set value great than # of CPUs'
UNION ALL
SELECT 'ASYNC_NETWORK_IO', 'NETWORK - Occurs on network writes when the task is blocked behind the network'
UNION ALL
SELECT 'LCK_M_BU', 'LOCK - Waiting to acquire a Bulk Update (BU) lock'
UNION ALL
SELECT 'LCK_M_IS', 'LOCK - Waiting to acquire an Intent Shared (IS) lock'
UNION ALL
SELECT 'LCK_M_IU', 'LOCK - Waiting to acquire an Intent Update (IU) lock '
UNION ALL
SELECT 'LCK_M_IX', 'LOCK - Waiting to acquire an Intent Exclusive (IX) lock'
UNION ALL
SELECT 'LCK_M_RIn_NL', 'LOCK - Waiting to acquire a NULL lock on the current key value and an Insert Range lock between the current and previous key'
UNION ALL
SELECT 'LCK_M_RIn_S', 'LOCK - Waiting to acquire a shared lock on the current key value and an Insert Range lock between the current and previous key'
UNION ALL
SELECT 'LCK_M_RIn_U', 'LOCK - Waiting to acquire an Update lock on the current key value, and an Insert Range lock between the current and previous key'
UNION ALL
SELECT 'LCK_M_RIn_X', 'LOCK - Waiting to acquire an Exclusive lock on the current key value, and an Insert Range lock between the current and previous key'
UNION ALL
SELECT 'LCK_M_RS_S', 'LOCK - Waiting to acquire a Shared lock on the current key value, and a Shared Range lock between the current and previous'
UNION ALL
SELECT 'LCK_M_RS_U', 'LOCK - Waiting to acquire an Update lock on the current key value, and an Update Range lock between the current and previous key'
UNION ALL
SELECT 'LCK_M_RX_S', 'LOCK - Waiting to acquire a Shared lock on the current key value, and an Exclusive Range lock between the current and previous key'
UNION ALL
SELECT 'LCK_M_RX_U', 'LOCK - Waiting to acquire an Update lock on the current key value, and an Exclusive range lock between the current and previous key'
UNION ALL
SELECT 'LCK_M_RX_X', 'LOCK - Waiting to acquire an Exclusive lock on the current key value, and an Exclusive Range lock between the current and previous key'
UNION ALL
SELECT 'LCK_M_S', 'LOCK - Waiting to acquire a Shared lock'
UNION ALL
SELECT 'LCK_M_SCH_M', 'LOCK - Waiting to acquire a Schema Modify lock'
UNION ALL
SELECT 'LCK_M_SCH_S', 'LOCK - Waiting to acquire a Schema Modify lock'
UNION ALL
SELECT 'LCK_M_SIU', 'LOCK - Waiting to acquire a Shared With Intent Update lock'
UNION ALL
SELECT 'LCK_M_SIX', 'LOCK - Waiting to acquire a Shared With Intent Exclusive lock'
UNION ALL
SELECT 'LCK_M_U', 'LOCK - Waiting to acquire an Update lock'
UNION ALL
SELECT 'LCK_M_UIX', 'LOCK - Waiting to acquire an Update With Intent Exclusive lock'
UNION ALL
SELECT 'LCK_M_X', 'LOCK - Waiting to acquire an Exclusive lock'
UNION ALL
SELECT 'LATCH_DT', 'LOCK - Waiting for a DT (destroy) latch. This does not include buffer latches or transaction mark latches'
UNION ALL
SELECT 'LATCH_EX', 'LOCK - Waiting for an EX (exclusive) latch. This does not include buffer latches or transaction mark latches'
UNION ALL
SELECT 'LATCH_KP', 'LOCK - Waiting for a KP (keep) latch. This does not include buffer latches or transaction mark latches'
UNION ALL
SELECT 'LATCH_SH', 'LOCK - Waiting for an SH (share) latch. This does not include buffer latches or transaction mark latches'
UNION ALL
SELECT 'LATCH_UP', 'LOCK - Waiting for an UP (update) latch. This does not include buffer latches or transaction mark latches'
UNION ALL
SELECT 'RESOURCE_SEMAPHORE',
'MEMORY - Query memory request cannot be granted immediately due to other concurrent queries. High waits and wait times may indicate excessive number of concurrent queries, or excessive memory request amounts'
UNION ALL
SELECT 'RESOURCE_SEMAPHORE_MUTEX', 'MEMORY - Query waits for its request for a thread reservation to be fulfilled. It also occurs when synchronizing query compile and memory grant requests'
UNION ALL
SELECT 'RESOURCE_SEMAPHORE_QUERY_COMPILE',
'MEMORY - Number of concurrent query compilations reaches a throttling limit. High waits and wait times may indicate excessive compilations, recompiles, or uncachable plans'
UNION ALL
SELECT 'RESOURCE_SEMAPHORE_SMALL_QUERY',
'MEMORY - Memory request by a small query cannot be granted immediately due to other concurrent queries. Wait time should not exceed more than a few seconds. High waits may indicate an excessive number of concurrent small queries while the main memory pool is blocked by waiting queries'
UNION ALL
SELECT 'WRITELOG', 'MEMORY - Waiting for a log flush to complete. Common operations that cause log flushes are checkpoints and transaction commits'
UNION ALL
SELECT 'PAGEIOLATCH_DT', 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Destroy mode. Long waits may indicate problems with the disk subsystem'
UNION ALL
SELECT 'PAGEIOLATCH_EX', 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Exclusive mode. Long waits may indicate problems with the disk subsystem'
UNION ALL
SELECT 'PAGEIOLATCH_KP', 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Keep mode. Long waits may indicate problems with the disk subsystem'
UNION ALL
SELECT 'PAGEIOLATCH_SH', 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Share mode. Long waits may indicate problems with the disk subsystem'
UNION ALL
SELECT 'PAGEIOLATCH_UP', 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Update mode. Long waits may indicate problems with the disk subsystem'
UNION ALL
SELECT 'PAGELATCH_DT', 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Destroy mode'
UNION ALL
SELECT 'PAGELATCH_EX', 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Exclusive mode'
UNION ALL
SELECT 'PAGELATCH_KP', 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Keep mode'
UNION ALL
SELECT 'PAGELATCH_SH', 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Shared mode'
UNION ALL
SELECT 'PAGELATCH_UP', 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Update mode'
UNION ALL
SELECT 'LOGBUFFER',
'DISK - Waiting for space in the log buffer to store a log record. Consistently high values may indicate that the log devices cannot keep up with the amount of log being generated by the server'
UNION ALL
SELECT 'ASYNC_IO_COMPLETION', 'DISK - Waiting for I/Os to finish'
UNION ALL
SELECT 'IO_COMPLETION', 'DISK - Waiting for I/O operations to complete. This wait type generally represents non-data page I/Os. Data page I/O completion waits appear as PAGEIOLATCH_* waits'
) b(wait_type, comment)
) b ON a.wait_type = b.wait_type
ORDER BY a.wait_time_ms DESC;




Not a DBA, just trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


LinkedIn | Blog coming soon (for sufficiently large values of "soon" )!
Post #1388694
Posted Monday, November 26, 2012 10:20 AM


SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, July 17, 2014 1:31 PM
Points: 439, Visits: 591
Elegant, reduced the logical reads needed to complete the query.
Post #1388715
Posted Monday, November 26, 2012 10:50 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, July 18, 2014 12:37 PM
Points: 312, Visits: 1,098
The temp tables are used to add the possible issues to the results.


Post #1388729
Posted Monday, November 26, 2012 10:52 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, July 18, 2014 12:37 PM
Points: 312, Visits: 1,098
Thanks Greg for the updated code. As we all know there are more than one way to skin SQL server

Rudy



Post #1388731
Posted Monday, November 26, 2012 12:43 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Wednesday, July 16, 2014 10:27 AM
Points: 406, Visits: 435
Cadavre (11/26/2012)
Why do you need the temporary tables?


Good one Cadavre! Your derived tables got me thinking about it some more. I took out that big constant scan with all the UNIONs I used before and turned it into a CASE statement. That removed the need for a JOIN.

;WITH sdows AS (
SELECT
wait_type
,waiting_tasks_count
,wait_time_ms
,max_wait_time_ms
,signal_wait_time_ms
,'comment' = CASE
WHEN wait_type = 'SOS_SCHEDULER_YIELD' THEN 'CPU - Execute this script: SELECT scheduler_id, current_tasks_count, runnable_tasks_count FROM sys.dm_os_schedulers WHERE scheduler_id < 255 ;If runnable tasks count > zero, CPU issues if double digits for any length of time, extreme CPU concern'
WHEN wait_type = 'CXPACKET' THEN 'SETTINGS OR CODE - Wait stats shows more than 5% of your waits are on CXPackets, you may want to test lower (or non-zero) values of “max degree of parallelism”. Never set value great than # of CPUs'
WHEN wait_type = 'ASYNC_NETWORK_IO' THEN 'NETWORK - Occurs on network writes when the task is blocked behind the network'
WHEN wait_type = 'LCK_M_BU' THEN 'LOCK - Waiting to acquire a Bulk Update (BU) lock'
WHEN wait_type = 'LCK_M_IS' THEN 'LOCK - Waiting to acquire an Intent Shared (IS) lock'
WHEN wait_type = 'LCK_M_IU' THEN 'LOCK - Waiting to acquire an Intent Update (IU) lock '
WHEN wait_type = 'LCK_M_IX' THEN 'LOCK - Waiting to acquire an Intent Exclusive (IX) lock'
WHEN wait_type = 'LCK_M_RIn_NL' THEN 'LOCK - Waiting to acquire a NULL lock on the current key value and an Insert Range lock between the current and previous key'
WHEN wait_type = 'LCK_M_RIn_S' THEN 'LOCK - Waiting to acquire a shared lock on the current key value and an Insert Range lock between the current and previous key'
WHEN wait_type = 'LCK_M_RIn_U' THEN 'LOCK - Waiting to acquire an Update lock on the current key value, and an Insert Range lock between the current and previous key'
WHEN wait_type = 'LCK_M_RIn_X' THEN 'LOCK - Waiting to acquire an Exclusive lock on the current key value, and an Insert Range lock between the current and previous key'
WHEN wait_type = 'LCK_M_RS_S' THEN 'LOCK - Waiting to acquire a Shared lock on the current key value, and a Shared Range lock between the current and previous'
WHEN wait_type = 'LCK_M_RS_U' THEN 'LOCK - Waiting to acquire an Update lock on the current key value, and an Update Range lock between the current and previous key'
WHEN wait_type = 'LCK_M_RX_S' THEN 'LOCK - Waiting to acquire a Shared lock on the current key value, and an Exclusive Range lock between the current and previous key'
WHEN wait_type = 'LCK_M_RX_U' THEN 'LOCK - Waiting to acquire an Update lock on the current key value, and an Exclusive range lock between the current and previous key'
WHEN wait_type = 'LCK_M_RX_X' THEN 'LOCK - Waiting to acquire an Exclusive lock on the current key value, and an Exclusive Range lock between the current and previous key'
WHEN wait_type = 'LCK_M_S' THEN 'LOCK - Waiting to acquire a Shared lock'
WHEN wait_type = 'LCK_M_SCH_M' THEN 'LOCK - Waiting to acquire a Schema Modify lock'
WHEN wait_type = 'LCK_M_SCH_S' THEN 'LOCK - Waiting to acquire a Schema Modify lock'
WHEN wait_type = 'LCK_M_SIU' THEN 'LOCK - Waiting to acquire a Shared With Intent Update lock'
WHEN wait_type = 'LCK_M_SIX' THEN 'LOCK - Waiting to acquire a Shared With Intent Exclusive lock'
WHEN wait_type = 'LCK_M_U' THEN 'LOCK - Waiting to acquire an Update lock'
WHEN wait_type = 'LCK_M_UIX' THEN 'LOCK - Waiting to acquire an Update With Intent Exclusive lock'
WHEN wait_type = 'LCK_M_X' THEN 'LOCK - Waiting to acquire an Exclusive lock'
WHEN wait_type = 'LATCH_DT' THEN 'LOCK - Waiting for a DT (destroy) latch. This does not include buffer latches or transaction mark latches'
WHEN wait_type = 'LATCH_EX' THEN 'LOCK - Waiting for an EX (exclusive) latch. This does not include buffer latches or transaction mark latches'
WHEN wait_type = 'LATCH_KP' THEN 'LOCK - Waiting for a KP (keep) latch. This does not include buffer latches or transaction mark latches'
WHEN wait_type = 'LATCH_SH' THEN 'LOCK - Waiting for an SH (share) latch. This does not include buffer latches or transaction mark latches'
WHEN wait_type = 'LATCH_UP' THEN 'LOCK - Waiting for an UP (update) latch. This does not include buffer latches or transaction mark latches'
WHEN wait_type = 'RESOURCE_SEMAPHORE' THEN 'MEMORY - Query memory request cannot be granted immediately due to other concurrent queries. High waits and wait times may indicate excessive number of concurrent queries, or excessive memory request amounts'
WHEN wait_type = 'RESOURCE_SEMAPHORE_MUTEX' THEN 'MEMORY - Query waits for its request for a thread reservation to be fulfilled. It also occurs when synchronizing query compile and memory grant requests'
WHEN wait_type = 'RESOURCE_SEMAPHORE_QUERY_COMPILE' THEN 'MEMORY - Number of concurrent query compilations reaches a throttling limit. High waits and wait times may indicate excessive compilations, recompiles, or uncachable plans'
WHEN wait_type = 'RESOURCE_SEMAPHORE_SMALL_QUERY' THEN 'MEMORY - Memory request by a small query cannot be granted immediately due to other concurrent queries. Wait time should not exceed more than a few seconds. High waits may indicate an excessive number of concurrent small queries while the main memory pool is blocked by waiting queries'
WHEN wait_type = 'WRITELOG' THEN 'MEMORY - Waiting for a log flush to complete. Common operations that cause log flushes are checkpoints and transaction commits'
WHEN wait_type = 'PAGEIOLATCH_DT' THEN 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Destroy mode. Long waits may indicate problems with the disk subsystem'
WHEN wait_type = 'PAGEIOLATCH_EX' THEN 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Exclusive mode. Long waits may indicate problems with the disk subsystem'
WHEN wait_type = 'PAGEIOLATCH_KP' THEN 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Keep mode. Long waits may indicate problems with the disk subsystem'
WHEN wait_type = 'PAGEIOLATCH_SH' THEN 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Share mode. Long waits may indicate problems with the disk subsystem'
WHEN wait_type = 'PAGEIOLATCH_UP' THEN 'DISK - Waiting on a latch for a buffer that is in an I/O request. The latch request is in Update mode. Long waits may indicate problems with the disk subsystem'
WHEN wait_type = 'PAGELATCH_DT' THEN 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Destroy mode'
WHEN wait_type = 'PAGELATCH_EX' THEN 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Exclusive mode'
WHEN wait_type = 'PAGELATCH_KP' THEN 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Keep mode'
WHEN wait_type = 'PAGELATCH_SH' THEN 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Shared mode'
WHEN wait_type = 'PAGELATCH_UP' THEN 'DISK - Waiting on a latch for a buffer that is not in an I/O request. The latch request is in Update mode'
WHEN wait_type = 'LOGBUFFER' THEN 'DISK - Waiting for space in the log buffer to store a log record. Consistently high values may indicate that the log devices cannot keep up with the amount of log being generated by the server'
WHEN wait_type = 'ASYNC_IO_COMPLETION' THEN 'DISK - Waiting for I/Os to finish'
WHEN wait_type = 'IO_COMPLETION' THEN 'DISK - Waiting for I/O operations to complete. This wait type generally represents non-data page I/Os. Data page I/O completion waits appear as PAGEIOLATCH_* waits'
ELSE NULL
END
FROM
sys.dm_os_wait_stats
WHERE
waiting_tasks_count <> 0
)
SELECT TOP 10
'OS WAIT STATS - WAIT TYPE' = wait_type
,'TASKS WAITING COUNT' = waiting_tasks_count
,'TIME WAITING (MS)' = wait_time_ms
,'MAX TIME WAITING (MS)' = max_wait_time_ms
,'SIGNAL TIME WAITING (MS)' = signal_wait_time_ms
,'POSSIBLE ISSUES' = comment
FROM
sdows
WHERE
comment IS NOT NULL
ORDER BY
wait_time_ms DESC

Rudy Panigas (11/26/2012)
As we all know there are more than one way to skin SQL server


Ain't that the truth, Rudy.
Post #1388797
Posted Tuesday, November 27, 2012 8:28 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Tuesday, July 15, 2014 11:47 AM
Points: 297, Visits: 193
I'm trying to understand the first two sets of results and where they come from in the code. You'll notice I get three result sets back, where do the first two "wait_type" come from and what is their significance?


Thanks!
Nick
Post #1389231
Posted Tuesday, November 27, 2012 8:47 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, July 18, 2014 12:37 PM
Points: 312, Visits: 1,098
nickm_GR (11/27/2012)
I'm trying to understand the first two sets of results and where they come from in the code. You'll notice I get three result sets back, where do the first two "wait_type" come from and what is their significance?


Thanks!
Nick


Hi Nick,

You didn't include the results on your post so I can't help there. As for what this all means? The code was written to provide some direction not as a complete diagnostic tool. You still need to do your internet searches and/or contact MS support. But at least you will have the top 10 issues that you can show to others and/or MS support so that you can get some help.

i'm sure that's not what your looking for here but I can't help diagnose your system without a whole lot more information and time.

Thanks,

Rudy



Post #1389254
Posted Tuesday, November 27, 2012 8:48 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, June 18, 2014 11:40 AM
Points: 26, Visits: 76
Many of us already know how to reset counters on the wait states however I saw a few people posting who are newer at this and want to know how they can determine wait states without it being cumulative since sql start. The command to reset the wait statistics is as follows:

DBCC SQLPERF('sys.dm_os_wait_stats', CLEAR);

As with every other DBCC command, consider the ramifications before executing it and clear only if the benefits outweigh the drawbacks. If for example I had a customer that had always observed sluggishness between 1:30-2:30pm and they wanted to know what the system was waiting on only for that particular hour then clearing the wait stats might make sense. Unfortunately, clearing any of the dm counters means that you could potentially lose a long period of aggregated metrics that might show a more well rounded picture of system since it was built over a long period of time.

While most folks here already know this I am hoping this has helped at least one person

Tony
Post #1389256
Posted Tuesday, November 27, 2012 8:56 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, July 18, 2014 12:37 PM
Points: 312, Visits: 1,098
Excellent Tony. Thanks for the information.

Rudy



Post #1389263
Posted Tuesday, November 27, 2012 12:51 PM


SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, July 17, 2014 1:31 PM
Points: 439, Visits: 591
nickm_GR (11/27/2012)
I'm trying to understand the first two sets of results and where they come from in the code. You'll notice I get three result sets back, where do the first two "wait_type" come from and what is their significance?


Thanks!
Nick


Hi Nick,
I got those too with the original version of the script. I am not familiar with cursors and perhaps it is some artifact of that or a typo. When I ran the code as re-written by either Greg Drake or Cadavre I don't get those extra results, just the nicely formatted table.
Post #1389384
« Prev Topic | Next Topic »

Add to briefcase «««1234»»

Permissions Expand / Collapse