[Edit 2016: Check out my new resource – a comprehensive library of all wait types and latch classes – see here.]
In both my wait statistics pre-conference workshops at the PASS Summit and SQLintersection I promised to do a bunch of blog posts. The first one on the list is a simple script to allow you to capture all the waits that occurred over a period of time.
The script does the following:
- Creates two temporary tables
- Captures the output from sys.dm_os_wait_stats into the first table
- Waits for a configurable delay (line 41 in the script – I made it 30 minutes in the example)
- Captures the output from sys.dm_os_wait_stats into the second table
- Provides my usual wait stats output on the results
Enjoy!
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
| /*============================================================================ File: ShortPeriodWaitStats.sql Summary: Short snapshot of wait stats SQL Server Versions: 2005 onwards ------------------------------------------------------------------------------ Written by Paul S. Randal, SQLskills.com (c) 2014, SQLskills.com. All rights reserved. For more scripts and sample code, check out http://www.SQLskills.com You may alter this code for your own *non-commercial* purposes (e.g. in a for-sale commercial tool). Use in your own environment is encouraged. You may republish altered code as long as you include this copyright and give due credit, but you must obtain prior permission before blogging this code. THIS CODE AND INFORMATION ARE PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE IMPLIED WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A PARTICULAR PURPOSE. ============================================================================*/ IF EXISTS ( SELECT * FROM [tempdb] . [sys] . [objects] WHERE [name] = N'##SQLskillsStats1' ) DROP TABLE [##SQLskillsStats1] ; IF EXISTS ( SELECT * FROM [tempdb] . [sys] . [objects] WHERE [name] = N'##SQLskillsStats2' ) DROP TABLE [##SQLskillsStats2] ; GO SELECT [wait_type] , [waiting_tasks_count] , [wait_time_ms] , [max_wait_time_ms] , [signal_wait_time_ms] INTO ##SQLskillsStats1 FROM sys.dm_os_wait_stats ; GO WAITFOR DELAY '00:30:00' ; GO SELECT [wait_type] , [waiting_tasks_count] , [wait_time_ms] , [max_wait_time_ms] , [signal_wait_time_ms] INTO ##SQLskillsStats2 FROM sys.dm_os_wait_stats ; GO WITH [DiffWaits] AS ( SELECT -- Waits that weren't in the first snapshot [ts2] . [wait_type] , [ts2] . [wait_time_ms] , [ts2] . [signal_wait_time_ms] , [ts2] . [waiting_tasks_count] FROM [##SQLskillsStats2] AS [ts2] LEFT OUTER JOIN [##SQLskillsStats1] AS [ts1] ON [ts2] . [wait_type] = [ts1] . [wait_type] WHERE [ts1] . [wait_type] IS NULL AND [ts2] . [wait_time_ms] > 0 UNION SELECT -- Diff of waits in both snapshots [ts2] . [wait_type] , [ts2] . [wait_time_ms] - [ts1] . [wait_time_ms] AS [wait_time_ms] , [ts2] . [signal_wait_time_ms] - [ts1] . [signal_wait_time_ms] AS [signal_wait_time_ms] , [ts2] . [waiting_tasks_count] - [ts1] . [waiting_tasks_count] AS [waiting_tasks_count] FROM [##SQLskillsStats2] AS [ts2] LEFT OUTER JOIN [##SQLskillsStats1] AS [ts1] ON [ts2] . [wait_type] = [ts1] . [wait_type] WHERE [ts1] . [wait_type] IS NOT NULL AND [ts2] . [waiting_tasks_count] - [ts1] . [waiting_tasks_count] > 0 AND [ts2] . [wait_time_ms] - [ts1] . [wait_time_ms] > 0 ) , [Waits] AS ( SELECT [wait_type] , [wait_time_ms] / 1000 . 0 AS [WaitS] , ( [wait_time_ms] - [signal_wait_time_ms] ) / 1000 . 0 AS [ResourceS] , [signal_wait_time_ms] / 1000 . 0 AS [SignalS] , [waiting_tasks_count] AS [WaitCount] , 100 . 0 * [wait_time_ms] / SUM ( [wait_time_ms] ) OVER ( ) AS [Percentage] , ROW_NUMBER ( ) OVER ( ORDER BY [wait_time_ms] DESC ) AS [RowNum] FROM [DiffWaits] 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_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'KSOURCE_WAKEUP' , N'LAZYWRITER_SLEEP' , N'LOGMGR_QUEUE' , N'ONDEMAND_TASK_QUEUE' , N'PWAIT_ALL_COMPONENTS_INITIALIZED' , N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP' , N'QDS_SHUTDOWN_QUEUE' , N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP' , 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'SLEEP_TEMPDBSTARTUP' , N'SNI_HTTP_ACCEPT' , N'SP_SERVER_DIAGNOSTICS_SLEEP' , N'SQLTRACE_BUFFER_FLUSH' , N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP' , N'SQLTRACE_WAIT_ENTRIES' , N'WAIT_FOR_RESULTS' , N'WAITFOR' , N'WAITFOR_TASKSHUTDOWN' , N'WAIT_XTP_HOST_WAIT' , N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG' , N'WAIT_XTP_CKPT_CLOSE' , N'XE_DISPATCHER_JOIN' , N'XE_DISPATCHER_WAIT' , N'XE_TIMER_EVENT' ) ) SELECT [W1] . [wait_type] AS [WaitType] , CAST ( [W1] . [WaitS] AS DECIMAL ( 16 , 2 ) ) AS [Wait_S] , CAST ( [W1] . [ResourceS] AS DECIMAL ( 16 , 2 ) ) AS [Resource_S] , CAST ( [W1] . [SignalS] AS DECIMAL ( 16 , 2 ) ) AS [Signal_S] , [W1] . [WaitCount] AS [WaitCount] , CAST ( [W1] . [Percentage] AS DECIMAL ( 5 , 2 ) ) AS [Percentage] , CAST ( ( [W1] . [WaitS] / [W1] . [WaitCount] ) AS DECIMAL ( 16 , 4 ) ) AS [AvgWait_S] , CAST ( ( [W1] . [ResourceS] / [W1] . [WaitCount] ) AS DECIMAL ( 16 , 4 ) ) AS [AvgRes_S] , CAST ( ( [W1] . [SignalS] / [W1] . [WaitCount] ) AS DECIMAL ( 16 , 4 ) ) AS [AvgSig_S] FROM [Waits] AS [W1] INNER JOIN [Waits] AS [W2] ON [W2] . [RowNum] < = [W1] . [RowNum] GROUP BY [W1] . [RowNum] , [W1] . [wait_type] , [W1] . [WaitS] , [W1] . [ResourceS] , [W1] . [SignalS] , [W1] . [WaitCount] , [W1] . [Percentage] HAVING SUM ( [W2] . [Percentage] ) - [W1] . [Percentage] < 95 ; -- percentage threshold GO -- Cleanup IF EXISTS ( SELECT * FROM [tempdb] . [sys] . [objects] WHERE [name] = N'##SQLskillsStats1' ) DROP TABLE [##SQLskillsStats1] ; IF EXISTS ( SELECT * FROM [tempdb] . [sys] . [objects] WHERE [name] = N'##SQLskillsStats2' ) DROP TABLE [##SQLskillsStats2] ; GO |
No hay comentarios.:
Publicar un comentario