Yesterday I posted a blog about a new DMV, which is introduced in SQL Server 2016. You can read the blog post here: Get Wait Stats Related to Specific Session ID With sys.dm_exec_session_wait_stats. After reading the blog post, I have received quite a few emails about SQL Server Wait Stats Collection Scripts. One of the question was is my earlier script still valid to collect the SQL Wait Stats for SQL Server 2016 and Later Versions.
Well, the answer is of course YES! The earlier scripts are still valid and they were written such a way that they work for all the versions of SQL Server.
However, of course, there are a few enhancements in recent versions of SQL Server. There were quite a few more wait stats were added as well as from SQL Server 2016, the wait stat collection scripts needed to be updated to reflect the same. Hence, I have rebuilt the Wait Stats Collection Scripts so it also includes the latest information.
/* Script to Clear Wait Types DBCC SQLPERF('sys.dm_os_wait_stats', CLEAR); GO */ -- SQL Wait Stats and Queies -- (C) Pinal Dave (https://blog.sqlauthority.com) 2017 -- Send query result to pinal@sqlauthority.com for quick feedback on resource bottlenecks SELECT wait_type AS Wait_Type, wait_time_ms / 1000.0 AS Wait_Time_Seconds, waiting_tasks_count AS Waiting_Tasks_Count, -- CAST((wait_time_ms / 1000.0)/waiting_tasks_count AS decimal(10,4)) AS AVG_Waiting_Tasks_Count, wait_time_ms * 100.0 / SUM(wait_time_ms) OVER() AS Percentage_WaitTime --,waiting_tasks_count * 100.0 / SUM(waiting_tasks_count) OVER() AS Percentage_Count FROM sys.dm_os_wait_stats WHERE wait_type NOT IN (N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH', N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE', N'CHKPT', N'CLR_AUTO_EVENT', N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE', N'DBMIRROR_DBM_EVENT', N'DBMIRROR_DBM_MUTEX', N'DBMIRROR_EVENTS_QUEUE', N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD', N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE', N'EXECSYNC', N'FSAGENT', N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX', N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE', N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE', N'LAZYWRITER_SLEEP', N'LOGMGR_QUEUE', N'MEMORY_ALLOCATION_EXT', N'ONDEMAND_TASK_QUEUE', N'PREEMPTIVE_HADR_LEASE_MECHANISM', N'PREEMPTIVE_OS_AUTHENTICATIONOPS', N'PREEMPTIVE_OS_AUTHORIZATIONOPS', N'PREEMPTIVE_OS_COMOPS', N'PREEMPTIVE_OS_CREATEFILE', N'PREEMPTIVE_OS_CRYPTOPS', N'PREEMPTIVE_OS_DEVICEOPS', N'PREEMPTIVE_OS_FILEOPS', N'PREEMPTIVE_OS_GENERICOPS', N'PREEMPTIVE_OS_LIBRARYOPS', N'PREEMPTIVE_OS_PIPEOPS', N'PREEMPTIVE_OS_QUERYREGISTRY', N'PREEMPTIVE_OS_VERIFYTRUST', N'PREEMPTIVE_OS_WAITFORSINGLEOBJECT', N'PREEMPTIVE_OS_WRITEFILEGATHER', N'PREEMPTIVE_SP_SERVER_DIAGNOSTICS', N'PREEMPTIVE_XE_GETTARGETSTATE', N'PWAIT_ALL_COMPONENTS_INITIALIZED', N'PWAIT_DIRECTLOGCONSUMER_GETNEXT', N'QDS_ASYNC_QUEUE', N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', N'QDS_SHUTDOWN_QUEUE', N'REDO_THREAD_PENDING_WORK', N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE', N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP', N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY', N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', N'SLEEP_SYSTEMTASK', N'SLEEP_TASK', N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', N'SQLTRACE_WAIT_ENTRIES', N'UCS_SESSION_REGISTRATION', N'WAIT_FOR_RESULTS', N'WAIT_XTP_CKPT_CLOSE', N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', N'WAIT_XTP_RECOVERY', N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', N'XE_TIMER_EVENT', N'XE_DISPATCHER_WAIT', N'XE_LIVE_TARGET_TVF' ) AND wait_time_ms >= 1 ORDER BY Wait_Time_Seconds DESC -- OPTION (MAXDOP 1) -- ORDER BY Waiting_Tasks_Count DESC
Now a days, I use this new wait stats collection scripts in my Comprehensive Database Performance Health Check service when we have to identify which particular session is facing the most bottlenecks. If you send me the results of the query to me in an email, I will be happy to do give you my opinion about your top wait statistics and how you can optimize your system for free.
Just drop an email with the results of the query in excel and I will respond promptly.
Reference: Pinal Dave (https://blog.sqlauthority.com)