-
Notifications
You must be signed in to change notification settings - Fork 999
/
sp_Blitz.sql
10498 lines (9353 loc) · 467 KB
/
sp_Blitz.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_Blitz') IS NULL
EXEC ('CREATE PROCEDURE dbo.sp_Blitz AS RETURN 0;');
GO
ALTER PROCEDURE [dbo].[sp_Blitz]
@Help TINYINT = 0 ,
@CheckUserDatabaseObjects TINYINT = 1 ,
@CheckProcedureCache TINYINT = 0 ,
@OutputType VARCHAR(20) = 'TABLE' ,
@OutputProcedureCache TINYINT = 0 ,
@CheckProcedureCacheFilter VARCHAR(10) = NULL ,
@CheckServerInfo TINYINT = 0 ,
@SkipChecksServer NVARCHAR(256) = NULL ,
@SkipChecksDatabase NVARCHAR(256) = NULL ,
@SkipChecksSchema NVARCHAR(256) = NULL ,
@SkipChecksTable NVARCHAR(256) = NULL ,
@IgnorePrioritiesBelow INT = NULL ,
@IgnorePrioritiesAbove INT = NULL ,
@OutputServerName NVARCHAR(256) = NULL ,
@OutputDatabaseName NVARCHAR(256) = NULL ,
@OutputSchemaName NVARCHAR(256) = NULL ,
@OutputTableName NVARCHAR(256) = NULL ,
@OutputXMLasNVARCHAR TINYINT = 0 ,
@EmailRecipients VARCHAR(MAX) = NULL ,
@EmailProfile sysname = NULL ,
@SummaryMode TINYINT = 0 ,
@BringThePain TINYINT = 0 ,
@UsualDBOwner sysname = NULL ,
@SkipBlockingChecks TINYINT = 1 ,
@Debug TINYINT = 0 ,
@Version VARCHAR(30) = NULL OUTPUT,
@VersionDate DATETIME = NULL OUTPUT,
@VersionCheckMode BIT = 0
WITH RECOMPILE
AS
SET NOCOUNT ON;
SET STATISTICS XML OFF;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SELECT @Version = '8.22', @VersionDate = '20241019';
SET @OutputType = UPPER(@OutputType);
IF(@VersionCheckMode = 1)
BEGIN
RETURN;
END;
IF @Help = 1
BEGIN
PRINT '
/*
sp_Blitz from http://FirstResponderKit.org
This script checks the health of your SQL Server and gives you a prioritized
to-do list of the most urgent things you should consider fixing.
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.
- If a database name has a question mark in it, some tests will fail. Gotta
love that unsupported sp_MSforeachdb.
- If you have offline databases, sp_Blitz fails the first time you run it,
but does work the second time. (Hoo, boy, this will be fun to debug.)
- @OutputServerName will output QueryPlans as NVARCHAR(MAX) since Microsoft
has refused to support XML columns in Linked Server queries. The bug is now
16 years old! *~ \o/ ~*
Unknown limitations of this version:
- None. (If we knew them, they would be known. Duh.)
Changes - for the full list of improvements and fixes in this version, see:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/
Parameter explanations:
@CheckUserDatabaseObjects 1=review user databases for triggers, heaps, etc. Takes more time for more databases and objects.
@CheckServerInfo 1=show server info like CPUs, memory, virtualization
@CheckProcedureCache 1=top 20-50 resource-intensive cache plans and analyze them for common performance issues.
@OutputProcedureCache 1=output the top 20-50 resource-intensive plans even if they did not trigger an alarm
@CheckProcedureCacheFilter ''CPU'' | ''Reads'' | ''Duration'' | ''ExecCount''
@OutputType ''TABLE''=table | ''COUNT''=row with number found | ''MARKDOWN''=bulleted list (including server info, excluding security findings) | ''SCHEMA''=version and field list | ''XML'' =table output as XML | ''NONE'' = none
@IgnorePrioritiesBelow 50=ignore priorities below 50
@IgnorePrioritiesAbove 50=ignore priorities above 50
@Debug 0=silent (Default) | 1=messages per step | 2=outputs dynamic queries
For the rest of the parameters, see https://www.BrentOzar.com/blitz/documentation for details.
MIT License
Copyright for portions of sp_Blitz are held by Microsoft as part of project
tigertoolbox and are provided under the MIT license:
https://github.com/Microsoft/tigertoolbox
All other copyrights for sp_Blitz are held by Brent Ozar Unlimited.
Copyright (c) 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.
*/';
RETURN;
END; /* @Help = 1 */
ELSE IF @OutputType = 'SCHEMA'
BEGIN
SELECT FieldList = '[Priority] TINYINT, [FindingsGroup] VARCHAR(50), [Finding] VARCHAR(200), [DatabaseName] NVARCHAR(128), [URL] VARCHAR(200), [Details] NVARCHAR(4000), [QueryPlan] NVARCHAR(MAX), [QueryPlanFiltered] NVARCHAR(MAX), [CheckID] INT';
END;/* IF @OutputType = 'SCHEMA' */
ELSE
BEGIN
DECLARE @StringToExecute NVARCHAR(4000)
,@curr_tracefilename NVARCHAR(500)
,@base_tracefilename NVARCHAR(500)
,@indx int
,@query_result_separator CHAR(1)
,@EmailSubject NVARCHAR(255)
,@EmailBody NVARCHAR(MAX)
,@EmailAttachmentFilename NVARCHAR(255)
,@ProductVersion NVARCHAR(128)
,@ProductVersionMajor DECIMAL(10,2)
,@ProductVersionMinor DECIMAL(10,2)
,@CurrentName NVARCHAR(128)
,@CurrentDefaultValue NVARCHAR(200)
,@CurrentCheckID INT
,@CurrentPriority INT
,@CurrentFinding VARCHAR(200)
,@CurrentURL VARCHAR(200)
,@CurrentDetails NVARCHAR(4000)
,@MsSinceWaitsCleared DECIMAL(38,0)
,@CpuMsSinceWaitsCleared DECIMAL(38,0)
,@ResultText NVARCHAR(MAX)
,@crlf NVARCHAR(2)
,@Processors int
,@NUMANodes int
,@MinServerMemory bigint
,@MaxServerMemory bigint
,@ColumnStoreIndexesInUse bit
,@QueryStoreInUse bit
,@TraceFileIssue bit
-- Flag for Windows OS to help with Linux support
,@IsWindowsOperatingSystem BIT
,@DaysUptime NUMERIC(23,2)
/* For First Responder Kit consistency check:*/
,@spBlitzFullName VARCHAR(1024)
,@BlitzIsOutdatedComparedToOthers BIT
,@tsql NVARCHAR(MAX)
,@VersionCheckModeExistsTSQL NVARCHAR(MAX)
,@BlitzProcDbName VARCHAR(256)
,@ExecRet INT
,@InnerExecRet INT
,@TmpCnt INT
,@PreviousComponentName VARCHAR(256)
,@PreviousComponentFullPath VARCHAR(1024)
,@CurrentStatementId INT
,@CurrentComponentSchema VARCHAR(256)
,@CurrentComponentName VARCHAR(256)
,@CurrentComponentType VARCHAR(256)
,@CurrentComponentVersionDate DATETIME2
,@CurrentComponentFullName VARCHAR(1024)
,@CurrentComponentMandatory BIT
,@MaximumVersionDate DATETIME
,@StatementCheckName VARCHAR(256)
,@StatementOutputsCounter BIT
,@OutputCounterExpectedValue INT
,@StatementOutputsExecRet BIT
,@StatementOutputsDateTime BIT
,@CurrentComponentMandatoryCheckOK BIT
,@CurrentComponentVersionCheckModeOK BIT
,@canExitLoop BIT
,@frkIsConsistent BIT
,@NeedToTurnNumericRoundabortBackOn BIT
,@sa bit = 1
,@SUSER_NAME sysname = SUSER_SNAME()
,@SkipDBCC bit = 0
,@SkipTrace bit = 0
,@SkipXPRegRead bit = 0
,@SkipXPFixedDrives bit = 0
,@SkipXPCMDShell bit = 0
,@SkipMaster bit = 0
,@SkipMSDB_objs bit = 0
,@SkipMSDB_jobs bit = 0
,@SkipModel bit = 0
,@SkipTempDB bit = 0
,@SkipValidateLogins bit = 0
,@SkipGetAlertInfo bit = 0
DECLARE
@db_perms table
(
database_name sysname,
permission_name sysname
);
INSERT
@db_perms
(
database_name,
permission_name
)
SELECT
database_name =
DB_NAME(d.database_id),
fmp.permission_name
FROM sys.databases AS d
CROSS APPLY fn_my_permissions(d.name, 'DATABASE') AS fmp
WHERE fmp.permission_name = N'SELECT'; /*Databases where we don't have read permissions*/
/* End of declarations for First Responder Kit consistency check:*/
;
/* Create temp table for check 73 */
IF OBJECT_ID('tempdb..#AlertInfo') IS NOT NULL
EXEC sp_executesql N'DROP TABLE #AlertInfo;';
CREATE TABLE #AlertInfo
(
FailSafeOperator NVARCHAR(255) ,
NotificationMethod INT ,
ForwardingServer NVARCHAR(255) ,
ForwardingSeverity INT ,
PagerToTemplate NVARCHAR(255) ,
PagerCCTemplate NVARCHAR(255) ,
PagerSubjectTemplate NVARCHAR(255) ,
PagerSendSubjectOnly NVARCHAR(255) ,
ForwardAlways INT
);
/* Create temp table for check 2301 */
IF OBJECT_ID('tempdb..#InvalidLogins') IS NOT NULL
EXEC sp_executesql N'DROP TABLE #InvalidLogins;';
CREATE TABLE #InvalidLogins
(
LoginSID varbinary(85),
LoginName VARCHAR(256)
);
/*Starting permissions checks here, but only if we're not a sysadmin*/
IF
(
SELECT
sa =
ISNULL
(
IS_SRVROLEMEMBER(N'sysadmin'),
0
)
) = 0
BEGIN
IF @Debug IN (1, 2) RAISERROR('User not SA, checking permissions', 0, 1) WITH NOWAIT;
SET @sa = 0; /*Setting this to 0 to skip DBCC COMMANDS*/
IF NOT EXISTS
(
SELECT
1/0
FROM sys.fn_my_permissions(NULL, NULL) AS fmp
WHERE fmp.permission_name = N'VIEW SERVER STATE'
)
BEGIN
RAISERROR('The user %s does not have VIEW SERVER STATE permissions.', 0, 11, @SUSER_NAME) WITH NOWAIT;
RETURN;
END; /*If we don't have this, we can't do anything at all.*/
IF NOT EXISTS
(
SELECT
1/0
FROM fn_my_permissions(N'sys.traces', N'OBJECT') AS fmp
WHERE fmp.permission_name = N'ALTER'
)
BEGIN
SET @SkipTrace = 1;
END; /*We need this permission to execute trace stuff, apparently*/
IF NOT EXISTS
(
SELECT
1/0
FROM fn_my_permissions(N'xp_fixeddrives', N'OBJECT') AS fmp
WHERE fmp.permission_name = N'EXECUTE'
)
BEGIN
SET @SkipXPFixedDrives = 1;
END; /*Need execute on xp_fixeddrives*/
IF NOT EXISTS
(
SELECT
1/0
FROM fn_my_permissions(N'xp_cmdshell', N'OBJECT') AS fmp
WHERE fmp.permission_name = N'EXECUTE'
)
BEGIN
SET @SkipXPCMDShell = 1;
END; /*Need execute on xp_cmdshell*/
IF ISNULL(@SkipValidateLogins, 0) != 1 /*If @SkipValidateLogins hasn't been set to 1 by the caller*/
BEGIN
BEGIN TRY
/* Try to fill the table for check 2301 */
INSERT INTO #InvalidLogins
(
[LoginSID]
,[LoginName]
)
EXEC sp_validatelogins;
SET @SkipValidateLogins = 0; /*We can execute sp_validatelogins*/
END TRY
BEGIN CATCH
SET @SkipValidateLogins = 1; /*We have don't have execute rights or sp_validatelogins throws an error so skip it*/
END CATCH;
END; /*Need execute on sp_validatelogins*/
IF NOT EXISTS
(
SELECT
1/0
FROM fn_my_permissions(N'[master].[dbo].[sp_MSgetalertinfo]', N'OBJECT') AS fmp
WHERE fmp.permission_name = N'EXECUTE'
)
BEGIN
SET @SkipGetAlertInfo = 1;
END; /*Need execute on sp_MSgetalertinfo*/
IF ISNULL(@SkipModel, 0) != 1 /*If @SkipModel hasn't been set to 1 by the caller*/
BEGIN
IF EXISTS
(
SELECT 1/0
FROM @db_perms
WHERE database_name = N'model'
)
BEGIN
BEGIN TRY
IF EXISTS
(
SELECT 1/0
FROM model.sys.objects
)
BEGIN
SET @SkipModel = 0; /*We have read permissions in the model database, and can view the objects*/
END;
END TRY
BEGIN CATCH
SET @SkipModel = 1; /*We have read permissions in the model database ... oh wait we got tricked, we can't view the objects*/
END CATCH;
END;
ELSE
BEGIN
SET @SkipModel = 1; /*We don't have read permissions in the model database*/
END;
END;
IF ISNULL(@SkipMSDB_objs, 0) != 1 /*If @SkipMSDB_objs hasn't been set to 1 by the caller*/
BEGIN
IF EXISTS
(
SELECT 1/0
FROM @db_perms
WHERE database_name = N'msdb'
)
BEGIN
BEGIN TRY
IF EXISTS
(
SELECT 1/0
FROM msdb.sys.objects
)
BEGIN
SET @SkipMSDB_objs = 0; /*We have read permissions in the msdb database, and can view the objects*/
END;
END TRY
BEGIN CATCH
SET @SkipMSDB_objs = 1; /*We have read permissions in the msdb database ... oh wait we got tricked, we can't view the objects*/
END CATCH;
END;
ELSE
BEGIN
SET @SkipMSDB_objs = 1; /*We don't have read permissions in the msdb database*/
END;
END;
IF ISNULL(@SkipMSDB_jobs, 0) != 1 /*If @SkipMSDB_jobs hasn't been set to 1 by the caller*/
BEGIN
IF EXISTS
(
SELECT 1/0
FROM @db_perms
WHERE database_name = N'msdb'
)
BEGIN
BEGIN TRY
IF EXISTS
(
SELECT 1/0
FROM msdb.dbo.sysjobs
)
BEGIN
SET @SkipMSDB_jobs = 0; /*We have read permissions in the msdb database, and can view the objects*/
END;
END TRY
BEGIN CATCH
SET @SkipMSDB_jobs = 1; /*We have read permissions in the msdb database ... oh wait we got tricked, we can't view the objects*/
END CATCH;
END;
ELSE
BEGIN
SET @SkipMSDB_jobs = 1; /*We don't have read permissions in the msdb database*/
END;
END;
END;
SET @crlf = NCHAR(13) + NCHAR(10);
SET @ResultText = 'sp_Blitz Results: ' + @crlf;
/* Last startup */
SELECT @DaysUptime = CAST(DATEDIFF(HOUR, create_date, GETDATE()) / 24. AS NUMERIC(23, 2))
FROM sys.databases
WHERE database_id = 2;
IF @DaysUptime = 0
SET @DaysUptime = .01;
/*
Set the session state of Numeric_RoundAbort to off if any databases have Numeric Round-Abort enabled.
Stops arithmetic overflow errors during data conversion. See Github issue #2302 for more info.
*/
IF ( (8192 & @@OPTIONS) = 8192 ) /* Numeric RoundAbort is currently on, so we may need to turn it off temporarily */
BEGIN
IF EXISTS (SELECT 1
FROM sys.databases
WHERE is_numeric_roundabort_on = 1) /* A database has it turned on */
BEGIN
SET @NeedToTurnNumericRoundabortBackOn = 1;
SET NUMERIC_ROUNDABORT OFF;
END;
END;
/*
--TOURSTOP01--
See https://www.BrentOzar.com/go/blitztour for a guided tour.
We start by creating #BlitzResults. It's a temp table that will store all of
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.
#BlitzResults 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.
For a list of checks, visit http://FirstResponderKit.org.
*/
IF OBJECT_ID('tempdb..#BlitzResults') IS NOT NULL
DROP TABLE #BlitzResults;
CREATE TABLE #BlitzResults
(
ID INT IDENTITY(1, 1) ,
CheckID INT ,
DatabaseName NVARCHAR(128) ,
Priority TINYINT ,
FindingsGroup VARCHAR(50) ,
Finding VARCHAR(200) ,
URL VARCHAR(200) ,
Details NVARCHAR(4000) ,
QueryPlan [XML] NULL ,
QueryPlanFiltered [NVARCHAR](MAX) NULL
);
IF OBJECT_ID('tempdb..#TemporaryDatabaseResults') IS NOT NULL
DROP TABLE #TemporaryDatabaseResults;
CREATE TABLE #TemporaryDatabaseResults
(
DatabaseName NVARCHAR(128) ,
Finding NVARCHAR(128)
);
/* First Responder Kit consistency (temporary tables) */
IF(OBJECT_ID('tempdb..#FRKObjects') IS NOT NULL)
BEGIN
EXEC sp_executesql N'DROP TABLE #FRKObjects;';
END;
-- this one represents FRK objects
CREATE TABLE #FRKObjects (
DatabaseName VARCHAR(256) NOT NULL,
ObjectSchemaName VARCHAR(256) NULL,
ObjectName VARCHAR(256) NOT NULL,
ObjectType VARCHAR(256) NOT NULL,
MandatoryComponent BIT NOT NULL
);
IF(OBJECT_ID('tempdb..#StatementsToRun4FRKVersionCheck') IS NOT NULL)
BEGIN
EXEC sp_executesql N'DROP TABLE #StatementsToRun4FRKVersionCheck;';
END;
-- This one will contain the statements to be executed
-- order: 1- Mandatory, 2- VersionCheckMode, 3- VersionCheck
CREATE TABLE #StatementsToRun4FRKVersionCheck (
StatementId INT IDENTITY(1,1),
CheckName VARCHAR(256),
SubjectName VARCHAR(256),
SubjectFullPath VARCHAR(1024),
StatementText NVARCHAR(MAX),
StatementOutputsCounter BIT,
OutputCounterExpectedValue INT,
StatementOutputsExecRet BIT,
StatementOutputsDateTime BIT
);
/* End of First Responder Kit consistency (temporary tables) */
/*
You can build your own table with a list of checks to skip. For example, you
might have some databases that you don't care about, or some checks you don't
want to run. Then, when you run sp_Blitz, you can specify these parameters:
@SkipChecksDatabase = 'DBAtools',
@SkipChecksSchema = 'dbo',
@SkipChecksTable = 'BlitzChecksToSkip'
Pass in the database, schema, and table that contains the list of checks you
want to skip. This part of the code checks those parameters, gets the list,
and then saves those in a temp table. As we run each check, we'll see if we
need to skip it.
*/
/* --TOURSTOP07-- */
IF OBJECT_ID('tempdb..#SkipChecks') IS NOT NULL
DROP TABLE #SkipChecks;
CREATE TABLE #SkipChecks
(
DatabaseName NVARCHAR(128) ,
CheckID INT ,
ServerName NVARCHAR(128)
);
CREATE CLUSTERED INDEX IX_CheckID_DatabaseName ON #SkipChecks(CheckID, DatabaseName);
INSERT INTO #SkipChecks
(DatabaseName)
SELECT
DB_NAME(d.database_id)
FROM sys.databases AS d
WHERE (DB_NAME(d.database_id) LIKE 'rdsadmin%'
OR LOWER(d.name) IN ('dbatools', 'dbadmin', 'dbmaintenance'))
OPTION(RECOMPILE);
/*Skip checks for database where we don't have read permissions*/
INSERT INTO
#SkipChecks
(
DatabaseName
)
SELECT
DB_NAME(d.database_id)
FROM sys.databases AS d
WHERE NOT EXISTS
(
SELECT
1/0
FROM @db_perms AS dp
WHERE dp.database_name = DB_NAME(d.database_id)
);
/*Skip individial checks where we don't have permissions*/
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 29, NULL)) AS v (DatabaseName, CheckID, ServerName) /*Looks for user tables in model*/
WHERE @SkipModel = 1;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 28, NULL)) AS v (DatabaseName, CheckID, ServerName) /*Tables in the MSDB Database*/
WHERE @SkipMSDB_objs = 1;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES
/*sysjobs checks*/
(NULL, 6, NULL), /*Jobs Owned By Users*/
(NULL, 57, NULL), /*SQL Agent Job Runs at Startup*/
(NULL, 79, NULL), /*Shrink Database Job*/
(NULL, 94, NULL), /*Agent Jobs Without Failure Emails*/
(NULL, 123, NULL), /*Agent Jobs Starting Simultaneously*/
(NULL, 180, NULL), /*Shrink Database Step In Maintenance Plan*/
(NULL, 181, NULL), /*Repetitive Maintenance Tasks*/
/*sysalerts checks*/
(NULL, 30, NULL), /*Not All Alerts Configured*/
(NULL, 59, NULL), /*Alerts Configured without Follow Up*/
(NULL, 61, NULL), /*No Alerts for Sev 19-25*/
(NULL, 96, NULL), /*No Alerts for Corruption*/
(NULL, 98, NULL), /*Alerts Disabled*/
(NULL, 219, NULL), /*Alerts Without Event Descriptions*/
/*sysoperators*/
(NULL, 31, NULL) /*No Operators Configured/Enabled*/
) AS v (DatabaseName, CheckID, ServerName)
WHERE @SkipMSDB_jobs = 1;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 68, NULL)) AS v (DatabaseName, CheckID, ServerName) /*DBCC command*/
WHERE @sa = 0;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 69, NULL)) AS v (DatabaseName, CheckID, ServerName) /*DBCC command*/
WHERE @sa = 0;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 92, NULL)) AS v (DatabaseName, CheckID, ServerName) /*xp_fixeddrives*/
WHERE @SkipXPFixedDrives = 1;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 106, NULL)) AS v (DatabaseName, CheckID, ServerName) /*alter trace*/
WHERE @SkipTrace = 1;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 211, NULL)) AS v (DatabaseName, CheckID, ServerName) /*xp_regread*/
WHERE @sa = 0;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 212, NULL)) AS v (DatabaseName, CheckID, ServerName) /*xp_regread*/
WHERE @SkipXPCMDShell = 1;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 2301, NULL)) AS v (DatabaseName, CheckID, ServerName) /*sp_validatelogins*/
WHERE @SkipValidateLogins = 1;
INSERT #SkipChecks (DatabaseName, CheckID, ServerName)
SELECT
v.*
FROM (VALUES(NULL, 73, NULL)) AS v (DatabaseName, CheckID, ServerName) /*sp_validatelogins*/
WHERE @SkipGetAlertInfo = 1;
IF @sa = 0
BEGIN
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 223 AS CheckID ,
0 AS Priority ,
'Informational' AS FindingsGroup ,
'Some Checks Skipped' AS Finding ,
'' AS URL ,
'User ''' + @SUSER_NAME + ''' is not part of the sysadmin role, so we skipped some checks that are not possible due to lack of permissions.' AS Details;
END;
/*End of SkipsChecks added due to permissions*/
IF @SkipChecksTable IS NOT NULL
AND @SkipChecksSchema IS NOT NULL
AND @SkipChecksDatabase IS NOT NULL
BEGIN
IF @Debug IN (1, 2) RAISERROR('Inserting SkipChecks', 0, 1) WITH NOWAIT;
SET @StringToExecute = N'INSERT INTO #SkipChecks(DatabaseName, CheckID, ServerName )
SELECT DISTINCT DatabaseName, CheckID, ServerName
FROM '
IF LTRIM(RTRIM(@SkipChecksServer)) <> ''
BEGIN
SET @StringToExecute += QUOTENAME(@SkipChecksServer) + N'.';
END
SET @StringToExecute += QUOTENAME(@SkipChecksDatabase) + N'.' + QUOTENAME(@SkipChecksSchema) + N'.' + QUOTENAME(@SkipChecksTable)
+ N' WHERE ServerName IS NULL OR ServerName = CAST(SERVERPROPERTY(''ServerName'') AS NVARCHAR(128)) OPTION (RECOMPILE);';
EXEC(@StringToExecute);
END;
-- Flag for Windows OS to help with Linux support
IF EXISTS ( SELECT 1
FROM sys.all_objects
WHERE name = 'dm_os_host_info' )
BEGIN
SELECT @IsWindowsOperatingSystem = CASE WHEN host_platform = 'Windows' THEN 1 ELSE 0 END FROM sys.dm_os_host_info ;
END;
ELSE
BEGIN
SELECT @IsWindowsOperatingSystem = 1 ;
END;
IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 106 )
AND (select convert(int,value_in_use) from sys.configurations where name = 'default trace enabled' ) = 1
BEGIN
select @curr_tracefilename = [path] from sys.traces where is_default = 1 ;
set @curr_tracefilename = reverse(@curr_tracefilename);
-- Set the trace file path separator based on underlying OS
IF (@IsWindowsOperatingSystem = 1) AND @curr_tracefilename IS NOT NULL
BEGIN
select @indx = patindex('%\%', @curr_tracefilename) ;
set @curr_tracefilename = reverse(@curr_tracefilename) ;
set @base_tracefilename = left( @curr_tracefilename,len(@curr_tracefilename) - @indx) + '\log.trc' ;
END;
ELSE
BEGIN
select @indx = patindex('%/%', @curr_tracefilename) ;
set @curr_tracefilename = reverse(@curr_tracefilename) ;
set @base_tracefilename = left( @curr_tracefilename,len(@curr_tracefilename) - @indx) + '/log.trc' ;
END;
END;
/* If the server has any databases on Antiques Roadshow, skip the checks that would break due to CTEs. */
IF @CheckUserDatabaseObjects = 1 AND EXISTS(SELECT * FROM sys.databases WHERE compatibility_level < 90)
BEGIN
SET @CheckUserDatabaseObjects = 0;
PRINT 'Databases with compatibility level < 90 found, so setting @CheckUserDatabaseObjects = 0.';
PRINT 'The database-level checks rely on CTEs, which are not supported in SQL 2000 compat level databases.';
PRINT 'Get with the cool kids and switch to a current compatibility level, Grandpa. To find the problems, run:';
PRINT 'SELECT * FROM sys.databases WHERE compatibility_level < 90;';
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 204 AS CheckID ,
0 AS Priority ,
'Informational' AS FindingsGroup ,
'@CheckUserDatabaseObjects Disabled' AS Finding ,
'https://www.BrentOzar.com/blitz/' AS URL ,
'Since you have databases with compatibility_level < 90, we can''t run @CheckUserDatabaseObjects = 1. To find them: SELECT * FROM sys.databases WHERE compatibility_level < 90' AS Details;
END;
/* --TOURSTOP08-- */
/* If the server is Amazon RDS, skip checks that it doesn't allow */
IF LEFT(CAST(SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS VARCHAR(8000)), 8) = 'EC2AMAZ-'
AND LEFT(CAST(SERVERPROPERTY('MachineName') AS VARCHAR(8000)), 8) = 'EC2AMAZ-'
AND db_id('rdsadmin') IS NOT NULL
AND EXISTS(SELECT * FROM master.sys.all_objects WHERE name IN ('rds_startup_tasks', 'rds_help_revlogin', 'rds_hexadecimal', 'rds_failover_tracking', 'rds_database_tracking', 'rds_track_change'))
BEGIN
INSERT INTO #SkipChecks (CheckID) VALUES (6); /* Security - Jobs Owned By Users per https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1919 */
INSERT INTO #SkipChecks (CheckID) VALUES (29); /* tables in model database created by users - not allowed */
INSERT INTO #SkipChecks (CheckID) VALUES (40); /* TempDB only has one data file in RDS */
INSERT INTO #SkipChecks (CheckID) VALUES (62); /* Database compatibility level - cannot change in RDS */
INSERT INTO #SkipChecks (CheckID) VALUES (68); /*Check for the last good DBCC CHECKDB date - can't run DBCC DBINFO() */
INSERT INTO #SkipChecks (CheckID) VALUES (69); /* High VLF check - requires DBCC LOGINFO permission */
INSERT INTO #SkipChecks (CheckID) VALUES (73); /* No Failsafe Operator Configured check */
INSERT INTO #SkipChecks (CheckID) VALUES (92); /* Drive info check - requires xp_Fixeddrives permission */
INSERT INTO #SkipChecks (CheckID) VALUES (100); /* Remote DAC disabled */
INSERT INTO #SkipChecks (CheckID) VALUES (177); /* Disabled Internal Monitoring Features check - requires dm_server_registry access */
INSERT INTO #SkipChecks (CheckID) VALUES (180); /* 180/181 are maintenance plans checks - Maint plans not available in RDS*/
INSERT INTO #SkipChecks (CheckID) VALUES (181); /*Find repetitive maintenance tasks*/
-- can check errorlog using rdsadmin.dbo.rds_read_error_log, so allow this check
--INSERT INTO #SkipChecks (CheckID) VALUES (193); /* xp_readerrorlog checking for IFI */
INSERT INTO #SkipChecks (CheckID) VALUES (211); /* xp_regread not allowed - checking for power saving */
INSERT INTO #SkipChecks (CheckID) VALUES (212); /* xp_regread not allowed - checking for additional instances */
INSERT INTO #SkipChecks (CheckID) VALUES (2301); /* sp_validatelogins called by Invalid login defined with Windows Authentication */
-- Following are skipped due to limited permissions in msdb/SQLAgent in RDS
INSERT INTO #SkipChecks (CheckID) VALUES (30); /* SQL Server Agent alerts not configured */
INSERT INTO #SkipChecks (CheckID) VALUES (31); /* check whether we have NO ENABLED operators */
INSERT INTO #SkipChecks (CheckID) VALUES (57); /* SQL Agent Job Runs at Startup */
INSERT INTO #SkipChecks (CheckID) VALUES (59); /* Alerts Configured without Follow Up */
INSERT INTO #SkipChecks (CheckID) VALUES (61); /*SQL Server Agent alerts do not exist for severity levels 19 through 25*/
INSERT INTO #SkipChecks (CheckID) VALUES (79); /* Shrink Database Job check */
INSERT INTO #SkipChecks (CheckID) VALUES (94); /* job failure without operator notification check */
INSERT INTO #SkipChecks (CheckID) VALUES (96); /* Agent alerts for corruption */
INSERT INTO #SkipChecks (CheckID) VALUES (98); /* check for disabled alerts */
INSERT INTO #SkipChecks (CheckID) VALUES (123); /* Agent Jobs Starting Simultaneously */
INSERT INTO #SkipChecks (CheckID) VALUES (219); /* check for alerts that do NOT include event descriptions in their outputs via email/pager/net-send */
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 223 AS CheckID ,
0 AS Priority ,
'Informational' AS FindingsGroup ,
'Some Checks Skipped' AS Finding ,
'https://aws.amazon.com/rds/sqlserver/' AS URL ,
'Amazon RDS detected, so we skipped some checks that are not currently possible, relevant, or practical there.' AS Details;
END; /* Amazon RDS skipped checks */
/* If the server is ExpressEdition, skip checks that it doesn't allow */
IF CAST(SERVERPROPERTY('Edition') AS NVARCHAR(1000)) LIKE N'%Express%'
BEGIN
INSERT INTO #SkipChecks (CheckID) VALUES (30); /* Alerts not configured */
INSERT INTO #SkipChecks (CheckID) VALUES (31); /* Operators not configured */
INSERT INTO #SkipChecks (CheckID) VALUES (61); /* Agent alerts 19-25 */
INSERT INTO #SkipChecks (CheckID) VALUES (73); /* Failsafe operator */
INSERT INTO #SkipChecks (CheckID) VALUES (96); /* Agent alerts for corruption */
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 223 AS CheckID ,
0 AS Priority ,
'Informational' AS FindingsGroup ,
'Some Checks Skipped' AS Finding ,
'https://stackoverflow.com/questions/1169634/limitations-of-sql-server-express' AS URL ,
'Express Edition detected, so we skipped some checks that are not currently possible, relevant, or practical there.' AS Details;
END; /* Express Edition skipped checks */
/* If the server is an Azure Managed Instance, skip checks that it doesn't allow */
IF SERVERPROPERTY('EngineEdition') = 8
BEGIN
INSERT INTO #SkipChecks (CheckID) VALUES (1); /* Full backups - because of the MI GUID name bug mentioned here: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1481 */
INSERT INTO #SkipChecks (CheckID) VALUES (2); /* Log backups - because of the MI GUID name bug mentioned here: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1481 */
INSERT INTO #SkipChecks (CheckID) VALUES (6); /* Security - Jobs Owned By Users per https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1919 */
INSERT INTO #SkipChecks (CheckID) VALUES (21); /* Informational - Database Encrypted per https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1919 */
INSERT INTO #SkipChecks (CheckID) VALUES (24); /* File Configuration - System Database on C Drive per https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1919 */
INSERT INTO #SkipChecks (CheckID) VALUES (50); /* Max Server Memory Set Too High - because they max it out */
INSERT INTO #SkipChecks (CheckID) VALUES (55); /* Security - Database Owner <> sa per https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1919 */
INSERT INTO #SkipChecks (CheckID) VALUES (74); /* TraceFlag On - because Azure Managed Instances go wild and crazy with the trace flags */
INSERT INTO #SkipChecks (CheckID) VALUES (97); /* Unusual SQL Server Edition */
INSERT INTO #SkipChecks (CheckID) VALUES (100); /* Remote DAC disabled - but it's working anyway, details here: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1481 */
INSERT INTO #SkipChecks (CheckID) VALUES (186); /* MSDB Backup History Purged Too Frequently */
INSERT INTO #SkipChecks (CheckID) VALUES (199); /* Default trace, details here: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1481 */
INSERT INTO #SkipChecks (CheckID) VALUES (211); /*Power Plan */
INSERT INTO #SkipChecks (CheckID, DatabaseName) VALUES (80, 'master'); /* Max file size set */
INSERT INTO #SkipChecks (CheckID, DatabaseName) VALUES (80, 'model'); /* Max file size set */
INSERT INTO #SkipChecks (CheckID, DatabaseName) VALUES (80, 'msdb'); /* Max file size set */
INSERT INTO #SkipChecks (CheckID, DatabaseName) VALUES (80, 'tempdb'); /* Max file size set */
INSERT INTO #SkipChecks (CheckID) VALUES (224); /* CheckID 224 - Performance - SSRS/SSAS/SSIS Installed */
INSERT INTO #SkipChecks (CheckID) VALUES (92); /* CheckID 92 - drive space */
INSERT INTO #SkipChecks (CheckID) VALUES (258);/* CheckID 258 - Security - SQL Server service is running as LocalSystem or NT AUTHORITY\SYSTEM */
INSERT INTO #SkipChecks (CheckID) VALUES (259);/* CheckID 259 - Security - SQL Server Agent service is running as LocalSystem or NT AUTHORITY\SYSTEM */
INSERT INTO #SkipChecks (CheckID) VALUES (260); /* CheckID 260 - Security - SQL Server service account is member of Administrators */
INSERT INTO #SkipChecks (CheckID) VALUES (261); /*CheckID 261 - Security - SQL Server Agent service account is member of Administrators */
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 223 AS CheckID ,
0 AS Priority ,
'Informational' AS FindingsGroup ,
'Some Checks Skipped' AS Finding ,
'https://docs.microsoft.com/en-us/azure/sql-database/sql-database-managed-instance-index' AS URL ,
'Managed Instance detected, so we skipped some checks that are not currently possible, relevant, or practical there.' AS Details;
END; /* Azure Managed Instance skipped checks */
/*
That's the end of the SkipChecks stuff.
The next several tables are used by various checks later.
*/
IF OBJECT_ID('tempdb..#ConfigurationDefaults') IS NOT NULL
DROP TABLE #ConfigurationDefaults;
CREATE TABLE #ConfigurationDefaults
(
name NVARCHAR(128) ,
DefaultValue BIGINT,
CheckID INT
);
IF OBJECT_ID ('tempdb..#Recompile') IS NOT NULL
DROP TABLE #Recompile;
CREATE TABLE #Recompile(
DBName varchar(200),
ProcName varchar(300),
RecompileFlag varchar(1),
SPSchema varchar(50)
);
IF OBJECT_ID('tempdb..#DatabaseDefaults') IS NOT NULL
DROP TABLE #DatabaseDefaults;
CREATE TABLE #DatabaseDefaults
(
name NVARCHAR(128) ,
DefaultValue NVARCHAR(200),
CheckID INT,
Priority INT,
Finding VARCHAR(200),
URL VARCHAR(200),
Details NVARCHAR(4000)
);
IF OBJECT_ID('tempdb..#DatabaseScopedConfigurationDefaults') IS NOT NULL
DROP TABLE #DatabaseScopedConfigurationDefaults;
CREATE TABLE #DatabaseScopedConfigurationDefaults
(ID INT IDENTITY(1,1), configuration_id INT, [name] NVARCHAR(60), default_value sql_variant, default_value_for_secondary sql_variant, CheckID INT, );
IF OBJECT_ID('tempdb..#DBCCs') IS NOT NULL
DROP TABLE #DBCCs;
CREATE TABLE #DBCCs
(
ID INT IDENTITY(1, 1)
PRIMARY KEY ,
ParentObject VARCHAR(255) ,
Object VARCHAR(255) ,
Field VARCHAR(255) ,
Value VARCHAR(255) ,
DbName NVARCHAR(128) NULL
);
IF OBJECT_ID('tempdb..#LogInfo2012') IS NOT NULL
DROP TABLE #LogInfo2012;
CREATE TABLE #LogInfo2012
(
recoveryunitid INT ,
FileID SMALLINT ,
FileSize BIGINT ,
StartOffset BIGINT ,
FSeqNo BIGINT ,
[Status] TINYINT ,
Parity TINYINT ,
CreateLSN NUMERIC(38)
);
IF OBJECT_ID('tempdb..#LogInfo') IS NOT NULL
DROP TABLE #LogInfo;
CREATE TABLE #LogInfo
(
FileID SMALLINT ,
FileSize BIGINT ,
StartOffset BIGINT ,
FSeqNo BIGINT ,
[Status] TINYINT ,
Parity TINYINT ,
CreateLSN NUMERIC(38)
);
IF OBJECT_ID('tempdb..#partdb') IS NOT NULL
DROP TABLE #partdb;
CREATE TABLE #partdb
(
dbname NVARCHAR(128) ,
objectname NVARCHAR(200) ,
type_desc NVARCHAR(128)
);
IF OBJECT_ID('tempdb..#TraceStatus') IS NOT NULL
DROP TABLE #TraceStatus;
CREATE TABLE #TraceStatus
(
TraceFlag VARCHAR(10) ,
status BIT ,
Global BIT ,
Session BIT
);
IF OBJECT_ID('tempdb..#driveInfo') IS NOT NULL