-
Notifications
You must be signed in to change notification settings - Fork 4
/
Management.BlockingChains.sql
635 lines (598 loc) · 24.1 KB
/
Management.BlockingChains.sql
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
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
/************************************************************************************************
BlockingChains tables
By: Wesley D. Brown
Date: 02/08/2011
**Description**
This uses sys.extended_properties to pull back comments attached to columns and tables.
It requires that MS_Description be the name of the property.
It also pulls back all column definitions stored in the systables for for that database.
Functions:
**End Discription**
**Change Log**
Bug Fix:
**End Change Log**
************************************************************************************************/
/************************************************************************************************
DROP TABLE [dbo].[BlockingChains]
DROP TABLE [dbo].[BlockingChainsHistory]
************************************************************************************************/
GO
IF NOT EXISTS (SELECT *
FROM dbo.sysobjects
WHERE id = Object_id(N'[dbo].[BlockingChains]')
AND Objectproperty(id, N'IsUserTable') = 1)
BEGIN
CREATE TABLE [dbo].[BlockingChains] (
[ServerName] [varchar] (255) NOT NULL,
[SampleTime] [datetime] NOT NULL ,
[Spid] [int] NULL ,
[SpidBlocked] [int] NULL ,
[WaitType] [varchar] (255) NULL ,
[WaitTime] [bigint] NULL ,
[PhysicalIO] [bigint] NULL ,
[CPUInSeconds] [bigint] NULL ,
[MemoryUsed] [bigint] NULL ,
[Name] [nvarchar] (128) NOT NULL ,
[NumberOfOpenTransactions] [tinyint] NULL ,
[Status] [varchar] (20) NULL ,
[HostName] [varchar] (50) NULL ,
[ProgramName] [varchar] (100) NULL ,
[CommandIssued] [varchar] (100) NULL ,
[DomainName] [varchar] (100) NULL ,
[DomainUserName] [varchar] (200) NULL ,
[LoginName] [varchar] (100) NULL ,
[EventTpe] [varchar] (255) NULL ,
[Parameters] [varchar] (255) NULL ,
[EventInfo] [varchar] (4000) NULL ,
[CommandText] [varchar] (max) NULL
)
END
ELSE
BEGIN
PRINT 'Table BlockingChains already exists'
END
IF NOT EXISTS (SELECT *
FROM dbo.sysobjects
WHERE id = Object_id(N'[dbo].[BlockingChainsHistory]')
AND Objectproperty(id, N'IsUserTable') = 1)
BEGIN
CREATE TABLE [dbo].[BlockingChainsHistory] (
[ServerName] [varchar] (255) NOT NULL,
[SampleTime] [datetime] NOT NULL ,
[Spid] [int] NULL ,
[SpidBlocked] [int] NULL ,
[WaitType] [varchar] (255) NULL ,
[WaitTime] [bigint] NULL ,
[PhysicalIO] [bigint] NULL ,
[CPUInSeconds] [bigint] NULL ,
[MemoryUsed] [bigint] NULL ,
[Name] [nvarchar] (128) NOT NULL ,
[NumberOfOpenTransactions] [tinyint] NULL ,
[Status] [varchar] (20) NULL ,
[HostName] [varchar] (50) NULL ,
[ProgramName] [varchar] (100) NULL ,
[CommandIssued] [varchar] (100) NULL ,
[DomainName] [varchar] (100) NULL ,
[DomainUserName] [varchar] (200) NULL ,
[LoginName] [varchar] (100) NULL ,
[EventTpe] [varchar] (255) NULL ,
[Parameters] [varchar] (255) NULL ,
[EventInfo] [varchar] (4000) NULL ,
[CommandText] [varchar] (max) NULL
)
END
ELSE
BEGIN
PRINT 'Table BlockingChainsHistory already exists'
END
--USE Management
GO
---------------------------------------------------------------------------------------
-- AlertOnBlocking
-- by: Wesley D. Brown
-- date: 02/08/2011
-- mod:
-- description:
-- This stored procedure is used to track and alert on blocking chains
--
-- parameters:
-- @Duration DATETIME = '08:00:00', -- Duration of data collection in hours.
-- @IntervalInSeconds INT = 30,-- Approximate time in seconds the gathering interval.
-- @MaximumWaitTime INT = 28000, -- This is in milliseconds.
-- @Recivers VARCHAR(8000) = '[email protected]', -- Who all gets the emails.
-- @ProcessesToIgnore VARCHAR(8000) = '', -- Ignore any processes that you don't want to trigger an alert.
-- @HostsToIgnore VARCHAR(8000) = '', -- Ignore any host that you don't want to trigger an alert.
-- @LoginsToIgnore VARCHAR(8000) = '' -- Ignore any login that you don't want to trigger an alert.
-- usage:
-- EXEC @RC = AlertOnBlocking
-- '08:00:00',
-- 30,
-- 28000,
-- '[email protected]',
-- '',
-- '',
-- ''
-- platforms:
-- SQL Server 2005
-- SQL Server 2008
-- SQL Server 2008 R2
-- tested:
-- SQL Server 2005 SP2
-- SQL Server 2008 R2
---------------------------------------------------------------------------------------
-- *** change log ***
-- Added history table and perge on start up if there is data in the main table
-- *** end change log ***
---------------------------------------------------------------------------------------
--USE <Management>
CREATE PROCEDURE AlertOnBlocking
-- Duration of data collection in hours.
@Duration DATETIME = '08:00:00',
-- Approximate time in seconds the gathering interval.
@IntervalInSeconds INT = 30,
-- This is in milliseconds.
@MaximumWaitTime INT = 28000,
-- Who all gets the emails.
@Recivers VARCHAR(8000) = '[email protected]',
-- Ignore any processes that you don't want to trigger an alert.
@ProcessesToIgnore VARCHAR(8000) = '',
-- Ignore any host that you don't want to trigger an alert.
@HostsToIgnore VARCHAR(8000) = '',
-- Ignore any login that you don't want to trigger an alert.
@LoginsToIgnore VARCHAR(8000) = ''
AS
SET nocount ON
IF EXISTS (SELECT
1
FROM
dbo.BlockingChains)
BEGIN
IF EXISTS (SELECT
*
FROM
dbo.sysobjects
WHERE
id = Object_id(N'[dbo].[BlockingChains]')
AND Objectproperty(id, N'IsTable') = 1)
BEGIN
INSERT INTO dbo.BlockingChainsHistory
SELECT
*
FROM
BlockingChains;
TRUNCATE TABLE dbo.BlockingChains
END
END
CREATE TABLE #active_spids
(
spid INT,
blocked INT,
waittype VARCHAR(255),
waittime BIGINT,
physical_io BIGINT,
cpu BIGINT,
memusage BIGINT,
[dbid] INT,
open_tran TINYINT,
[status] VARCHAR(20),
hostname VARCHAR(50),
[program_name] VARCHAR(100),
cmd VARCHAR(100),
nt_domain VARCHAR(100),
nt_username VARCHAR(200),
loginame VARCHAR(100),
[sql_handle] [BINARY] (20) NOT NULL,
[stmt_start] [INT] NOT NULL,
[stmt_end] [INT] NOT NULL,
[sql_text] [VARCHAR] (MAX)
)
CREATE TABLE #active_spids_info
(
spid INT,
blocked INT,
waittype VARCHAR(255),
waittime BIGINT,
physical_io BIGINT,
cpu BIGINT,
memusage BIGINT,
[dbid] INT,
open_tran TINYINT,
[status] VARCHAR(20),
hostname VARCHAR(50),
[program_name] VARCHAR(100),
cmd VARCHAR(100),
nt_domain VARCHAR(100),
nt_username VARCHAR(200),
loginame VARCHAR(100),
[sql_handle] [BINARY] (20) NOT NULL,
[stmt_start] [INT] NOT NULL,
[stmt_end] [INT] NOT NULL,
eventtype VARCHAR(255),
parameters VARCHAR(255),
eventinfo VARCHAR(4000),
[text] [VARCHAR] (MAX)
)
CREATE TABLE #event_info
(
spid INT,
eventtype VARCHAR(255),
[Parameters] VARCHAR(255),
eventinfo VARCHAR(4000)
)
DECLARE @TerminateGatheringDT DATETIME,-- when to stop gathering
@WaitFor_Interval DATETIME,
@LastRecordingDT DATETIME,
@RecordingDT DATETIME,
@myError INT,-- Local copy of @@ERROR
@myRowCount INT,-- Local copy of @@RowCount
@msgText NVARCHAR(4000),-- for error messages
@dbname VARCHAR(255),
@svrname VARCHAR(255),
@datestart AS DATETIME,
@tstamp VARCHAR(255),
@spid1 VARCHAR(255),
@dbname1 VARCHAR(255),
@status VARCHAR(255),
@hostname VARCHAR(255),
@programname VARCHAR(255),
@cmd VARCHAR(255),
@nt_domain VARCHAR(255),
@nt_username VARCHAR(255),
@loginame VARCHAR(255),
@text VARCHAR(8000),
@msg VARCHAR(8000),
@sub VARCHAR(8000),
@timestamp AS DATETIME,
@spid INT,
@sqlhandle BINARY(20),
@tsqlhandle AS VARCHAR(255),
@waittime VARCHAR(255),
@waittype VARCHAR(255),
@buffer VARCHAR(255),
@diffmsec BIGINT
--SET @Duration = '08:00:00' -- Duration of data collection
--SET @IntervalInSeconds = 30 -- Approx sec in the gathering interval
--SET @MaximumWaitTime = 28000 -- This is in miliseconds!!!
--SET @Recivers = '' --who all gets the emails
SET @diffmsec = Datediff(ms, CONVERT(DATETIME, '00:00:00', 8), @Duration)
SELECT @WaitFor_Interval = Dateadd (s, @IntervalInSeconds,
CONVERT (DATETIME, '00:00:00', 108
)),
@TerminateGatheringDT = Dateadd(ms, @diffmsec, Getdate())
WHILE Getdate() <= @TerminateGatheringDT
BEGIN
TRUNCATE TABLE #active_spids
TRUNCATE TABLE #active_spids_info
TRUNCATE TABLE #event_info
INSERT INTO #active_spids
SELECT spid,
blocked,
waittype,
waittime,
physical_io,
cpu,
[memusage],
a.dbid,
open_tran,
a.status,
hostname,
[program_name],
cmd,
nt_domain,
nt_username,
loginame,
[sql_handle],
[stmt_start],
[stmt_end],
[text]
FROM (SELECT spid,
blocked,
'waittype' = CASE
WHEN waittype = 0x0001 THEN
'Exclusive table lock'
WHEN waittype = 0x0003 THEN
'Exclusive intent lock'
WHEN waittype = 0x0004 THEN
'Shared table lock'
WHEN waittype = 0x0005 THEN
'Exclusive page lock'
WHEN waittype = 0x0006 THEN
'Shared page lock'
WHEN waittype = 0x0007 THEN
'Update page lock'
WHEN waittype = 0x0013 THEN
'Buffer resource lock (exclusive) request'
WHEN waittype = 0x0013 THEN
'Miscellaneous I/O (sort, audit, direct xact log I/O)'
WHEN waittype = 0x0020 THEN 'Buffer in I/O'
WHEN waittype = 0x0022 THEN 'Buffer being dirtied'
WHEN waittype = 0x0023 THEN 'Buffer being dumped'
WHEN waittype = 0x0081 THEN 'Write the TLog'
WHEN waittype = 0x0200 THEN 'Parallel query coordination'
WHEN waittype = 0x0208 THEN 'Parallel query coordination'
WHEN waittype = 0x0420 THEN 'Buffer I/O latch'
WHEN waittype = 0x0421 THEN 'Buffer I/O latch'
WHEN waittype = 0x0422 THEN 'Buffer I/O latch'
WHEN waittype = 0x0423 THEN 'Buffer I/O latch'
WHEN waittype = 0x0424 THEN 'Buffer I/O latch'
WHEN waittype = 0x0425 THEN 'Buffer I/O latch'
WHEN waittype = 0x0800 THEN 'Network I/O completion'
WHEN waittype = 0x8001 THEN 'Exclusive table lock'
WHEN waittype = 0x8003 THEN 'Exclusive intent lock'
WHEN waittype = 0x8004 THEN 'Shared table lock'
WHEN waittype = 0x8005 THEN 'Exclusive page lock'
WHEN waittype = 0x8006 THEN 'Shared page lock'
WHEN waittype = 0x8007 THEN 'Update page lock'
WHEN waittype = 0x8011 THEN
'Buffer resource lock (shared) request'
ELSE 'OLEDB/Miscellaneous'
END,
waittime,
physical_io,
cpu,
[memusage],
sp.dbid,
open_tran,
status,
hostname,
[program_name],
cmd,
nt_domain,
nt_username,
loginame,
[sql_handle],
[stmt_start],
[stmt_end],
[text]
FROM MASTER.dbo.sysprocesses sp WITH(nolock)
CROSS APPLY sys.Dm_exec_sql_text([sql_handle]))a
WHERE blocked > 0
AND waittime > @MaximumWaitTime
UNION ALL
SELECT spid,
blocked,
waittype,
waittime,
physical_io,
cpu,
[memusage],
a.dbid,
open_tran,
a.status,
hostname,
[program_name],
cmd,
nt_domain,
nt_username,
loginame,
[sql_handle],
[stmt_start],
[stmt_end],
[text]
FROM (SELECT spid,
blocked,
'waittype' = CASE
WHEN waittype = 0x0001 THEN
'Exclusive table lock'
WHEN waittype = 0x0003 THEN
'Exclusive intent lock'
WHEN waittype = 0x0004 THEN
'Shared table lock'
WHEN waittype = 0x0005 THEN
'Exclusive page lock'
WHEN waittype = 0x0006 THEN
'Shared page lock'
WHEN waittype = 0x0007 THEN
'Update page lock'
WHEN waittype = 0x0013 THEN
'Buffer resource lock (exclusive) request'
WHEN waittype = 0x0013 THEN
'Miscellaneous I/O (sort, audit, direct xact log I/O)'
WHEN waittype = 0x0020 THEN 'Buffer in I/O'
WHEN waittype = 0x0022 THEN 'Buffer being dirtied'
WHEN waittype = 0x0023 THEN 'Buffer being dumped'
WHEN waittype = 0x0081 THEN 'Write the TLog'
WHEN waittype = 0x0200 THEN 'Parallel query coordination'
WHEN waittype = 0x0208 THEN 'Parallel query coordination'
WHEN waittype = 0x0420 THEN 'Buffer I/O latch'
WHEN waittype = 0x0421 THEN 'Buffer I/O latch'
WHEN waittype = 0x0422 THEN 'Buffer I/O latch'
WHEN waittype = 0x0423 THEN 'Buffer I/O latch'
WHEN waittype = 0x0424 THEN 'Buffer I/O latch'
WHEN waittype = 0x0425 THEN 'Buffer I/O latch'
WHEN waittype = 0x0800 THEN 'Network I/O completion'
WHEN waittype = 0x8001 THEN 'Exclusive table lock'
WHEN waittype = 0x8003 THEN 'Exclusive intent lock'
WHEN waittype = 0x8004 THEN 'Shared table lock'
WHEN waittype = 0x8005 THEN 'Exclusive page lock'
WHEN waittype = 0x8006 THEN 'Shared page lock'
WHEN waittype = 0x8007 THEN 'Update page lock'
WHEN waittype = 0x8011 THEN
'Buffer resource lock (shared) request'
ELSE 'OLEDB/Miscellaneous'
END,
waittime,
physical_io,
cpu,
[memusage],
sp.dbid,
open_tran,
status,
hostname,
[program_name],
cmd,
nt_domain,
nt_username,
loginame,
[sql_handle],
[stmt_start],
[stmt_end],
[text]
FROM MASTER.dbo.sysprocesses sp WITH(nolock)
CROSS APPLY sys.Dm_exec_sql_text([sql_handle])
WHERE spid IN (SELECT blocked
FROM MASTER.dbo.sysprocesses WITH(nolock)
WHERE blocked > 0
AND waittime > @MaximumWaitTime)) a
ORDER BY blocked
--loop through the spids without a cursor
WHILE (SELECT COUNT(spid)
FROM #active_spids) > 0
BEGIN
SET @spid = (SELECT TOP 1 spid
FROM #active_spids
ORDER BY spid)
--grab the top spid
INSERT INTO #active_spids_info
(spid,
blocked,
waittype,
waittime,
physical_io,
cpu,
[memusage],
dbid,
open_tran,
status,
hostname,
[program_name],
cmd,
nt_domain,
nt_username,
loginame,
[sql_handle],
[stmt_start],
[stmt_end],
[text])
SELECT TOP 1 spid,
blocked,
waittype,
waittime,
physical_io,
cpu,
[memusage],
dbid,
open_tran,
status,
hostname,
[program_name],
cmd,
nt_domain,
nt_username,
loginame,
[sql_handle],
[stmt_start],
[stmt_end],
[sql_text]
FROM #active_spids
ORDER BY spid
INSERT INTO #event_info
(eventtype,
parameters,
eventinfo)
EXEC('DBCC INPUTBUFFER (' + @spid + ') WITH NO_INFOMSGS')
--get the inputbuffer
EXEC('update #event_info set spid = '+@spid+' where spid IS NULL')
--add the spid to the input buffer data
SELECT @sqlhandle = sql_handle
FROM #active_spids
WHERE spid = @spid
DELETE FROM #active_spids
WHERE spid = @spid
--remove the spid processed
END
UPDATE #active_spids_info
SET #active_spids_info.eventtype = #event_info.eventtype,
#active_spids_info.parameters = #event_info.parameters,
#active_spids_info.eventinfo = #event_info.eventinfo
FROM #active_spids_info,
#event_info
WHERE #active_spids_info.spid = #event_info.spid
--join all the info into one table
SET @timestamp = Getdate()
--select statement to return results
INSERT INTO dbo.blockingchains
SELECT @@SERVERNAME,
@timestamp AS tstamp,
a.spid,
a.blocked,
a.waittype,
a.waittime,
a.physical_io,
( a.cpu / 1000 ) AS cpu_in_seconds,
a.[memusage],
b.[name],
a.open_tran,
a.status,
a.hostname,
a.[program_name],
a.cmd,
a.nt_domain,
a.nt_username,
a.loginame,
a.eventtype,
a.parameters,
a.eventinfo,
a.TEXT
FROM #active_spids_info a
INNER JOIN MASTER.dbo.sysdatabases b
ON a.dbid = b.dbid
IF ( (SELECT MAX(sampletime)
FROM dbo.blockingchains
WHERE spidblocked = 0
AND programname NOT IN( @ProcessesToIgnore )
AND hostname NOT IN( @HostsToIgnore )
AND ( domainname NOT IN( @LoginsToIgnore )
OR loginname NOT IN( @LoginsToIgnore ) )) =
@timestamp
)
BEGIN
SELECT @sub = 'Blocking Issues - ' + @@SERVERNAME
SELECT @tstamp = sampletime,
@spid1 = spid,
@status = status,
@hostname = Isnull(hostname, ''),
@programname = Isnull([programname], ''),
@cmd = Isnull(commandissued, ''),
@nt_domain = Isnull(domainname, ''),
@nt_username = Isnull(domainusername, ''),
@loginame = Isnull(loginname, ''),
@text = Isnull(commandtext, ''),
@waittime = (SELECT MAX(waittime)
FROM dbo.blockingchains
WHERE sampletime = (SELECT MAX(sampletime)
FROM
dbo.blockingchains)),
@waittype = Isnull(waittype, ''),
@buffer = Isnull(eventinfo, '')
FROM dbo.blockingchains
WHERE sampletime = (SELECT MAX(sampletime)
FROM dbo.blockingchains)
AND spidblocked = 0
SELECT @msg =
'The user below is at the head of the blocking chain on the listed server:'
+ CHAR(13) +
'__________________________________________________________________________'
+
CHAR(13) + 'Server Name:' + @@SERVERNAME + CHAR(13) +
'TimeStamp: ' + @tstamp + CHAR(13) + 'SPID: ' + @spid1 + CHAR(13)
+ 'Login Name: ' + @loginame + CHAR(13) + 'NT Domain: ' + @nt_domain + CHAR(13)
+ 'NT Username: ' + @nt_username + CHAR(13) + 'Host Name: ' + @hostname + CHAR(13)
+ 'Command: ' + @cmd + CHAR(13) + 'Program Name: ' +
@programname + CHAR(13) + 'Wait Type: ' + @waittype + CHAR(13)
+
'Maximum Wait Time For Blocked Thread: ' + @waittime + CHAR(13) +
'Input Buffer: ' + @buffer + CHAR(13) + 'Status: ' + @status +
CHAR(13) + 'SQL String:' + CHAR(13) +
'--WARNING CAN BE LONG AND MAY NOT BE THE WHOLE TEXT!!!--' +
CHAR(13) + @text
EXEC msdb.dbo.Sp_send_dbmail
@recipients = @Recivers,
@body = @msg,
@subject = @sub;
END
WAITFOR delay @WaitFor_Interval -- delay
END
DROP TABLE #active_spids
DROP TABLE #active_spids_info
DROP TABLE #event_info