Skip to content

Commit 15a1c16

Browse files
committed
Wait stat Monitoring added
1 parent 012f41a commit 15a1c16

File tree

1 file changed

+185
-0
lines changed

1 file changed

+185
-0
lines changed
Lines changed: 185 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,185 @@
1+
/**********************************************
2+
Monitoring Wait stats
3+
***********************************************/
4+
5+
--========================================--
6+
/*** 1. Monitor Current sessions wait ***/
7+
--========================================--
8+
9+
10+
SELECT
11+
dm_ws.wait_duration_ms,
12+
dm_ws.wait_type,
13+
dm_es.status,
14+
dm_t.TEXT,
15+
dm_qp.query_plan,
16+
dm_ws.session_ID,
17+
dm_es.cpu_time,
18+
dm_es.memory_usage,
19+
dm_es.logical_reads,
20+
dm_es.total_elapsed_time,
21+
dm_es.program_name,
22+
DB_NAME(dm_r.database_id) DatabaseName,
23+
-- Optional columns
24+
dm_ws.blocking_session_id,
25+
dm_r.wait_resource,
26+
dm_es.login_name,
27+
dm_r.command,
28+
dm_r.last_wait_type
29+
FROM sys.dm_os_waiting_tasks dm_ws
30+
INNER JOIN sys.dm_exec_requests dm_r
31+
ON dm_ws.session_id = dm_r.session_id
32+
INNER JOIN sys.dm_exec_sessions dm_es
33+
ON dm_es.session_id = dm_r.session_id
34+
CROSS APPLY sys.dm_exec_sql_text(dm_r.sql_handle) dm_t
35+
CROSS APPLY sys.dm_exec_query_plan(dm_r.plan_handle) dm_qp
36+
WHERE dm_es.is_user_process = 1
37+
GO
38+
39+
--===========================================--
40+
/*** 2. Monior waits for a specific period ***/
41+
--===========================================--
42+
43+
-- Got this from SQLskills.com
44+
-- You can set the time limit in > WAITFOR DELAY '00:30:00';
45+
46+
IF EXISTS (SELECT
47+
*
48+
FROM [tempdb].[sys].[objects]
49+
WHERE [name] = N'##SQLskillsStats1')
50+
DROP TABLE [##SQLskillsStats1];
51+
52+
IF EXISTS (SELECT
53+
*
54+
FROM [tempdb].[sys].[objects]
55+
WHERE [name] = N'##SQLskillsStats2')
56+
DROP TABLE [##SQLskillsStats2];
57+
GO
58+
59+
SELECT
60+
[wait_type],
61+
[waiting_tasks_count],
62+
[wait_time_ms],
63+
[max_wait_time_ms],
64+
[signal_wait_time_ms] INTO ##SQLskillsStats1
65+
FROM sys.dm_os_wait_stats;
66+
GO
67+
68+
WAITFOR DELAY '00:30:00';
69+
GO
70+
71+
SELECT
72+
[wait_type],
73+
[waiting_tasks_count],
74+
[wait_time_ms],
75+
[max_wait_time_ms],
76+
[signal_wait_time_ms] INTO ##SQLskillsStats2
77+
FROM sys.dm_os_wait_stats;
78+
GO
79+
80+
WITH [DiffWaits]
81+
AS (SELECT
82+
-- Waits that weren't in the first snapshot
83+
[ts2].[wait_type],
84+
[ts2].[wait_time_ms],
85+
[ts2].[signal_wait_time_ms],
86+
[ts2].[waiting_tasks_count]
87+
FROM [##SQLskillsStats2] AS [ts2]
88+
LEFT OUTER JOIN [##SQLskillsStats1] AS [ts1]
89+
ON [ts2].[wait_type] = [ts1].[wait_type]
90+
WHERE [ts1].[wait_type] IS NULL
91+
AND [ts2].[wait_time_ms] > 0
92+
UNION
93+
SELECT
94+
-- Diff of waits in both snapshots
95+
[ts2].[wait_type],
96+
[ts2].[wait_time_ms] - [ts1].[wait_time_ms] AS [wait_time_ms],
97+
[ts2].[signal_wait_time_ms] - [ts1].[signal_wait_time_ms] AS [signal_wait_time_ms],
98+
[ts2].[waiting_tasks_count] - [ts1].[waiting_tasks_count] AS [waiting_tasks_count]
99+
FROM [##SQLskillsStats2] AS [ts2]
100+
LEFT OUTER JOIN [##SQLskillsStats1] AS [ts1]
101+
ON [ts2].[wait_type] = [ts1].[wait_type]
102+
WHERE [ts1].[wait_type] IS NOT NULL
103+
AND [ts2].[waiting_tasks_count] - [ts1].[waiting_tasks_count] > 0
104+
AND [ts2].[wait_time_ms] - [ts1].[wait_time_ms] > 0),
105+
[Waits]
106+
AS (SELECT
107+
[wait_type],
108+
[wait_time_ms] / 1000.0 AS [WaitS],
109+
([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS],
110+
[signal_wait_time_ms] / 1000.0 AS [SignalS],
111+
[waiting_tasks_count] AS [WaitCount],
112+
100.0 * [wait_time_ms] / SUM([wait_time_ms]) OVER () AS [Percentage],
113+
ROW_NUMBER() OVER (ORDER BY [wait_time_ms] DESC) AS [RowNum]
114+
FROM [DiffWaits]
115+
WHERE [wait_type] NOT IN (
116+
N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR',
117+
N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH',
118+
N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE',
119+
N'CHKPT', N'CLR_AUTO_EVENT',
120+
N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE',
121+
N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE',
122+
N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD',
123+
N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE',
124+
N'EXECSYNC', N'FSAGENT',
125+
N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX',
126+
N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION',
127+
N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE',
128+
N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE',
129+
N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP',
130+
N'LOGMGR_QUEUE', N'ONDEMAND_TASK_QUEUE',
131+
N'PWAIT_ALL_COMPONENTS_INITIALIZED',
132+
N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP',
133+
N'QDS_SHUTDOWN_QUEUE',
134+
N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP',
135+
N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE',
136+
N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH',
137+
N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP',
138+
N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY',
139+
N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP',
140+
N'SLEEP_SYSTEMTASK', N'SLEEP_TASK',
141+
N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT',
142+
N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH',
143+
N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP',
144+
N'SQLTRACE_WAIT_ENTRIES', N'WAIT_FOR_RESULTS',
145+
N'WAITFOR', N'WAITFOR_TASKSHUTDOWN',
146+
N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG',
147+
N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN',
148+
N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT'))
149+
SELECT
150+
[W1].[wait_type] AS [WaitType],
151+
CAST([W1].[WaitS] AS decimal(16, 2)) AS [Wait_S],
152+
CAST([W1].[ResourceS] AS decimal(16, 2)) AS [Resource_S],
153+
CAST([W1].[SignalS] AS decimal(16, 2)) AS [Signal_S],
154+
[W1].[WaitCount] AS [WaitCount],
155+
CAST([W1].[Percentage] AS decimal(5, 2)) AS [Percentage],
156+
CAST(([W1].[WaitS] / [W1].[WaitCount]) AS decimal(16, 4)) AS [AvgWait_S],
157+
CAST(([W1].[ResourceS] / [W1].[WaitCount]) AS decimal(16, 4)) AS [AvgRes_S],
158+
CAST(([W1].[SignalS] / [W1].[WaitCount]) AS decimal(16, 4)) AS [AvgSig_S]
159+
FROM [Waits] AS [W1]
160+
INNER JOIN [Waits] AS [W2]
161+
ON [W2].[RowNum] <= [W1].[RowNum]
162+
GROUP BY [W1].[RowNum],
163+
[W1].[wait_type],
164+
[W1].[WaitS],
165+
[W1].[ResourceS],
166+
[W1].[SignalS],
167+
[W1].[WaitCount],
168+
[W1].[Percentage]
169+
HAVING SUM([W2].[Percentage]) - [W1].[Percentage] < 95; -- percentage threshold
170+
GO
171+
172+
-- Cleanup
173+
IF EXISTS (SELECT
174+
*
175+
FROM [tempdb].[sys].[objects]
176+
WHERE [name] = N'##SQLskillsStats1')
177+
DROP TABLE [##SQLskillsStats1];
178+
179+
IF EXISTS (SELECT
180+
*
181+
FROM [tempdb].[sys].[objects]
182+
WHERE [name] = N'##SQLskillsStats2')
183+
DROP TABLE [##SQLskillsStats2];
184+
GO
185+

0 commit comments

Comments
 (0)