forked from BrentOzarULTD/SQL-Server-First-Responder-Kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathsp_BlitzFirst.sql
2624 lines (2441 loc) · 157 KB
/
sp_BlitzFirst.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
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
IF OBJECT_ID('dbo.sp_BlitzFirst') IS NULL
EXEC ('CREATE PROCEDURE dbo.sp_BlitzFirst AS RETURN 0;')
GO
ALTER PROCEDURE [dbo].[sp_BlitzFirst]
@Question NVARCHAR(MAX) = NULL ,
@Help TINYINT = 0 ,
@AsOf DATETIMEOFFSET = NULL ,
@ExpertMode TINYINT = 0 ,
@Seconds INT = 5 ,
@OutputType VARCHAR(20) = 'TABLE' ,
@OutputServerName NVARCHAR(256) = NULL ,
@OutputDatabaseName NVARCHAR(256) = NULL ,
@OutputSchemaName NVARCHAR(256) = NULL ,
@OutputTableName NVARCHAR(256) = NULL ,
@OutputTableNameFileStats NVARCHAR(256) = NULL ,
@OutputTableNamePerfmonStats NVARCHAR(256) = NULL ,
@OutputTableNameWaitStats NVARCHAR(256) = NULL ,
@OutputXMLasNVARCHAR TINYINT = 0 ,
@FilterPlansByDatabase VARCHAR(MAX) = NULL ,
@CheckProcedureCache TINYINT = 0 ,
@FileLatencyThresholdMS INT = 100 ,
@SinceStartup TINYINT = 0 ,
@VersionDate DATETIME = NULL OUTPUT
WITH EXECUTE AS CALLER, RECOMPILE
AS
BEGIN
SET NOCOUNT ON;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SET @VersionDate = '20160626'
IF @Help = 1 PRINT '
sp_BlitzFirst from http://FirstResponderKit.org
This script gives you a prioritized list of why your SQL Server is slow right now.
This is not an overall health check - for that, check out sp_Blitz.
To learn more, visit http://FirstResponderKit.org where you can download new
versions for free, watch training videos on how it works, get more info on
the findings, contribute your own code, and more.
Known limitations of this version:
- Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000. It
may work just fine on 2005, and if it does, hug your parents. Just don''t
file support issues if it breaks.
- If a temp table called #CustomPerfmonCounters exists for any other session,
but not our session, this stored proc will fail with an error saying the
temp table #CustomPerfmonCounters does not exist.
- @OutputServerName is not functional yet.
Unknown limitations of this version:
- None. Like Zombo.com, the only limit is yourself.
Changes in v24 - 2016/06/26
- Renamed from sp_AskBrent.
- BREAKING CHANGE: Standardized input & output parameters to be
consistent across the entire First Responder Kit. This also means the old
old output parameter @Version is no more, because we are switching to
semantic versioning. More info:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/284
- BREAKING CHANGE: The CheckDate field datatype is now DATETIMEOFFSET. This
makes it easier to combine results from multiple servers into one table even
when servers are in different data centers, different time zones. More info:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/288
- Added BROKER_TRANSMITTER to list of ignorable wait types. More info:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/268
- Also ignore REDO_THREAD_PENDING_WORK, UCS_SESSION_REGISTRATION. More info:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/174
- Only show what queries are running now if @ExpertMode = 1. More info:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/266
Changes in v23 - April 27, 2016
- Christopher Whitcome fixed a bug in the new active-queries result set. Thanks!
Changes in v22 - April 19, 2016
- New @SinceStartup parameter. Defaults to 0. When turned on with 1, it sets
@Seconds = 0, @ExpertMode = 1, and skips results for what is running now and
the headline-news result set (the first two).
- If @Seconds = 0, output waits in hours instead of seconds. This only changes
the onscreen results - not the table results, because I try not to break the
existing table storage by changing output data.
- Added wait time per core per second (or per hour) in the ExpertMode wait
stats output.
MIT License
Copyright (c) 2016 Brent Ozar Unlimited
Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software without restriction, including without limitation the rights
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:
The above copyright notice and this permission notice shall be included in all
copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.
'
RAISERROR('Setting up configuration variables',10,1) WITH NOWAIT;
DECLARE @StringToExecute NVARCHAR(4000),
@ParmDefinitions NVARCHAR(4000),
@Parm1 NVARCHAR(4000),
@OurSessionID INT,
@LineFeed NVARCHAR(10),
@StockWarningHeader NVARCHAR(500),
@StockWarningFooter NVARCHAR(100),
@StockDetailsHeader NVARCHAR(100),
@StockDetailsFooter NVARCHAR(100),
@StartSampleTime DATETIMEOFFSET,
@FinishSampleTime DATETIMEOFFSET,
@FinishSampleTimeWaitFor DATETIME,
@ServiceName sysname,
@OutputTableNameFileStats_View NVARCHAR(256),
@OutputTableNamePerfmonStats_View NVARCHAR(256),
@OutputTableNameWaitStats_View NVARCHAR(256),
@ObjectFullName NVARCHAR(2000);
/* Sanitize our inputs */
SELECT
@OutputTableNameFileStats_View = QUOTENAME(@OutputTableNameFileStats + '_Deltas'),
@OutputTableNamePerfmonStats_View = QUOTENAME(@OutputTableNamePerfmonStats + '_Deltas'),
@OutputTableNameWaitStats_View = QUOTENAME(@OutputTableNameWaitStats + '_Deltas');
SELECT
@OutputDatabaseName = QUOTENAME(@OutputDatabaseName),
@OutputSchemaName = QUOTENAME(@OutputSchemaName),
@OutputTableName = QUOTENAME(@OutputTableName),
@OutputTableNameFileStats = QUOTENAME(@OutputTableNameFileStats),
@OutputTableNamePerfmonStats = QUOTENAME(@OutputTableNamePerfmonStats),
@OutputTableNameWaitStats = QUOTENAME(@OutputTableNameWaitStats),
@LineFeed = CHAR(13) + CHAR(10),
@StartSampleTime = SYSDATETIMEOFFSET(),
@FinishSampleTime = DATEADD(ss, @Seconds, SYSDATETIMEOFFSET()),
@FinishSampleTimeWaitFor = DATEADD(ss, @Seconds, GETDATE()),
@OurSessionID = @@SPID;
IF @SinceStartup = 1
SELECT @Seconds = 0, @ExpertMode = 1;
IF @Seconds = 0 AND CAST(SERVERPROPERTY('edition') AS VARCHAR(100)) = 'SQL Azure'
SELECT @StartSampleTime = DATEADD(ms, AVG(-wait_time_ms), SYSDATETIMEOFFSET()), @FinishSampleTime = SYSDATETIMEOFFSET()
FROM sys.dm_os_wait_stats w
WHERE wait_type IN ('BROKER_TASK_STOP','DIRTY_PAGE_POLL','HADR_FILESTREAM_IOMGR_IOCOMPLETION','LAZYWRITER_SLEEP',
'LOGMGR_QUEUE','REQUEST_FOR_DEADLOCK_SEARCH','XE_DISPATCHER_WAIT','XE_TIMER_EVENT')
ELSE IF @Seconds = 0 AND CAST(SERVERPROPERTY('edition') AS VARCHAR(100)) <> 'SQL Azure'
SELECT @StartSampleTime = create_date , @FinishSampleTime = SYSDATETIMEOFFSET()
FROM sys.databases
WHERE database_id = 2;
ELSE
SELECT @StartSampleTime = SYSDATETIMEOFFSET(), @FinishSampleTime = DATEADD(ss, @Seconds, SYSDATETIMEOFFSET());
IF @OutputType = 'SCHEMA'
BEGIN
SELECT FieldList = '[Priority] TINYINT, [FindingsGroup] VARCHAR(50), [Finding] VARCHAR(200), [URL] VARCHAR(200), [Details] NVARCHAR(4000), [HowToStopIt] NVARCHAR(MAX), [QueryPlan] XML, [QueryText] NVARCHAR(MAX)'
END
ELSE IF @AsOf IS NOT NULL AND @OutputDatabaseName IS NOT NULL AND @OutputSchemaName IS NOT NULL AND @OutputTableName IS NOT NULL
BEGIN
/* They want to look into the past. */
SET @StringToExecute = N' IF EXISTS(SELECT * FROM '
+ @OutputDatabaseName
+ '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = '''
+ @OutputSchemaName + ''') SELECT CheckDate, [Priority], [FindingsGroup], [Finding], [URL], CAST([Details] AS [XML]) AS Details,'
+ '[HowToStopIt], [CheckID], [StartTime], [LoginName], [NTUserName], [OriginalLoginName], [ProgramName], [HostName], [DatabaseID],'
+ '[DatabaseName], [OpenTransactionCount], [QueryPlan], [QueryText] FROM '
+ @OutputDatabaseName + '.'
+ @OutputSchemaName + '.'
+ @OutputTableName
+ ' WHERE CheckDate >= DATEADD(mi, -15, ''' + CAST(@AsOf AS NVARCHAR(100)) + ''')'
+ ' AND CheckDate <= DATEADD(mi, 15, ''' + CAST(@AsOf AS NVARCHAR(100)) + ''')'
+ ' /*ORDER BY CheckDate, Priority , FindingsGroup , Finding , Details*/;';
EXEC(@StringToExecute);
END /* IF @AsOf IS NOT NULL AND @OutputDatabaseName IS NOT NULL AND @OutputSchemaName IS NOT NULL AND @OutputTableName IS NOT NULL */
ELSE IF @Question IS NULL /* IF @OutputType = 'SCHEMA' */
BEGIN
/* What's running right now? This is the first result set. */
IF @@VERSION LIKE 'Microsoft SQL Server 2005%'
BEGIN
SET @StringToExecute = 'SELECT [r].[start_time] ,
CONVERT(VARCHAR, DATEADD(ms, [r].[total_elapsed_time], 0), 114) AS [elapsed_time] ,
[s].[session_id] ,
[s].[status] ,
[dest].[text] ,
[deqp].[query_plan] ,
[s].[cpu_time] ,
[s].[memory_usage] ,
[s].[reads] ,
[s].[writes] ,
[s].[logical_reads] ,
[r].[blocking_session_id] ,
[r].[wait_type] ,
[r].[wait_time] ,
[r].[last_wait_type] ,
[r].[wait_resource] ,
[r].[estimated_completion_time] ,
[r].[deadlock_priority] ,
[r].[granted_query_memory] ,
CASE [s].[transaction_isolation_level]
WHEN 0 THEN ''Unspecified''
WHEN 1 THEN ''Read Uncommitted''
WHEN 2 THEN ''Read Committed''
WHEN 3 THEN ''Repeatable Read''
WHEN 4 THEN ''Serializable''
WHEN 5 THEN ''Snapshot''
ELSE ''WHAT HAVE YOU DONE?''
END AS [transaction_isolation_level] ,
[s].[nt_domain] ,
[s].[host_name] ,
[s].[nt_user_name] ,
[s].[program_name] ,
[s].[client_interface_name],
[r].sql_handle,
[r].plan_handle
FROM [sys].[dm_exec_sessions] AS [s]
JOIN [sys].[dm_exec_requests] AS [r]
ON [r].[session_id] = [s].[session_id]
CROSS APPLY [sys].[dm_exec_sql_text]([r].[sql_handle]) AS [dest]
OUTER APPLY [sys].[dm_exec_query_plan]([r].[plan_handle]) AS [deqp]
WHERE [r].[session_id] <> @@SPID
AND [s].[is_user_process] = 1
ORDER BY [r].[start_time];'
END
ELSE
BEGIN
SET @StringToExecute = 'SELECT [r].[start_time] ,
CONVERT(VARCHAR, DATEADD(ms, [r].[total_elapsed_time], 0), 114) AS [elapsed_time] ,
[s].[session_id] ,
DB_NAME([r].[database_id]) AS [DatabaseName] ,
[s].[status] ,
[dest].[text] ,
[deqp].[query_plan] ,
[s].[cpu_time] ,
[s].[memory_usage] ,
[s].[reads] ,
[s].[writes] ,
[s].[logical_reads] ,
[r].[blocking_session_id] ,
[r].[wait_type] ,
[r].[wait_time] ,
[r].[last_wait_type] ,
[r].[wait_resource] ,
[r].[estimated_completion_time] ,
[r].[open_transaction_count] ,
[r].[deadlock_priority] ,
[r].[granted_query_memory] ,
CASE [s].[transaction_isolation_level]
WHEN 0 THEN ''Unspecified''
WHEN 1 THEN ''Read Uncommitted''
WHEN 2 THEN ''Read Committed''
WHEN 3 THEN ''Repeatable Read''
WHEN 4 THEN ''Serializable''
WHEN 5 THEN ''Snapshot''
ELSE ''WHAT HAVE YOU DONE?''
END AS [transaction_isolation_level] ,
[s].[nt_domain] ,
[s].[host_name] ,
[s].[nt_user_name] ,
[s].[program_name] ,
[s].[client_interface_name],
[r].sql_handle,
[r].plan_handle
FROM [sys].[dm_exec_sessions] AS [s]
JOIN [sys].[dm_exec_requests] AS [r]
ON [r].[session_id] = [s].[session_id]
CROSS APPLY [sys].[dm_exec_sql_text]([r].[sql_handle]) AS [dest]
OUTER APPLY [sys].[dm_exec_query_plan]([r].[plan_handle]) AS [deqp]
WHERE [r].[session_id] <> @@SPID
AND [s].[is_user_process] = 1
ORDER BY [r].[start_time];'
END
IF @SinceStartup = 0 AND @Seconds > 0 AND @ExpertMode = 1
EXEC(@StringToExecute);
RAISERROR('Now starting diagnostic analysis',10,1) WITH NOWAIT;
/*
We start by creating #AskBrentResults. It's a temp table that will store
the results from our checks. Throughout the rest of this stored procedure,
we're running a series of checks looking for dangerous things inside the SQL
Server. When we find a problem, we insert rows into #BlitzResults. At the
end, we return these results to the end user.
#AskBrentResults has a CheckID field, but there's no Check table. As we do
checks, we insert data into this table, and we manually put in the CheckID.
We (Brent Ozar Unlimited) maintain a list of the checks by ID#. You can
download that from http://FirstResponderKit.org if you want to build
a tool that relies on the output of sp_BlitzFirst.
*/
IF OBJECT_ID('tempdb..#AskBrentResults') IS NOT NULL
DROP TABLE #AskBrentResults;
CREATE TABLE #AskBrentResults
(
ID INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
CheckID INT NOT NULL,
Priority TINYINT NOT NULL,
FindingsGroup VARCHAR(50) NOT NULL,
Finding VARCHAR(200) NOT NULL,
URL VARCHAR(200) NULL,
Details NVARCHAR(4000) NULL,
HowToStopIt NVARCHAR(MAX) NULL,
QueryPlan [XML] NULL,
QueryText NVARCHAR(MAX) NULL,
StartTime DATETIMEOFFSET NULL,
LoginName NVARCHAR(128) NULL,
NTUserName NVARCHAR(128) NULL,
OriginalLoginName NVARCHAR(128) NULL,
ProgramName NVARCHAR(128) NULL,
HostName NVARCHAR(128) NULL,
DatabaseID INT NULL,
DatabaseName NVARCHAR(128) NULL,
OpenTransactionCount INT NULL,
QueryStatsNowID INT NULL,
QueryStatsFirstID INT NULL,
PlanHandle VARBINARY(64) NULL,
DetailsInt INT NULL,
);
IF OBJECT_ID('tempdb..#WaitStats') IS NOT NULL
DROP TABLE #WaitStats;
CREATE TABLE #WaitStats (Pass TINYINT NOT NULL, wait_type NVARCHAR(60), wait_time_ms BIGINT, signal_wait_time_ms BIGINT, waiting_tasks_count BIGINT, SampleTime DATETIMEOFFSET);
IF OBJECT_ID('tempdb..#FileStats') IS NOT NULL
DROP TABLE #FileStats;
CREATE TABLE #FileStats (
ID INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
Pass TINYINT NOT NULL,
SampleTime DATETIMEOFFSET NOT NULL,
DatabaseID INT NOT NULL,
FileID INT NOT NULL,
DatabaseName NVARCHAR(256) ,
FileLogicalName NVARCHAR(256) ,
TypeDesc NVARCHAR(60) ,
SizeOnDiskMB BIGINT ,
io_stall_read_ms BIGINT ,
num_of_reads BIGINT ,
bytes_read BIGINT ,
io_stall_write_ms BIGINT ,
num_of_writes BIGINT ,
bytes_written BIGINT,
PhysicalName NVARCHAR(520) ,
avg_stall_read_ms INT ,
avg_stall_write_ms INT
);
IF OBJECT_ID('tempdb..#QueryStats') IS NOT NULL
DROP TABLE #QueryStats;
CREATE TABLE #QueryStats (
ID INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
Pass INT NOT NULL,
SampleTime DATETIMEOFFSET NOT NULL,
[sql_handle] VARBINARY(64),
statement_start_offset INT,
statement_end_offset INT,
plan_generation_num BIGINT,
plan_handle VARBINARY(64),
execution_count BIGINT,
total_worker_time BIGINT,
total_physical_reads BIGINT,
total_logical_writes BIGINT,
total_logical_reads BIGINT,
total_clr_time BIGINT,
total_elapsed_time BIGINT,
creation_time DATETIMEOFFSET,
query_hash BINARY(8),
query_plan_hash BINARY(8),
Points TINYINT
);
IF OBJECT_ID('tempdb..#PerfmonStats') IS NOT NULL
DROP TABLE #PerfmonStats;
CREATE TABLE #PerfmonStats (
ID INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
Pass TINYINT NOT NULL,
SampleTime DATETIMEOFFSET NOT NULL,
[object_name] NVARCHAR(128) NOT NULL,
[counter_name] NVARCHAR(128) NOT NULL,
[instance_name] NVARCHAR(128) NULL,
[cntr_value] BIGINT NULL,
[cntr_type] INT NOT NULL,
[value_delta] BIGINT NULL,
[value_per_second] DECIMAL(18,2) NULL
);
IF OBJECT_ID('tempdb..#PerfmonCounters') IS NOT NULL
DROP TABLE #PerfmonCounters;
CREATE TABLE #PerfmonCounters (
ID INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
[object_name] NVARCHAR(128) NOT NULL,
[counter_name] NVARCHAR(128) NOT NULL,
[instance_name] NVARCHAR(128) NULL
);
IF OBJECT_ID('tempdb..#FilterPlansByDatabase') IS NOT NULL
DROP TABLE #FilterPlansByDatabase;
CREATE TABLE #FilterPlansByDatabase (DatabaseID INT PRIMARY KEY CLUSTERED);
IF OBJECT_ID('tempdb..#MasterFiles') IS NOT NULL
DROP TABLE #MasterFiles;
CREATE TABLE #MasterFiles (database_id INT, file_id INT, type_desc NVARCHAR(50), name NVARCHAR(255), physical_name NVARCHAR(255), size BIGINT);
/* Azure SQL Database doesn't have sys.master_files, so we have to build our own. */
IF CAST(SERVERPROPERTY('edition') AS VARCHAR(100)) = 'SQL Azure'
SET @StringToExecute = 'INSERT INTO #MasterFiles (database_id, file_id, type_desc, name, physical_name, size) SELECT DB_ID(), file_id, type_desc, name, physical_name, size FROM sys.database_files;'
ELSE
SET @StringToExecute = 'INSERT INTO #MasterFiles (database_id, file_id, type_desc, name, physical_name, size) SELECT database_id, file_id, type_desc, name, physical_name, size FROM sys.master_files;'
EXEC(@StringToExecute);
IF @FilterPlansByDatabase IS NOT NULL
BEGIN
IF UPPER(LEFT(@FilterPlansByDatabase,4)) = 'USER'
BEGIN
INSERT INTO #FilterPlansByDatabase (DatabaseID)
SELECT database_id
FROM sys.databases
WHERE [name] NOT IN ('master', 'model', 'msdb', 'tempdb')
END
ELSE
BEGIN
SET @FilterPlansByDatabase = @FilterPlansByDatabase + ','
;WITH a AS
(
SELECT CAST(1 AS BIGINT) f, CHARINDEX(',', @FilterPlansByDatabase) t, 1 SEQ
UNION ALL
SELECT t + 1, CHARINDEX(',', @FilterPlansByDatabase, t + 1), SEQ + 1
FROM a
WHERE CHARINDEX(',', @FilterPlansByDatabase, t + 1) > 0
)
INSERT #FilterPlansByDatabase (DatabaseID)
SELECT SUBSTRING(@FilterPlansByDatabase, f, t - f)
FROM a
WHERE SUBSTRING(@FilterPlansByDatabase, f, t - f) IS NOT NULL
OPTION (MAXRECURSION 0)
END
END
SET @StockWarningHeader = '<?ClickToSeeCommmand -- ' + @LineFeed + @LineFeed
+ 'WARNING: Running this command may result in data loss or an outage.' + @LineFeed
+ 'This tool is meant as a shortcut to help generate scripts for DBAs.' + @LineFeed
+ 'It is not a substitute for database training and experience.' + @LineFeed
+ 'Now, having said that, here''s the details:' + @LineFeed + @LineFeed;
SELECT @StockWarningFooter = @LineFeed + @LineFeed + '-- ?>',
@StockDetailsHeader = '<?ClickToSeeDetails -- ' + @LineFeed,
@StockDetailsFooter = @LineFeed + ' -- ?>';
/* Get the instance name to use as a Perfmon counter prefix. */
IF CAST(SERVERPROPERTY('edition') AS VARCHAR(100)) = 'SQL Azure'
SELECT TOP 1 @ServiceName = LEFT(object_name, (CHARINDEX(':', object_name) - 1))
FROM sys.dm_os_performance_counters;
ELSE
BEGIN
SET @StringToExecute = 'INSERT INTO #PerfmonStats(object_name, Pass, SampleTime, counter_name, cntr_type) SELECT CASE WHEN @@SERVICENAME = ''MSSQLSERVER'' THEN ''SQLServer'' ELSE ''MSSQL$'' + @@SERVICENAME END, 0, SYSDATETIMEOFFSET(), ''stuffing'', 0 ;'
EXEC(@StringToExecute);
SELECT @ServiceName = object_name FROM #PerfmonStats;
DELETE #PerfmonStats;
END
/* Build a list of queries that were run in the last 10 seconds.
We're looking for the death-by-a-thousand-small-cuts scenario
where a query is constantly running, and it doesn't have that
big of an impact individually, but it has a ton of impact
overall. We're going to build this list, and then after we
finish our @Seconds sample, we'll compare our plan cache to
this list to see what ran the most. */
/* Populate #QueryStats. SQL 2005 doesn't have query hash or query plan hash. */
IF @CheckProcedureCache = 1
BEGIN
RAISERROR('@CheckProcedureCache = 1, capturing first pass of plan cache',10,1) WITH NOWAIT;
IF @@VERSION LIKE 'Microsoft SQL Server 2005%'
BEGIN
IF @FilterPlansByDatabase IS NULL
BEGIN
SET @StringToExecute = N'INSERT INTO #QueryStats ([sql_handle], Pass, SampleTime, statement_start_offset, statement_end_offset, plan_generation_num, plan_handle, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time, query_hash, query_plan_hash, Points)
SELECT [sql_handle], 1 AS Pass, SYSDATETIMEOFFSET(), statement_start_offset, statement_end_offset, plan_generation_num, plan_handle, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time, NULL AS query_hash, NULL AS query_plan_hash, 0
FROM sys.dm_exec_query_stats qs
WHERE qs.last_execution_time >= (DATEADD(ss, -10, SYSDATETIMEOFFSET()));';
END
ELSE
BEGIN
SET @StringToExecute = N'INSERT INTO #QueryStats ([sql_handle], Pass, SampleTime, statement_start_offset, statement_end_offset, plan_generation_num, plan_handle, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time, query_hash, query_plan_hash, Points)
SELECT [sql_handle], 1 AS Pass, SYSDATETIMEOFFSET(), statement_start_offset, statement_end_offset, plan_generation_num, plan_handle, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time, NULL AS query_hash, NULL AS query_plan_hash, 0
FROM sys.dm_exec_query_stats qs
CROSS APPLY sys.dm_exec_plan_attributes(qs.plan_handle) AS attr
INNER JOIN #FilterPlansByDatabase dbs ON CAST(attr.value AS INT) = dbs.DatabaseID
WHERE qs.last_execution_time >= (DATEADD(ss, -10, SYSDATETIMEOFFSET()))
AND attr.attribute = ''dbid'';';
END
END
ELSE
BEGIN
IF @FilterPlansByDatabase IS NULL
BEGIN
SET @StringToExecute = N'INSERT INTO #QueryStats ([sql_handle], Pass, SampleTime, statement_start_offset, statement_end_offset, plan_generation_num, plan_handle, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time, query_hash, query_plan_hash, Points)
SELECT [sql_handle], 1 AS Pass, SYSDATETIMEOFFSET(), statement_start_offset, statement_end_offset, plan_generation_num, plan_handle, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time, query_hash, query_plan_hash, 0
FROM sys.dm_exec_query_stats qs
WHERE qs.last_execution_time >= (DATEADD(ss, -10, SYSDATETIMEOFFSET()));';
END
ELSE
BEGIN
SET @StringToExecute = N'INSERT INTO #QueryStats ([sql_handle], Pass, SampleTime, statement_start_offset, statement_end_offset, plan_generation_num, plan_handle, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time, query_hash, query_plan_hash, Points)
SELECT [sql_handle], 1 AS Pass, SYSDATETIMEOFFSET(), statement_start_offset, statement_end_offset, plan_generation_num, plan_handle, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time, query_hash, query_plan_hash, 0
FROM sys.dm_exec_query_stats qs
CROSS APPLY sys.dm_exec_plan_attributes(qs.plan_handle) AS attr
INNER JOIN #FilterPlansByDatabase dbs ON CAST(attr.value AS INT) = dbs.DatabaseID
WHERE qs.last_execution_time >= (DATEADD(ss, -10, SYSDATETIMEOFFSET()))
AND attr.attribute = ''dbid'';';
END
END
EXEC(@StringToExecute);
/* Get the totals for the entire plan cache */
INSERT INTO #QueryStats (Pass, SampleTime, execution_count, total_worker_time, total_physical_reads, total_logical_writes, total_logical_reads, total_clr_time, total_elapsed_time, creation_time)
SELECT -1 AS Pass, SYSDATETIMEOFFSET(), SUM(execution_count), SUM(total_worker_time), SUM(total_physical_reads), SUM(total_logical_writes), SUM(total_logical_reads), SUM(total_clr_time), SUM(total_elapsed_time), MIN(creation_time)
FROM sys.dm_exec_query_stats qs;
END /*IF @CheckProcedureCache = 1 */
IF EXISTS (SELECT *
FROM tempdb.sys.all_objects obj
INNER JOIN tempdb.sys.all_columns col1 ON obj.object_id = col1.object_id AND col1.name = 'object_name'
INNER JOIN tempdb.sys.all_columns col2 ON obj.object_id = col2.object_id AND col2.name = 'counter_name'
INNER JOIN tempdb.sys.all_columns col3 ON obj.object_id = col3.object_id AND col3.name = 'instance_name'
WHERE obj.name LIKE '%CustomPerfmonCounters%')
BEGIN
SET @StringToExecute = 'INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) SELECT [object_name],[counter_name],[instance_name] FROM #CustomPerfmonCounters'
EXEC(@StringToExecute);
END
ELSE
BEGIN
/* Add our default Perfmon counters */
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Forwarded Records/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Page compression attempts/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Page Splits/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Skipped Ghosted Records/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Table Lock Escalations/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Worktables Created/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Page life expectancy', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Page reads/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Page writes/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Readahead pages/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Target pages', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Total pages', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Databases','', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Active Transactions','_Total')
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Databases','Log Growths', '_Total')
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Databases','Log Shrinks', '_Total')
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Exec Statistics','Distributed Query', 'Execs in progress')
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Exec Statistics','DTC calls', 'Execs in progress')
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Exec Statistics','Extended Procedures', 'Execs in progress')
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Exec Statistics','OLEDB calls', 'Execs in progress')
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':General Statistics','Active Temp Tables', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':General Statistics','Logins/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':General Statistics','Logouts/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':General Statistics','Mars Deadlocks', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':General Statistics','Processes blocked', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Locks','Number of Deadlocks/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Memory Manager','Memory Grants Pending', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Errors','Errors/sec', '_Total')
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','Batch Requests/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','Forced Parameterizations/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','Guided plan executions/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','SQL Attention rate', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','SQL Compilations/sec', NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','SQL Re-Compilations/sec', NULL)
/* Below counters added by Jefferson Elias */
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Worktables From Cache Base',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Worktables From Cache Ratio',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Database pages',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Free pages',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Stolen pages',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Memory Manager','Granted Workspace Memory (KB)',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Memory Manager','Maximum Workspace Memory (KB)',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Memory Manager','Target Server Memory (KB)',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Memory Manager','Total Server Memory (KB)',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Buffer cache hit ratio',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Buffer cache hit ratio base',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Checkpoint pages/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Free list stalls/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Lazy writes/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','Auto-Param Attempts/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','Failed Auto-Params/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','Safe Auto-Params/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':SQL Statistics','Unsafe Auto-Params/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Workfiles Created/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':General Statistics','User Connections',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Latches','Average Latch Wait Time (ms)',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Latches','Average Latch Wait Time Base',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Latches','Latch Waits/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Latches','Total Latch Wait Time (ms)',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Locks','Average Wait Time (ms)',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Locks','Average Wait Time Base',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Locks','Lock Requests/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Locks','Lock Timeouts/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Locks','Lock Wait Time (ms)',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Locks','Lock Waits/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Transactions','Longest Transaction Running Time',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Full Scans/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Access Methods','Index Searches/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Buffer Manager','Page lookups/sec',NULL)
INSERT INTO #PerfmonCounters ([object_name],[counter_name],[instance_name]) VALUES (@ServiceName + ':Cursor Manager by Type','Active cursors',NULL)
END
/* Populate #FileStats, #PerfmonStats, #WaitStats with DMV data.
After we finish doing our checks, we'll take another sample and compare them. */
RAISERROR('Capturing first pass of wait stats, perfmon counters, file stats',10,1) WITH NOWAIT;
INSERT #WaitStats(Pass, SampleTime, wait_type, wait_time_ms, signal_wait_time_ms, waiting_tasks_count)
SELECT
1 AS Pass,
CASE @Seconds WHEN 0 THEN @StartSampleTime ELSE SYSDATETIMEOFFSET() END AS SampleTime,
os.wait_type,
CASE @Seconds WHEN 0 THEN 0 ELSE SUM(os.wait_time_ms) OVER (PARTITION BY os.wait_type) END as sum_wait_time_ms,
CASE @Seconds WHEN 0 THEN 0 ELSE SUM(os.signal_wait_time_ms) OVER (PARTITION BY os.wait_type ) END as sum_signal_wait_time_ms,
CASE @Seconds WHEN 0 THEN 0 ELSE SUM(os.waiting_tasks_count) OVER (PARTITION BY os.wait_type) END AS sum_waiting_tasks
FROM sys.dm_os_wait_stats os
WHERE os.wait_type not in (
'REQUEST_FOR_DEADLOCK_SEARCH',
'SQLTRACE_INCREMENTAL_FLUSH_SLEEP',
'SQLTRACE_BUFFER_FLUSH',
'LAZYWRITER_SLEEP',
'XE_TIMER_EVENT',
'XE_DISPATCHER_WAIT',
'FT_IFTS_SCHEDULER_IDLE_WAIT',
'LOGMGR_QUEUE',
'CHECKPOINT_QUEUE',
'BROKER_TO_FLUSH',
'BROKER_TASK_STOP',
'BROKER_EVENTHANDLER',
'SLEEP_TASK',
'WAITFOR',
'DBMIRROR_DBM_MUTEX',
'DBMIRROR_EVENTS_QUEUE',
'DBMIRRORING_CMD',
'DISPATCHER_QUEUE_SEMAPHORE',
'BROKER_RECEIVE_WAITFOR',
'CLR_AUTO_EVENT',
'DIRTY_PAGE_POLL',
'HADR_FILESTREAM_IOMGR_IOCOMPLETION',
'ONDEMAND_TASK_QUEUE',
'FT_IFTSHC_MUTEX',
'CLR_MANUAL_EVENT',
'CLR_SEMAPHORE',
'DBMIRROR_WORKER_QUEUE',
'DBMIRROR_DBM_EVENT',
'SP_SERVER_DIAGNOSTICS_SLEEP',
'HADR_CLUSAPI_CALL',
'HADR_LOGCAPTURE_WAIT',
'HADR_NOTIFICATION_DEQUEUE',
'HADR_TIMER_TASK',
'HADR_WORK_QUEUE',
'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP',
'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP',
'RESOURCE_GOVERNOR_IDLE',
'QDS_ASYNC_QUEUE',
'QDS_SHUTDOWN_QUEUE',
'SLEEP_SYSTEMTASK',
'BROKER_TRANSMITTER',
'REDO_THREAD_PENDING_WORK',
'UCS_SESSION_REGISTRATION'
)
ORDER BY sum_wait_time_ms DESC;
INSERT INTO #FileStats (Pass, SampleTime, DatabaseID, FileID, DatabaseName, FileLogicalName, SizeOnDiskMB, io_stall_read_ms ,
num_of_reads, [bytes_read] , io_stall_write_ms,num_of_writes, [bytes_written], PhysicalName, TypeDesc)
SELECT
1 AS Pass,
CASE @Seconds WHEN 0 THEN @StartSampleTime ELSE SYSDATETIMEOFFSET() END AS SampleTime,
mf.[database_id],
mf.[file_id],
DB_NAME(vfs.database_id) AS [db_name],
mf.name + N' [' + mf.type_desc COLLATE SQL_Latin1_General_CP1_CI_AS + N']' AS file_logical_name ,
CAST(( ( vfs.size_on_disk_bytes / 1024.0 ) / 1024.0 ) AS INT) AS size_on_disk_mb ,
CASE @Seconds WHEN 0 THEN 0 ELSE vfs.io_stall_read_ms END ,
CASE @Seconds WHEN 0 THEN 0 ELSE vfs.num_of_reads END ,
CASE @Seconds WHEN 0 THEN 0 ELSE vfs.[num_of_bytes_read] END ,
CASE @Seconds WHEN 0 THEN 0 ELSE vfs.io_stall_write_ms END ,
CASE @Seconds WHEN 0 THEN 0 ELSE vfs.num_of_writes END ,
CASE @Seconds WHEN 0 THEN 0 ELSE vfs.[num_of_bytes_written] END ,
mf.physical_name,
mf.type_desc
FROM sys.dm_io_virtual_file_stats (NULL, NULL) AS vfs
INNER JOIN #MasterFiles AS mf ON vfs.file_id = mf.file_id
AND vfs.database_id = mf.database_id
WHERE vfs.num_of_reads > 0
OR vfs.num_of_writes > 0;
INSERT INTO #PerfmonStats (Pass, SampleTime, [object_name],[counter_name],[instance_name],[cntr_value],[cntr_type])
SELECT 1 AS Pass,
CASE @Seconds WHEN 0 THEN @StartSampleTime ELSE SYSDATETIMEOFFSET() END AS SampleTime, RTRIM(dmv.object_name), RTRIM(dmv.counter_name), RTRIM(dmv.instance_name), CASE @Seconds WHEN 0 THEN 0 ELSE dmv.cntr_value END, dmv.cntr_type
FROM #PerfmonCounters counters
INNER JOIN sys.dm_os_performance_counters dmv ON counters.counter_name COLLATE SQL_Latin1_General_CP1_CI_AS = RTRIM(dmv.counter_name) COLLATE SQL_Latin1_General_CP1_CI_AS
AND counters.[object_name] COLLATE SQL_Latin1_General_CP1_CI_AS = RTRIM(dmv.[object_name]) COLLATE SQL_Latin1_General_CP1_CI_AS
AND (counters.[instance_name] IS NULL OR counters.[instance_name] COLLATE SQL_Latin1_General_CP1_CI_AS = RTRIM(dmv.[instance_name]) COLLATE SQL_Latin1_General_CP1_CI_AS)
RAISERROR('Beginning investigatory queries',10,1) WITH NOWAIT;
/* Maintenance Tasks Running - Backup Running - CheckID 1 */
IF @Seconds > 0
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, QueryPlan, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, OpenTransactionCount)
SELECT 1 AS CheckID,
1 AS Priority,
'Maintenance Tasks Running' AS FindingGroup,
'Backup Running' AS Finding,
'http://www.BrentOzar.com/askbrent/backups/' AS URL,
'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) is ' + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' AS Details,
'KILL ' + CAST(r.session_id AS NVARCHAR(100)) + ';' AS HowToStopIt,
pl.query_plan AS QueryPlan,
r.start_time AS StartTime,
s.login_name AS LoginName,
s.nt_user_name AS NTUserName,
s.[program_name] AS ProgramName,
s.[host_name] AS HostName,
db.[resource_database_id] AS DatabaseID,
DB_NAME(db.resource_database_id) AS DatabaseName,
0 AS OpenTransactionCount
FROM sys.dm_exec_requests r
INNER JOIN sys.dm_exec_connections c ON r.session_id = c.session_id
INNER JOIN sys.dm_exec_sessions s ON r.session_id = s.session_id
INNER JOIN (
SELECT DISTINCT request_session_id, resource_database_id
FROM sys.dm_tran_locks
WHERE resource_type = N'DATABASE'
AND request_mode = N'S'
AND request_status = N'GRANT'
AND request_owner_type = N'SHARED_TRANSACTION_WORKSPACE') AS db ON s.session_id = db.request_session_id
CROSS APPLY sys.dm_exec_query_plan(r.plan_handle) pl
WHERE r.command LIKE 'BACKUP%';
/* If there's a backup running, add details explaining how long full backup has been taking in the last month. */
IF @Seconds > 0 AND CAST(SERVERPROPERTY('edition') AS VARCHAR(100)) <> 'SQL Azure'
BEGIN
SET @StringToExecute = 'UPDATE #AskBrentResults SET Details = Details + '' Over the last 60 days, the full backup usually takes '' + CAST((SELECT AVG(DATEDIFF(mi, bs.backup_start_date, bs.backup_finish_date)) FROM msdb.dbo.backupset bs WHERE abr.DatabaseName = bs.database_name AND bs.type = ''D'' AND bs.backup_start_date > DATEADD(dd, -60, SYSDATETIMEOFFSET()) AND bs.backup_finish_date IS NOT NULL) AS NVARCHAR(100)) + '' minutes.'' FROM #AskBrentResults abr WHERE abr.CheckID = 1 AND EXISTS (SELECT * FROM msdb.dbo.backupset bs WHERE bs.type = ''D'' AND bs.backup_start_date > DATEADD(dd, -60, SYSDATETIMEOFFSET()) AND bs.backup_finish_date IS NOT NULL AND abr.DatabaseName = bs.database_name AND DATEDIFF(mi, bs.backup_start_date, bs.backup_finish_date) > 1)';
EXEC(@StringToExecute);
END
/* Maintenance Tasks Running - DBCC Running - CheckID 2 */
IF @Seconds > 0
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, QueryPlan, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, OpenTransactionCount)
SELECT 2 AS CheckID,
1 AS Priority,
'Maintenance Tasks Running' AS FindingGroup,
'DBCC Running' AS Finding,
'http://www.BrentOzar.com/askbrent/dbcc/' AS URL,
'Corruption check of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' AS Details,
'KILL ' + CAST(r.session_id AS NVARCHAR(100)) + ';' AS HowToStopIt,
pl.query_plan AS QueryPlan,
r.start_time AS StartTime,
s.login_name AS LoginName,
s.nt_user_name AS NTUserName,
s.[program_name] AS ProgramName,
s.[host_name] AS HostName,
db.[resource_database_id] AS DatabaseID,
DB_NAME(db.resource_database_id) AS DatabaseName,
0 AS OpenTransactionCount
FROM sys.dm_exec_requests r
INNER JOIN sys.dm_exec_connections c ON r.session_id = c.session_id
INNER JOIN sys.dm_exec_sessions s ON r.session_id = s.session_id
INNER JOIN (SELECT DISTINCT l.request_session_id, l.resource_database_id
FROM sys.dm_tran_locks l
INNER JOIN sys.databases d ON l.resource_database_id = d.database_id
WHERE l.resource_type = N'DATABASE'
AND l.request_mode = N'S'
AND l.request_status = N'GRANT'
AND l.request_owner_type = N'SHARED_TRANSACTION_WORKSPACE') AS db ON s.session_id = db.request_session_id
CROSS APPLY sys.dm_exec_query_plan(r.plan_handle) pl
WHERE r.command LIKE 'DBCC%';
/* Maintenance Tasks Running - Restore Running - CheckID 3 */
IF @Seconds > 0
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, QueryPlan, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, OpenTransactionCount)
SELECT 3 AS CheckID,
1 AS Priority,
'Maintenance Tasks Running' AS FindingGroup,
'Restore Running' AS Finding,
'http://www.BrentOzar.com/askbrent/backups/' AS URL,
'Restore of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) is ' + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' AS Details,
'KILL ' + CAST(r.session_id AS NVARCHAR(100)) + ';' AS HowToStopIt,
pl.query_plan AS QueryPlan,
r.start_time AS StartTime,
s.login_name AS LoginName,
s.nt_user_name AS NTUserName,
s.[program_name] AS ProgramName,
s.[host_name] AS HostName,
db.[resource_database_id] AS DatabaseID,
DB_NAME(db.resource_database_id) AS DatabaseName,
0 AS OpenTransactionCount
FROM sys.dm_exec_requests r
INNER JOIN sys.dm_exec_connections c ON r.session_id = c.session_id
INNER JOIN sys.dm_exec_sessions s ON r.session_id = s.session_id
INNER JOIN (
SELECT DISTINCT request_session_id, resource_database_id
FROM sys.dm_tran_locks
WHERE resource_type = N'DATABASE'
AND request_mode = N'S'
AND request_status = N'GRANT'
AND request_owner_type = N'SHARED_TRANSACTION_WORKSPACE') AS db ON s.session_id = db.request_session_id
CROSS APPLY sys.dm_exec_query_plan(r.plan_handle) pl
WHERE r.command LIKE 'RESTORE%';
/* SQL Server Internal Maintenance - Database File Growing - CheckID 4 */
IF @Seconds > 0
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, QueryPlan, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, OpenTransactionCount)
SELECT 4 AS CheckID,
1 AS Priority,
'SQL Server Internal Maintenance' AS FindingGroup,
'Database File Growing' AS Finding,
'http://www.BrentOzar.com/go/instant' AS URL,
'SQL Server is waiting for Windows to provide storage space for a database restore, a data file growth, or a log file growth. This task has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '.' + @LineFeed + 'Check the query plan (expert mode) to identify the database involved.' AS Details,
'Unfortunately, you can''t stop this, but you can prevent it next time. Check out http://www.BrentOzar.com/go/instant for details.' AS HowToStopIt,
pl.query_plan AS QueryPlan,
r.start_time AS StartTime,
s.login_name AS LoginName,
s.nt_user_name AS NTUserName,
s.[program_name] AS ProgramName,
s.[host_name] AS HostName,
NULL AS DatabaseID,
NULL AS DatabaseName,
0 AS OpenTransactionCount
FROM sys.dm_os_waiting_tasks t
INNER JOIN sys.dm_exec_connections c ON t.session_id = c.session_id
INNER JOIN sys.dm_exec_requests r ON t.session_id = r.session_id
INNER JOIN sys.dm_exec_sessions s ON r.session_id = s.session_id
CROSS APPLY sys.dm_exec_query_plan(r.plan_handle) pl
WHERE t.wait_type = 'PREEMPTIVE_OS_WRITEFILEGATHER'
/* Query Problems - Long-Running Query Blocking Others - CheckID 5 */
/*
IF @Seconds > 0
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, QueryPlan, QueryText, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, OpenTransactionCount)
SELECT 5 AS CheckID,
1 AS Priority,
'Query Problems' AS FindingGroup,
'Long-Running Query Blocking Others' AS Finding,
'http://www.BrentOzar.com/go/blocking' AS URL,
'Query in ' + DB_NAME(db.resource_database_id) + ' has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' + @LineFeed + @LineFeed
+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(rBlocker.sql_handle)),
(SELECT TOP 1 [text] FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) WHERE spBlocker.spid = tBlocked.blocking_session_id), '') AS NVARCHAR(2000)) AS Details,
'KILL ' + CAST(tBlocked.blocking_session_id AS NVARCHAR(100)) + ';' AS HowToStopIt,
(SELECT TOP 1 query_plan FROM sys.dm_exec_query_plan(rBlocker.plan_handle)) AS QueryPlan,
COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(rBlocker.sql_handle)),
(SELECT TOP 1 [text] FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) WHERE spBlocker.spid = tBlocked.blocking_session_id)) AS QueryText,
r.start_time AS StartTime,
s.login_name AS LoginName,
s.nt_user_name AS NTUserName,
s.[program_name] AS ProgramName,
s.[host_name] AS HostName,
db.[resource_database_id] AS DatabaseID,
DB_NAME(db.resource_database_id) AS DatabaseName,
0 AS OpenTransactionCount
FROM sys.dm_exec_sessions s
INNER JOIN sys.dm_exec_requests r ON s.session_id = r.session_id
INNER JOIN sys.dm_exec_connections c ON s.session_id = c.session_id
INNER JOIN sys.dm_os_waiting_tasks tBlocked ON tBlocked.session_id = s.session_id AND tBlocked.session_id <> s.session_id
INNER JOIN (
SELECT DISTINCT request_session_id, resource_database_id
FROM sys.dm_tran_locks
WHERE resource_type = N'DATABASE'
AND request_mode = N'S'
AND request_status = N'GRANT'
AND request_owner_type = N'SHARED_TRANSACTION_WORKSPACE') AS db ON s.session_id = db.request_session_id
LEFT OUTER JOIN sys.dm_exec_requests rBlocker ON tBlocked.blocking_session_id = rBlocker.session_id
WHERE NOT EXISTS (SELECT * FROM sys.dm_os_waiting_tasks tBlocker WHERE tBlocker.session_id = tBlocked.blocking_session_id AND tBlocker.blocking_session_id IS NOT NULL)
AND s.last_request_start_time < DATEADD(SECOND, -30, SYSDATETIMEOFFSET())
*/
/* Query Problems - Plan Cache Erased Recently */
IF DATEADD(mi, -15, SYSDATETIMEOFFSET()) < (SELECT TOP 1 creation_time FROM sys.dm_exec_query_stats ORDER BY creation_time)
BEGIN
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt)
SELECT TOP 1 7 AS CheckID,
50 AS Priority,
'Query Problems' AS FindingGroup,
'Plan Cache Erased Recently' AS Finding,
'http://www.BrentOzar.com/askbrent/plan-cache-erased-recently/' AS URL,
'The oldest query in the plan cache was created at ' + CAST(creation_time AS NVARCHAR(50)) + '. ' + @LineFeed + @LineFeed
+ 'This indicates that someone ran DBCC FREEPROCCACHE at that time,' + @LineFeed
+ 'Giving SQL Server temporary amnesia. Now, as queries come in,' + @LineFeed
+ 'SQL Server has to use a lot of CPU power in order to build execution' + @LineFeed
+ 'plans and put them in cache again. This causes high CPU loads.' AS Details,
'Find who did that, and stop them from doing it again.' AS HowToStopIt
FROM sys.dm_exec_query_stats
ORDER BY creation_time
END;
/* Query Problems - Sleeping Query with Open Transactions - CheckID 8 */
IF @Seconds > 0
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, QueryText, OpenTransactionCount)
SELECT 8 AS CheckID,
50 AS Priority,
'Query Problems' AS FindingGroup,
'Sleeping Query with Open Transactions' AS Finding,
'http://www.brentozar.com/askbrent/sleeping-query-with-open-transactions/' AS URL,
'Database: ' + DB_NAME(db.resource_database_id) + @LineFeed + 'Host: ' + s.[host_name] + @LineFeed + 'Program: ' + s.[program_name] + @LineFeed + 'Asleep with open transactions and locks since ' + CAST(s.last_request_end_time AS NVARCHAR(100)) + '. ' AS Details,
'KILL ' + CAST(s.session_id AS NVARCHAR(100)) + ';' AS HowToStopIt,
s.last_request_start_time AS StartTime,
s.login_name AS LoginName,
s.nt_user_name AS NTUserName,
s.[program_name] AS ProgramName,
s.[host_name] AS HostName,
db.[resource_database_id] AS DatabaseID,
DB_NAME(db.resource_database_id) AS DatabaseName,
(SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(c.most_recent_sql_handle)) AS QueryText,
sessions_with_transactions.open_transaction_count AS OpenTransactionCount
FROM (SELECT session_id, SUM(open_transaction_count) AS open_transaction_count FROM sys.dm_exec_requests WHERE open_transaction_count > 0 GROUP BY session_id) AS sessions_with_transactions
INNER JOIN sys.dm_exec_sessions s ON sessions_with_transactions.session_id = s.session_id
INNER JOIN sys.dm_exec_connections c ON s.session_id = c.session_id
INNER JOIN (
SELECT DISTINCT request_session_id, resource_database_id
FROM sys.dm_tran_locks
WHERE resource_type = N'DATABASE'
AND request_mode = N'S'
AND request_status = N'GRANT'
AND request_owner_type = N'SHARED_TRANSACTION_WORKSPACE') AS db ON s.session_id = db.request_session_id
WHERE s.status = 'sleeping'
AND s.last_request_end_time < DATEADD(ss, -10, SYSDATETIMEOFFSET())
AND EXISTS(SELECT * FROM sys.dm_tran_locks WHERE request_session_id = s.session_id
AND NOT (resource_type = N'DATABASE' AND request_mode = N'S' AND request_status = N'GRANT' AND request_owner_type = N'SHARED_TRANSACTION_WORKSPACE'))
/* Query Problems - Query Rolling Back - CheckID 9 */
IF @Seconds > 0
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, QueryText)
SELECT 9 AS CheckID,
1 AS Priority,
'Query Problems' AS FindingGroup,
'Query Rolling Back' AS Finding,
'http://www.BrentOzar.com/askbrent/rollback/' AS URL,
'Rollback started at ' + CAST(r.start_time AS NVARCHAR(100)) + ', is ' + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete.' AS Details,
'Unfortunately, you can''t stop this. Whatever you do, don''t restart the server in an attempt to fix it - SQL Server will keep rolling back.' AS HowToStopIt,
r.start_time AS StartTime,
s.login_name AS LoginName,
s.nt_user_name AS NTUserName,
s.[program_name] AS ProgramName,
s.[host_name] AS HostName,
db.[resource_database_id] AS DatabaseID,
DB_NAME(db.resource_database_id) AS DatabaseName,
(SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(c.most_recent_sql_handle)) AS QueryText
FROM sys.dm_exec_sessions s
INNER JOIN sys.dm_exec_connections c ON s.session_id = c.session_id
INNER JOIN sys.dm_exec_requests r ON s.session_id = r.session_id
LEFT OUTER JOIN (
SELECT DISTINCT request_session_id, resource_database_id
FROM sys.dm_tran_locks
WHERE resource_type = N'DATABASE'
AND request_mode = N'S'
AND request_status = N'GRANT'
AND request_owner_type = N'SHARED_TRANSACTION_WORKSPACE') AS db ON s.session_id = db.request_session_id
WHERE r.status = 'rollback'
/* Server Performance - Page Life Expectancy Low - CheckID 10 */
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt)
SELECT 10 AS CheckID,
50 AS Priority,
'Server Performance' AS FindingGroup,
'Page Life Expectancy Low' AS Finding,
'http://www.BrentOzar.com/askbrent/page-life-expectancy/' AS URL,
'SQL Server Buffer Manager:Page life expectancy is ' + CAST(c.cntr_value AS NVARCHAR(10)) + ' seconds.' + @LineFeed
+ 'This means SQL Server can only keep data pages in memory for that many seconds after reading those pages in from storage.' + @LineFeed
+ 'This is a symptom, not a cause - it indicates very read-intensive queries that need an index, or insufficient server memory.' AS Details,
'Add more memory to the server, or find the queries reading a lot of data, and make them more efficient (or fix them with indexes).' AS HowToStopIt
FROM sys.dm_os_performance_counters c
WHERE object_name LIKE 'SQLServer:Buffer Manager%'
AND counter_name LIKE 'Page life expectancy%'
AND cntr_value < 300
/* Server Info - Database Size, Total GB - CheckID 21 */
INSERT INTO #AskBrentResults (CheckID, Priority, FindingsGroup, Finding, Details, DetailsInt, URL)
SELECT 21 AS CheckID,
251 AS Priority,
'Server Info' AS FindingGroup,
'Database Size, Total GB' AS Finding,