Using sys.dm_os_wait_stat is not useful for deep troubleshooting because this view contains wait events for ALL processes/queries running on your instance since last restart. Using command “DBCC SQLPERF (‘sys.dm_os_wait_stats’, CLEAR)” we can reset this view with no restart but on big and stressed instances with many processes and applications running this isn’t a real good solution.
SQL 2008 introduce a new powerful and flexible way to collect performance data: Extended Events.
With EE we can collect performance data for a wide range of counters with almost any filter we want.
The following procedure collect and manage asyncronously data of a SINGLE session.
Using this solution you can collect wait events infos of your session while testing or wait events infos about a single user or application.
NOTE: Stats are collected in a fs folder, so watch carefully space used growing while collecting.
--- 1) Drop the monitor session if it exists. IF EXISTS (SELECT * FROM sys.server_event_sessions WHERE name = 'WaitMon') DROP EVENT SESSION WaitMon ON SERVER GO --- 2) Create the new monitor session. CREATE EVENT SESSION WaitMon ON SERVER ADD EVENT sqlos.wait_info (WHERE sqlserver.session_id = 79 ) ---INSERT HERE the session id to monitor ADD TARGET package0.asynchronous_file_target (SET FILENAME = N'S:tempEE_WaitMonStats.xel', ---INSERT HERE the correct path for collected data stats METADATAFILE = N'S:tempEE_WaitMonStats.xem') WITH (max_dispatch_latency = 1 seconds); GO --- 3) Start the Monitor session ALTER EVENT SESSION WaitMon ON SERVER STATE = START; GO --- 4) >>>>>>...run your query or wait for data collection from spid session....<<<<<< --- 5) Stop the Monitor session ALTER EVENT SESSION WaitMon ON SERVER STATE = STOP; GO --- 6) Load collected data in a temp table CREATE TABLE #RawEventData ( Rowid INT IDENTITY PRIMARY KEY, event_data XML); GO INSERT INTO #RawEventData(event_data) SELECT CAST (event_data AS XML) AS event_data FROM sys.fn_xe_file_target_read_file ('S:tempEE_WaitMonStats*.xel', ---INSERT HERE the correct path for collected data stats 'S:tempEE_WaitMonStats*.xem', null, null); GO --- 7) Query data to analize wait events SELECT waits.[Wait Type], COUNT (*) AS [Wait Count], SUM (waits.[Duration]) AS [Total Wait Time (ms)], SUM (waits.[Duration]) - SUM (waits.[Signal Duration]) AS [Total Resource Wait Time (ms)], SUM (waits.[Signal Duration]) AS [Total Signal Wait Time (ms)] FROM (SELECT event_data.value ('(/event/@timestamp)[1]', 'DATETIME') AS [Time], event_data.value ('(/event/data[@name=''wait_type'']/text)[1]', 'VARCHAR(100)') AS [Wait Type], event_data.value ('(/event/data[@name=''opcode'']/text)[1]', 'VARCHAR(100)') AS [Op], event_data.value ('(/event/data[@name=''duration'']/value)[1]', 'BIGINT') AS [Duration], event_data.value ('(/event/data[@name=''signal_duration'']/value)[1]', 'BIGINT') AS [Signal Duration] FROM #RawEventData ) AS waits WHERE waits.[op] = 'End' GROUP BY waits.[Wait Type] ORDER BY [Total Wait Time (ms)] DESC; GO --- 8) Cleanup DROP TABLE #RawEventData; GO