• 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.