forked from BrentOzarULTD/SQL-Server-First-Responder-Kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
sp_Blitz.sql
executable file
·7927 lines (7024 loc) · 347 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 ,
@Debug TINYINT = 0,
@VersionDate DATETIME = NULL OUTPUT
WITH RECOMPILE
AS
SET NOCOUNT ON;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
DECLARE @Version VARCHAR(30);
SET @Version = '6.4';
SET @VersionDate = '20180401';
SET @OutputType = UPPER(@OutputType);
IF @Help = 1 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 | ''SCHEMA''=version and field list | ''NONE'' = none
@IgnorePrioritiesBelow 50=ignore priorities below 50
@IgnorePrioritiesAbove 50=ignore priorities above 50
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 copyright for sp_Blitz are held by Brent Ozar Unlimited, 2017.
Copyright (c) 2017 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.
*/';
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;
ELSE /* IF @OutputType = 'SCHEMA' */
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
,@TraceFileIssue bit
-- Flag for Windows OS to help with Linux support
,@IsWindowsOperatingSystem BIT
,@DaysUptime NUMERIC(23,2);
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;
/*
--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)
);
/*
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.
Really anal-retentive users will note that the @SkipChecksServer parameter is
not used. YET. We added that parameter in so that we could avoid changing the
stored proc's surface area (interface) later.
*/
/* --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);
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 = 'INSERT INTO #SkipChecks(DatabaseName, CheckID, ServerName )
SELECT DISTINCT DatabaseName, CheckID, ServerName
FROM ' + QUOTENAME(@SkipChecksDatabase) + '.' + QUOTENAME(@SkipChecksSchema) + '.' + QUOTENAME(@SkipChecksTable)
+ ' WHERE ServerName IS NULL OR ServerName = SERVERPROPERTY(''ServerName'') OPTION (RECOMPILE);';
EXEC(@StringToExecute);
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
-- 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;
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)
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 LEFT(CAST(SERVERPROPERTY('ServerName') AS VARCHAR(8000)), 8) = 'EC2AMAZ-'
BEGIN
INSERT INTO #SkipChecks (CheckID) VALUES (6);
INSERT INTO #SkipChecks (CheckID) VALUES (29);
INSERT INTO #SkipChecks (CheckID) VALUES (30);
INSERT INTO #SkipChecks (CheckID) VALUES (31);
INSERT INTO #SkipChecks (CheckID) VALUES (40); /* TempDB only has one data file */
INSERT INTO #SkipChecks (CheckID) VALUES (57);
INSERT INTO #SkipChecks (CheckID) VALUES (59);
INSERT INTO #SkipChecks (CheckID) VALUES (61);
INSERT INTO #SkipChecks (CheckID) VALUES (62);
INSERT INTO #SkipChecks (CheckID) VALUES (68);
INSERT INTO #SkipChecks (CheckID) VALUES (69);
INSERT INTO #SkipChecks (CheckID) VALUES (73);
INSERT INTO #SkipChecks (CheckID) VALUES (79);
INSERT INTO #SkipChecks (CheckID) VALUES (92);
INSERT INTO #SkipChecks (CheckID) VALUES (94);
INSERT INTO #SkipChecks (CheckID) VALUES (96);
INSERT INTO #SkipChecks (CheckID) VALUES (98);
INSERT INTO #SkipChecks (CheckID) VALUES (100); /* Remote DAC disabled */
INSERT INTO #SkipChecks (CheckID) VALUES (123);
INSERT INTO #SkipChecks (CheckID) VALUES (177);
INSERT INTO #SkipChecks (CheckID) VALUES (180); /* 180/181 are maintenance plans */
INSERT INTO #SkipChecks (CheckID) VALUES (181);
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 */
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 (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 (199); /* Default trace, details here: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/1481 */
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
DROP TABLE #driveInfo;
CREATE TABLE #driveInfo
(
drive NVARCHAR ,
SIZE DECIMAL(18, 2)
);
IF OBJECT_ID('tempdb..#dm_exec_query_stats') IS NOT NULL
DROP TABLE #dm_exec_query_stats;
CREATE TABLE #dm_exec_query_stats
(
[id] [int] NOT NULL
IDENTITY(1, 1) ,
[sql_handle] [varbinary](64) NOT NULL ,
[statement_start_offset] [int] NOT NULL ,
[statement_end_offset] [int] NOT NULL ,
[plan_generation_num] [bigint] NOT NULL ,
[plan_handle] [varbinary](64) NOT NULL ,
[creation_time] [datetime] NOT NULL ,
[last_execution_time] [datetime] NOT NULL ,
[execution_count] [bigint] NOT NULL ,
[total_worker_time] [bigint] NOT NULL ,
[last_worker_time] [bigint] NOT NULL ,
[min_worker_time] [bigint] NOT NULL ,
[max_worker_time] [bigint] NOT NULL ,
[total_physical_reads] [bigint] NOT NULL ,
[last_physical_reads] [bigint] NOT NULL ,
[min_physical_reads] [bigint] NOT NULL ,
[max_physical_reads] [bigint] NOT NULL ,
[total_logical_writes] [bigint] NOT NULL ,
[last_logical_writes] [bigint] NOT NULL ,
[min_logical_writes] [bigint] NOT NULL ,
[max_logical_writes] [bigint] NOT NULL ,
[total_logical_reads] [bigint] NOT NULL ,
[last_logical_reads] [bigint] NOT NULL ,
[min_logical_reads] [bigint] NOT NULL ,
[max_logical_reads] [bigint] NOT NULL ,
[total_clr_time] [bigint] NOT NULL ,
[last_clr_time] [bigint] NOT NULL ,
[min_clr_time] [bigint] NOT NULL ,
[max_clr_time] [bigint] NOT NULL ,
[total_elapsed_time] [bigint] NOT NULL ,
[last_elapsed_time] [bigint] NOT NULL ,
[min_elapsed_time] [bigint] NOT NULL ,
[max_elapsed_time] [bigint] NOT NULL ,
[query_hash] [binary](8) NULL ,
[query_plan_hash] [binary](8) NULL ,
[query_plan] [xml] NULL ,
[query_plan_filtered] [nvarchar](MAX) NULL ,
[text] [nvarchar](MAX) COLLATE SQL_Latin1_General_CP1_CI_AS
NULL ,
[text_filtered] [nvarchar](MAX) COLLATE SQL_Latin1_General_CP1_CI_AS
NULL
);
IF OBJECT_ID('tempdb..#ErrorLog') IS NOT NULL
DROP TABLE #ErrorLog;
CREATE TABLE #ErrorLog
(
LogDate DATETIME ,
ProcessInfo NVARCHAR(20) ,
[Text] NVARCHAR(1000)
);
IF OBJECT_ID('tempdb..#fnTraceGettable') IS NOT NULL
DROP TABLE #fnTraceGettable;
CREATE TABLE #fnTraceGettable
(
TextData NVARCHAR(4000) ,
DatabaseName NVARCHAR(256) ,
EventClass INT ,
Severity INT ,
StartTime DATETIME ,
EndTime DATETIME ,
Duration BIGINT ,
NTUserName NVARCHAR(256) ,
NTDomainName NVARCHAR(256) ,
HostName NVARCHAR(256) ,
ApplicationName NVARCHAR(256) ,
LoginName NVARCHAR(256) ,
DBUserName NVARCHAR(256)
);
IF OBJECT_ID('tempdb..#Instances') IS NOT NULL
DROP TABLE #Instances;
CREATE TABLE #Instances
(
Instance_Number NVARCHAR(MAX) ,
Instance_Name NVARCHAR(MAX) ,
Data_Field NVARCHAR(MAX)
);
IF OBJECT_ID('tempdb..#IgnorableWaits') IS NOT NULL
DROP TABLE #IgnorableWaits;
CREATE TABLE #IgnorableWaits (wait_type NVARCHAR(60));
INSERT INTO #IgnorableWaits VALUES ('BROKER_EVENTHANDLER');
INSERT INTO #IgnorableWaits VALUES ('BROKER_RECEIVE_WAITFOR');
INSERT INTO #IgnorableWaits VALUES ('BROKER_TASK_STOP');
INSERT INTO #IgnorableWaits VALUES ('BROKER_TO_FLUSH');
INSERT INTO #IgnorableWaits VALUES ('BROKER_TRANSMITTER');
INSERT INTO #IgnorableWaits VALUES ('CHECKPOINT_QUEUE');
INSERT INTO #IgnorableWaits VALUES ('CLR_AUTO_EVENT');
INSERT INTO #IgnorableWaits VALUES ('CLR_MANUAL_EVENT');
INSERT INTO #IgnorableWaits VALUES ('CLR_SEMAPHORE');
INSERT INTO #IgnorableWaits VALUES ('DBMIRROR_DBM_EVENT');
INSERT INTO #IgnorableWaits VALUES ('DBMIRROR_DBM_MUTEX');
INSERT INTO #IgnorableWaits VALUES ('DBMIRROR_EVENTS_QUEUE');
INSERT INTO #IgnorableWaits VALUES ('DBMIRROR_WORKER_QUEUE');
INSERT INTO #IgnorableWaits VALUES ('DBMIRRORING_CMD');
INSERT INTO #IgnorableWaits VALUES ('DIRTY_PAGE_POLL');
INSERT INTO #IgnorableWaits VALUES ('DISPATCHER_QUEUE_SEMAPHORE');
INSERT INTO #IgnorableWaits VALUES ('FT_IFTS_SCHEDULER_IDLE_WAIT');
INSERT INTO #IgnorableWaits VALUES ('FT_IFTSHC_MUTEX');
INSERT INTO #IgnorableWaits VALUES ('HADR_CLUSAPI_CALL');
INSERT INTO #IgnorableWaits VALUES ('HADR_FILESTREAM_IOMGR_IOCOMPLETION');
INSERT INTO #IgnorableWaits VALUES ('HADR_LOGCAPTURE_WAIT');
INSERT INTO #IgnorableWaits VALUES ('HADR_NOTIFICATION_DEQUEUE');
INSERT INTO #IgnorableWaits VALUES ('HADR_TIMER_TASK');
INSERT INTO #IgnorableWaits VALUES ('HADR_WORK_QUEUE');
INSERT INTO #IgnorableWaits VALUES ('LAZYWRITER_SLEEP');
INSERT INTO #IgnorableWaits VALUES ('LOGMGR_QUEUE');
INSERT INTO #IgnorableWaits VALUES ('ONDEMAND_TASK_QUEUE');
INSERT INTO #IgnorableWaits VALUES ('PREEMPTIVE_HADR_LEASE_MECHANISM');
INSERT INTO #IgnorableWaits VALUES ('PREEMPTIVE_SP_SERVER_DIAGNOSTICS');
INSERT INTO #IgnorableWaits VALUES ('QDS_ASYNC_QUEUE');
INSERT INTO #IgnorableWaits VALUES ('QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP');
INSERT INTO #IgnorableWaits VALUES ('QDS_PERSIST_TASK_MAIN_LOOP_SLEEP');
INSERT INTO #IgnorableWaits VALUES ('QDS_SHUTDOWN_QUEUE');
INSERT INTO #IgnorableWaits VALUES ('REDO_THREAD_PENDING_WORK');
INSERT INTO #IgnorableWaits VALUES ('REQUEST_FOR_DEADLOCK_SEARCH');
INSERT INTO #IgnorableWaits VALUES ('SLEEP_SYSTEMTASK');
INSERT INTO #IgnorableWaits VALUES ('SLEEP_TASK');
INSERT INTO #IgnorableWaits VALUES ('SP_SERVER_DIAGNOSTICS_SLEEP');
INSERT INTO #IgnorableWaits VALUES ('SQLTRACE_BUFFER_FLUSH');
INSERT INTO #IgnorableWaits VALUES ('SQLTRACE_INCREMENTAL_FLUSH_SLEEP');
INSERT INTO #IgnorableWaits VALUES ('UCS_SESSION_REGISTRATION');
INSERT INTO #IgnorableWaits VALUES ('WAIT_XTP_OFFLINE_CKPT_NEW_LOG');
INSERT INTO #IgnorableWaits VALUES ('WAITFOR');
INSERT INTO #IgnorableWaits VALUES ('XE_DISPATCHER_WAIT');
INSERT INTO #IgnorableWaits VALUES ('XE_LIVE_TARGET_TVF');
INSERT INTO #IgnorableWaits VALUES ('XE_TIMER_EVENT');
IF @Debug IN (1, 2) RAISERROR('Setting @MsSinceWaitsCleared', 0, 1) WITH NOWAIT;
SELECT @MsSinceWaitsCleared = DATEDIFF(MINUTE, create_date, CURRENT_TIMESTAMP) * 60000.0
FROM sys.databases
WHERE name = 'tempdb';
/* Have they cleared wait stats? Using a 10% fudge factor */
IF @MsSinceWaitsCleared * .9 > (SELECT MAX(wait_time_ms) FROM sys.dm_os_wait_stats WHERE wait_type IN ('SP_SERVER_DIAGNOSTICS_SLEEP', 'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', 'REQUEST_FOR_DEADLOCK_SEARCH', 'HADR_FILESTREAM_IOMGR_IOCOMPLETION', 'LAZYWRITER_SLEEP', 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', 'DIRTY_PAGE_POLL', 'LOGMGR_QUEUE'))
BEGIN
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 185) WITH NOWAIT;
SET @MsSinceWaitsCleared = (SELECT MAX(wait_time_ms) FROM sys.dm_os_wait_stats WHERE wait_type IN ('SP_SERVER_DIAGNOSTICS_SLEEP', 'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', 'REQUEST_FOR_DEADLOCK_SEARCH', 'HADR_FILESTREAM_IOMGR_IOCOMPLETION', 'LAZYWRITER_SLEEP', 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', 'DIRTY_PAGE_POLL', 'LOGMGR_QUEUE'));
IF @MsSinceWaitsCleared = 0 SET @MsSinceWaitsCleared = 1;
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
VALUES( 185,
240,
'Wait Stats',
'Wait Stats Have Been Cleared',
'https://BrentOzar.com/go/waits',
'Someone ran DBCC SQLPERF to clear sys.dm_os_wait_stats at approximately: ' + CONVERT(NVARCHAR(100), DATEADD(ms, (-1 * @MsSinceWaitsCleared), GETDATE()), 120));
END;
/* @CpuMsSinceWaitsCleared is used for waits stats calculations */
IF @Debug IN (1, 2) RAISERROR('Setting @CpuMsSinceWaitsCleared', 0, 1) WITH NOWAIT;
SELECT @CpuMsSinceWaitsCleared = @MsSinceWaitsCleared * scheduler_count
FROM sys.dm_os_sys_info;
/* If we're outputting CSV or Markdown, don't bother checking the plan cache because we cannot export plans. */
IF @OutputType = 'CSV' OR @OutputType = 'MARKDOWN'
SET @CheckProcedureCache = 0;
/* If we're posting a question on Stack, include background info on the server */
IF @OutputType = 'MARKDOWN'
SET @CheckServerInfo = 1;
/* Only run CheckUserDatabaseObjects if there are less than 50 databases. */
IF @BringThePain = 0 AND 50 <= (SELECT COUNT(*) FROM sys.databases) AND @CheckUserDatabaseObjects = 1
BEGIN
SET @CheckUserDatabaseObjects = 0;
PRINT 'Running sp_Blitz @CheckUserDatabaseObjects = 1 on a server with 50+ databases may cause temporary insanity for the server and/or user.';
PRINT 'If you''re sure you want to do this, run again with the parameter @BringThePain = 1.';
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 201 AS CheckID ,
0 AS Priority ,
'Informational' AS FindingsGroup ,
'@CheckUserDatabaseObjects Disabled' AS Finding ,
'https://www.BrentOzar.com/blitz/' AS URL ,
'If you want to check 50+ databases, you have to also use @BringThePain = 1.' AS Details;
END;
/* Sanitize our inputs */
SELECT
@OutputServerName = QUOTENAME(@OutputServerName),
@OutputDatabaseName = QUOTENAME(@OutputDatabaseName),
@OutputSchemaName = QUOTENAME(@OutputSchemaName),
@OutputTableName = QUOTENAME(@OutputTableName);
/* Get the major and minor build numbers */
IF @Debug IN (1, 2) RAISERROR('Getting version information.', 0, 1) WITH NOWAIT;
SET @ProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128));
SELECT @ProductVersionMajor = SUBSTRING(@ProductVersion, 1,CHARINDEX('.', @ProductVersion) + 1 ),
@ProductVersionMinor = PARSENAME(CONVERT(varchar(32), @ProductVersion), 2);
/*
Whew! we're finally done with the setup, and we can start doing checks.
First, let's make sure we're actually supposed to do checks on this server.
The user could have passed in a SkipChecks table that specified to skip ALL
checks on this server, so let's check for that:
*/
IF ( ( SERVERPROPERTY('ServerName') NOT IN ( SELECT ServerName
FROM #SkipChecks
WHERE DatabaseName IS NULL
AND CheckID IS NULL ) )
OR ( @SkipChecksTable IS NULL )
)
BEGIN
/*
Our very first check! We'll put more comments in this one just to
explain exactly how it works. First, we check to see if we're
supposed to skip CheckID 1 (that's the check we're working on.)
*/
IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 1 )
BEGIN
/*
Below, we check master.sys.databases looking for databases
that haven't had a backup in the last week. If we find any,
we insert them into #BlitzResults, the temp table that
tracks our server's problems. Note that if the check does
NOT find any problems, we don't save that. We're only
saving the problems, not the successful checks.
*/
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 1) WITH NOWAIT;
IF SERVERPROPERTY('EngineName') <> 8 /* Azure Managed Instances need a special query */
BEGIN
INSERT INTO #BlitzResults
( CheckID ,
DatabaseName ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 1 AS CheckID ,
d.[name] AS DatabaseName ,
1 AS Priority ,
'Backup' AS FindingsGroup ,
'Backups Not Performed Recently' AS Finding ,
'https://BrentOzar.com/go/nobak' AS URL ,
'Last backed up: '
+ COALESCE(CAST(MAX(b.backup_finish_date) AS VARCHAR(25)),'never') AS Details
FROM master.sys.databases d
LEFT OUTER JOIN msdb.dbo.backupset b ON d.name COLLATE SQL_Latin1_General_CP1_CI_AS = b.database_name COLLATE SQL_Latin1_General_CP1_CI_AS
AND b.type = 'D'
AND b.server_name = SERVERPROPERTY('ServerName') /*Backupset ran on current server */
WHERE d.database_id <> 2 /* Bonus points if you know what that means */
AND d.state NOT IN(1, 6, 10) /* Not currently offline or restoring, like log shipping databases */
AND d.is_in_standby = 0 /* Not a log shipping target database */
AND d.source_database_id IS NULL /* Excludes database snapshots */
AND d.name NOT IN ( SELECT DISTINCT
DatabaseName
FROM #SkipChecks
WHERE CheckID IS NULL OR CheckID = 1)
/*
The above NOT IN filters out the databases we're not supposed to check.
*/
GROUP BY d.name
HAVING MAX(b.backup_finish_date) <= DATEADD(dd,
-7, GETDATE())
OR MAX(b.backup_finish_date) IS NULL;
END;
ELSE /* SERVERPROPERTY('EngineName') must be 8, Azure Managed Instances */
BEGIN
INSERT INTO #BlitzResults
( CheckID ,
DatabaseName ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 1 AS CheckID ,
d.[name] AS DatabaseName ,
1 AS Priority ,
'Backup' AS FindingsGroup ,
'Backups Not Performed Recently' AS Finding ,
'https://BrentOzar.com/go/nobak' AS URL ,
'Last backed up: '
+ COALESCE(CAST(MAX(b.backup_finish_date) AS VARCHAR(25)),'never') AS Details
FROM master.sys.databases d
LEFT OUTER JOIN msdb.dbo.backupset b ON d.name COLLATE SQL_Latin1_General_CP1_CI_AS = b.database_name COLLATE SQL_Latin1_General_CP1_CI_AS
AND b.type = 'D'
WHERE d.database_id <> 2 /* Bonus points if you know what that means */
AND d.state NOT IN(1, 6, 10) /* Not currently offline or restoring, like log shipping databases */
AND d.is_in_standby = 0 /* Not a log shipping target database */
AND d.source_database_id IS NULL /* Excludes database snapshots */
AND d.name NOT IN ( SELECT DISTINCT
DatabaseName
FROM #SkipChecks
WHERE CheckID IS NULL OR CheckID = 1)
/*
The above NOT IN filters out the databases we're not supposed to check.
*/
GROUP BY d.name
HAVING MAX(b.backup_finish_date) <= DATEADD(dd,
-7, GETDATE())
OR MAX(b.backup_finish_date) IS NULL;
END;
/*
And there you have it. The rest of this stored procedure works the same
way: it asks:
- Should I skip this check?
- If not, do I find problems?
- Insert the results into #BlitzResults
*/
END;
/*
And that's the end of CheckID #1.
CheckID #2 is a little simpler because it only involves one query, and it's
more typical for queries that people contribute. But keep reading, because
the next check gets more complex again.
*/
IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 2 )
BEGIN
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 2) WITH NOWAIT;
INSERT INTO #BlitzResults
( CheckID ,
DatabaseName ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT DISTINCT
2 AS CheckID ,
d.name AS DatabaseName ,
1 AS Priority ,
'Backup' AS FindingsGroup ,
'Full Recovery Model w/o Log Backups' AS Finding ,
'https://BrentOzar.com/go/biglogs' AS URL ,
( 'The ' + CAST(CAST((SELECT ((SUM([mf].[size]) * 8.) / 1024.) FROM sys.[master_files] AS [mf] WHERE [mf].[database_id] = d.[database_id] AND [mf].[type_desc] = 'LOG') AS DECIMAL(18,2)) AS VARCHAR(30)) + 'MB log file has not been backed up in the last week.' ) AS Details
FROM master.sys.databases d
WHERE d.recovery_model IN ( 1, 2 )
AND d.database_id NOT IN ( 2, 3 )
AND d.source_database_id IS NULL
AND d.state NOT IN(1, 6, 10) /* Not currently offline or restoring, like log shipping databases */
AND d.is_in_standby = 0 /* Not a log shipping target database */
AND d.source_database_id IS NULL /* Excludes database snapshots */
AND d.name NOT IN ( SELECT DISTINCT
DatabaseName
FROM #SkipChecks
WHERE CheckID IS NULL OR CheckID = 2)
AND NOT EXISTS ( SELECT *
FROM msdb.dbo.backupset b
WHERE d.name COLLATE SQL_Latin1_General_CP1_CI_AS = b.database_name COLLATE SQL_Latin1_General_CP1_CI_AS
AND b.type = 'L'
AND b.backup_finish_date >= DATEADD(dd,
-7, GETDATE()) );
END;
/*
Next up, we've got CheckID 8. (These don't have to go in order.) This one
won't work on SQL Server 2005 because it relies on a new DMV that didn't
exist prior to SQL Server 2008. This means we have to check the SQL Server
version first, then build a dynamic string with the query we want to run:
*/
IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 8 )
BEGIN
IF @@VERSION NOT LIKE '%Microsoft SQL Server 2000%'
AND @@VERSION NOT LIKE '%Microsoft SQL Server 2005%'
BEGIN
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 8) WITH NOWAIT;
SET @StringToExecute = 'INSERT INTO #BlitzResults
(CheckID, Priority,
FindingsGroup,
Finding, URL,
Details)
SELECT 8 AS CheckID,
230 AS Priority,
''Security'' AS FindingsGroup,
''Server Audits Running'' AS Finding,
''https://BrentOzar.com/go/audits'' AS URL,
(''SQL Server built-in audit functionality is being used by server audit: '' + [name]) AS Details FROM sys.dm_server_audit_status OPTION (RECOMPILE);';
IF @Debug = 2 AND @StringToExecute IS NOT NULL PRINT @StringToExecute;
IF @Debug = 2 AND @StringToExecute IS NULL PRINT '@StringToExecute has gone NULL, for some reason.';
EXECUTE(@StringToExecute);
END;
END;
/*
But what if you need to run a query in every individual database?
Hop down to the @CheckUserDatabaseObjects section.
And that's the basic idea! You can read through the rest of the
checks if you like - some more exciting stuff happens closer to the
end of the stored proc, where we start doing things like checking
the plan cache, but those aren't as cleanly commented.
If you'd like to contribute your own check, use one of the check
formats shown above and email it to [email protected]. You don't
have to pick a CheckID or a link - we'll take care of that when we
test and publish the code. Thanks!
*/
IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 93 )
BEGIN
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 93) WITH NOWAIT;
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT
93 AS CheckID ,
1 AS Priority ,
'Backup' AS FindingsGroup ,
'Backing Up to Same Drive Where Databases Reside' AS Finding ,
'https://BrentOzar.com/go/backup' AS URL ,
CAST(COUNT(1) AS VARCHAR(50)) + ' backups done on drive '
+ UPPER(LEFT(bmf.physical_device_name, 3))
+ ' in the last two weeks, where database files also live. This represents a serious risk if that array fails.' Details
FROM msdb.dbo.backupmediafamily AS bmf
INNER JOIN msdb.dbo.backupset AS bs ON bmf.media_set_id = bs.media_set_id
AND bs.backup_start_date >= ( DATEADD(dd,
-14, GETDATE()) )
/* Filter out databases that were recently restored: */
LEFT OUTER JOIN msdb.dbo.restorehistory rh ON bs.database_name = rh.destination_database_name AND rh.restore_date > DATEADD(dd, -14, GETDATE())
WHERE UPPER(LEFT(bmf.physical_device_name, 3)) <> 'HTT' AND
UPPER(LEFT(bmf.physical_device_name COLLATE SQL_Latin1_General_CP1_CI_AS, 3)) IN (
SELECT DISTINCT
UPPER(LEFT(mf.physical_name COLLATE SQL_Latin1_General_CP1_CI_AS, 3))
FROM sys.master_files AS mf )
AND rh.destination_database_name IS NULL
GROUP BY UPPER(LEFT(bmf.physical_device_name, 3));
END;
IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 119 )
AND EXISTS ( SELECT *
FROM sys.all_objects o
WHERE o.name = 'dm_database_encryption_keys' )
BEGIN
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 119) WITH NOWAIT;
SET @StringToExecute = 'INSERT INTO #BlitzResults (CheckID, Priority, FindingsGroup, Finding, DatabaseName, URL, Details)
SELECT 119 AS CheckID,
1 AS Priority,
''Backup'' AS FindingsGroup,
''TDE Certificate Not Backed Up Recently'' AS Finding,
db_name(dek.database_id) AS DatabaseName,
''https://BrentOzar.com/go/tde'' AS URL,
''The certificate '' + c.name + '' is used to encrypt database '' + db_name(dek.database_id) + ''. Last backup date: '' + COALESCE(CAST(c.pvt_key_last_backup_date AS VARCHAR(100)), ''Never'') AS Details
FROM sys.certificates c INNER JOIN sys.dm_database_encryption_keys dek ON c.thumbprint = dek.encryptor_thumbprint
WHERE pvt_key_last_backup_date IS NULL OR pvt_key_last_backup_date <= DATEADD(dd, -30, GETDATE()) OPTION (RECOMPILE);';
IF @Debug = 2 AND @StringToExecute IS NOT NULL PRINT @StringToExecute;
IF @Debug = 2 AND @StringToExecute IS NULL PRINT '@StringToExecute has gone NULL, for some reason.';
EXECUTE(@StringToExecute);
END;
IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 202 )
AND EXISTS ( SELECT *
FROM sys.all_columns c
WHERE c.name = 'pvt_key_last_backup_date' )
AND EXISTS ( SELECT *
FROM msdb.INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = 'backupset' AND c.COLUMN_NAME = 'encryptor_thumbprint' )
BEGIN
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 202) WITH NOWAIT;
SET @StringToExecute = 'INSERT INTO #BlitzResults (CheckID, Priority, FindingsGroup, Finding, URL, Details)
SELECT DISTINCT 202 AS CheckID,
1 AS Priority,
''Backup'' AS FindingsGroup,
''Encryption Certificate Not Backed Up Recently'' AS Finding,
''https://BrentOzar.com/go/tde'' AS URL,
''The certificate '' + c.name + '' is used to encrypt database backups. Last backup date: '' + COALESCE(CAST(c.pvt_key_last_backup_date AS VARCHAR(100)), ''Never'') AS Details
FROM sys.certificates c
INNER JOIN msdb.dbo.backupset bs ON c.thumbprint = bs.encryptor_thumbprint
WHERE pvt_key_last_backup_date IS NULL OR pvt_key_last_backup_date <= DATEADD(dd, -30, GETDATE()) OPTION (RECOMPILE);';
IF @Debug = 2 AND @StringToExecute IS NOT NULL PRINT @StringToExecute;
IF @Debug = 2 AND @StringToExecute IS NULL PRINT '@StringToExecute has gone NULL, for some reason.';
EXECUTE(@StringToExecute);
END;
IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 3 )
BEGIN
IF DATEADD(dd, -60, GETDATE()) > (SELECT TOP 1 backup_start_date FROM msdb.dbo.backupset ORDER BY backup_start_date)
BEGIN