diff --git a/SQLChecks/Auto Create Statistics is Off.sql b/SQLChecks/Auto Create Statistics is Off.sql index 3694d1d..f3d843a 100644 --- a/SQLChecks/Auto Create Statistics is Off.sql +++ b/SQLChecks/Auto Create Statistics is Off.sql @@ -20,6 +20,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -35,7 +36,26 @@ ELSE 1 END , - CurrentStateImpact = 3 , -- High - RecommendationEffort = 1 , -- Low - RecommendationRisk = 1 , -- Low + WorstCaseImpact = 3 , -- High + CurrentStateImpact = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 -- None + ELSE + 3 -- High + END , + RecommendationEffort = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 -- None + ELSE + 1 -- Low + END , + RecommendationRisk = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 -- None + ELSE + 1 -- Low + END , AdditionalInfo = @AdditionalInfo; diff --git a/SQLChecks/Columns with the IMAGE, TEXT, or NTEXT Data Types.sql b/SQLChecks/Columns with the IMAGE, TEXT, or NTEXT Data Types.sql index 0a3621d..8974253 100644 --- a/SQLChecks/Columns with the IMAGE, TEXT, or NTEXT Data Types.sql +++ b/SQLChecks/Columns with the IMAGE, TEXT, or NTEXT Data Types.sql @@ -144,6 +144,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -159,6 +160,7 @@ ELSE 1 END , + WorstCaseImpact = 1 , -- Low CurrentStateImpact = CASE WHEN @NumberOfColumns = 0 diff --git a/SQLChecks/Databases not in the Same Compatibility Level as the Instance.sql b/SQLChecks/Databases not in the Same Compatibility Level as the Instance.sql index 4a1fe6b..2386fbd 100644 --- a/SQLChecks/Databases not in the Same Compatibility Level as the Instance.sql +++ b/SQLChecks/Databases not in the Same Compatibility Level as the Instance.sql @@ -1,9 +1,17 @@ DECLARE - @InstanceCompatibilityLevel AS TINYINT; + @InstanceCompatibilityLevel AS TINYINT , + @NumberOfDatabases AS INT; SET @InstanceCompatibilityLevel = CAST (LEFT (CAST (SERVERPROPERTY ('ProductVersion') AS NVARCHAR(128)) , CHARINDEX (N'.' , CAST (SERVERPROPERTY ('ProductVersion') AS NVARCHAR(128))) - 1) AS TINYINT) * 10; + SELECT + @NumberOfDatabases = COUNT (*) + FROM + sys.databases + WHERE + [compatibility_level] != @InstanceCompatibilityLevel; + SET @AdditionalInfo = ( SELECT @@ -25,6 +33,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -40,7 +49,28 @@ ELSE 1 END , - CurrentStateImpact = 2 , -- Medium - RecommendationEffort = 2 , -- Medium - RecommendationRisk = 3 , -- Medium + WorstCaseImpact = 2 , -- Medium + CurrentStateImpact = + CASE + WHEN @NumberOfDatabases = 0 + THEN 0 -- None + ELSE + 2 -- Medium + END , + RecommendationEffort = + CASE + WHEN @NumberOfDatabases = 0 + THEN 0 -- None + WHEN @NumberOfDatabases BETWEEN 1 AND 5 + THEN 2 -- Medium + ELSE + 3 -- High + END , + RecommendationRisk = + CASE + WHEN @NumberOfDatabases = 0 + THEN 0 -- None + ELSE + 2 -- Medium + END , AdditionalInfo = @AdditionalInfo; diff --git a/SQLChecks/Databases with Auto-Close Enabled.sql b/SQLChecks/Databases with Auto-Close Enabled.sql index 70a5e44..3afe7de 100644 --- a/SQLChecks/Databases with Auto-Close Enabled.sql +++ b/SQLChecks/Databases with Auto-Close Enabled.sql @@ -20,6 +20,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -35,9 +36,28 @@ ELSE 1 END , - CurrentStateImpact = 1 , -- Low - RecommendationEffort = 1 , -- Low - RecommendationRisk = 1 , -- Low + WorstCaseImpact = 1 , -- Low + CurrentStateImpact = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 + ELSE + 1 -- Low + END , + RecommendationEffort = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 + ELSE + 1 -- Low + END , + RecommendationRisk = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 + ELSE + 1 -- Low + END , AdditionalInfo = @AdditionalInfo; BREAK; diff --git a/SQLChecks/Databases with Auto-Shrink Enabled.sql b/SQLChecks/Databases with Auto-Shrink Enabled.sql index 99bc381..b9b50c2 100644 --- a/SQLChecks/Databases with Auto-Shrink Enabled.sql +++ b/SQLChecks/Databases with Auto-Shrink Enabled.sql @@ -20,6 +20,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -35,9 +36,28 @@ ELSE 1 END , - CurrentStateImpact = 1 , -- Low - RecommendationEffort = 1 , -- Low - RecommendationRisk = 1 , -- Low + WorstCaseImpact = 1 , -- Low + CurrentStateImpact = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 + ELSE + 1 -- Low + END , + RecommendationEffort = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 + ELSE + 1 -- Low + END , + RecommendationRisk = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 + ELSE + 1 -- Low + END , AdditionalInfo = @AdditionalInfo; BREAK; diff --git a/SQLChecks/Heap Tables.sql b/SQLChecks/Heap Tables.sql index af2f06e..b185eff 100644 --- a/SQLChecks/Heap Tables.sql +++ b/SQLChecks/Heap Tables.sql @@ -1,7 +1,8 @@ DECLARE @DatabaseName AS SYSNAME , - @Command AS NVARCHAR(MAX); + @Command AS NVARCHAR(MAX) , + @NumberOfTables AS INT; DROP TABLE IF EXISTS #HeapTables; @@ -127,6 +128,11 @@ DEALLOCATE DatabasesCursor; + SELECT + @NumberOfTables = COUNT (*) + FROM + #HeapTables; + SET @AdditionalInfo = ( SELECT @@ -161,6 +167,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -176,9 +183,30 @@ ELSE 1 END , - CurrentStateImpact = 2 , -- Medium - RecommendationEffort = 3 , -- High - RecommendationRisk = 3 , -- High + WorstCaseImpact = 2 , -- Medium + CurrentStateImpact = + CASE + WHEN @NumberOfTables = 0 + THEN 0 -- None + ELSE + 2 -- Medium + END , + RecommendationEffort = + CASE + WHEN @NumberOfTables = 0 + THEN 0 -- None + WHEN @NumberOfTables BETWEEN 1 AND 5 + THEN 2 -- Medium + ELSE + 3 -- High + END , + RecommendationRisk = + CASE + WHEN @NumberOfTables = 0 + THEN 0 -- None + ELSE + 3 -- High + END , AdditionalInfo = @AdditionalInfo; DROP TABLE diff --git a/SQLChecks/Indexes with High Fragmentation.sql b/SQLChecks/Indexes with High Fragmentation.sql index cf660b3..afea143 100644 --- a/SQLChecks/Indexes with High Fragmentation.sql +++ b/SQLChecks/Indexes with High Fragmentation.sql @@ -1,7 +1,8 @@ DECLARE - @DatabaseName AS SYSNAME , - @Command AS NVARCHAR(MAX); + @DatabaseName AS SYSNAME , + @Command AS NVARCHAR(MAX) , + @NumberOfIndexes AS INT; DROP TABLE IF EXISTS #FragmentedIndexes; @@ -103,6 +104,12 @@ DEALLOCATE DatabasesCursor; + SELECT + @NumberOfIndexes = COUNT (*) + FROM + #FragmentedIndexes; + + SET @AdditionalInfo = ( SELECT @@ -139,6 +146,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -154,9 +162,30 @@ ELSE 1 END , - CurrentStateImpact = 2 , -- Medium - RecommendationEffort = 1 , -- Low - RecommendationRisk = 2 , -- Medium + WorstCaseImpact = 2 , -- Medium + CurrentStateImpact = + CASE + WHEN @NumberOfIndexes = 0 + THEN 0 -- None + WHEN @NumberOfIndexes BETWEEN 1 AND 10 + THEN 1 -- Low + ELSE + 2 -- Medium + END , + RecommendationEffort = + CASE + WHEN @NumberOfIndexes = 0 + THEN 0 -- None + ELSE + 1 -- Low + END , + RecommendationRisk = + CASE + WHEN @NumberOfIndexes = 0 + THEN 0 -- None + ELSE + 2 -- Medium + END , AdditionalInfo = @AdditionalInfo; DROP TABLE diff --git a/SQLChecks/Max Memory Configuration Too High.sql b/SQLChecks/Max Memory Configuration Too High.sql index 7db1377..e81c6da 100644 --- a/SQLChecks/Max Memory Configuration Too High.sql +++ b/SQLChecks/Max Memory Configuration Too High.sql @@ -74,6 +74,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -89,9 +90,28 @@ ELSE 0 END , - CurrentStateImpact = 2 , -- Medium - RecommendationEffort = 1 , -- Low - RecommendationRisk = 1 , -- Low + WorstCaseImpact = 2 , -- Medium + CurrentStateImpact = + CASE + WHEN @CurrentMaxMemorySetting_MB > @RecommendedMaxMemorySetting_MB + THEN 2 -- Medium + ELSE + 0 -- None + END , + RecommendationEffort = + CASE + WHEN @CurrentMaxMemorySetting_MB > @RecommendedMaxMemorySetting_MB + THEN 1 -- Low + ELSE + 0 -- None + END , + RecommendationRisk = + CASE + WHEN @CurrentMaxMemorySetting_MB > @RecommendedMaxMemorySetting_MB + THEN 1 -- Low + ELSE + 0 -- None + END , AdditionalInfo = @AdditionalInfo; BREAK; diff --git a/SQLChecks/Optimize for Ad-Hoc Workloads should be Enabled.sql b/SQLChecks/Optimize for Ad-Hoc Workloads should be Enabled.sql index 7feb02d..c097e28 100644 --- a/SQLChecks/Optimize for Ad-Hoc Workloads should be Enabled.sql +++ b/SQLChecks/Optimize for Ad-Hoc Workloads should be Enabled.sql @@ -15,12 +15,23 @@ WHERE [name] = N'optimize for ad hoc workloads'; + SET @AdditionalInfo = + ( + SELECT + AdhocRatio = @AdhocRatio , + CurrentConfig = @OptimizeForAdhocWorkloads + FOR XML + PATH (N'') , + ROOT (N'OptimizeForAdhocWorkloads') + ); + INSERT INTO #Checks ( CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -31,12 +42,31 @@ Title = N'{CheckTitle}' , RequiresAttention = CASE - WHEN @AdditionalInfo IS NULL - THEN 0 + WHEN @AdhocRatio > 0.5 AND @OptimizeForAdhocWorkloads = 0 + THEN 1 + ELSE + 0 + END , + WorstCaseImpact = 1 , -- Low + CurrentStateImpact = + CASE + WHEN @AdhocRatio > 0.5 AND @OptimizeForAdhocWorkloads = 0 + THEN 1 -- Low + ELSE + 0 -- None + END , + RecommendationEffort = + CASE + WHEN @AdhocRatio > 0.5 AND @OptimizeForAdhocWorkloads = 0 + THEN 1 -- Low + ELSE + 0 -- None + END , + RecommendationRisk = + CASE + WHEN @AdhocRatio > 0.5 AND @OptimizeForAdhocWorkloads = 0 + THEN 1 -- Low ELSE - 1 + 0 -- None END , - CurrentStateImpact = 1 , -- Low - RecommendationEffort = 1 , -- Low - RecommendationRisk = 1 , -- Low AdditionalInfo = @AdditionalInfo; diff --git a/SQLChecks/Query Plans with Index Spools or Table Spools.sql b/SQLChecks/Query Plans with Index Spools or Table Spools.sql index 4049825..26bebcd 100644 --- a/SQLChecks/Query Plans with Index Spools or Table Spools.sql +++ b/SQLChecks/Query Plans with Index Spools or Table Spools.sql @@ -1,9 +1,12 @@ + DECLARE + @NumberOfPlans AS INT; + SET @AdditionalInfo = NULL; WITH XMLNAMESPACES (DEFAULT N'http://schemas.microsoft.com/sqlserver/2004/07/showplan') - SELECT TOP (1) + SELECT @AdditionalInfo = N'Found Query Plans with Index Spools or Table Spools' FROM sys.dm_exec_cached_plans AS CachedPlans @@ -18,12 +21,15 @@ AND QueryPlans.query_plan.query('.').exist('data(//Object[@Schema!="[sys]"][1])') = 1; + SET @NumberOfPlans = @@ROWCOUNT; + INSERT INTO #Checks ( CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -39,9 +45,36 @@ ELSE 1 END , - CurrentStateImpact = 2 , -- Medium - RecommendationEffort = 3 , -- High - RecommendationRisk = 2 , -- Medium + WorstCaseImpact = 3 , -- High + CurrentStateImpact = + CASE + WHEN @NumberOfPlans = 0 + THEN 0 -- None + WHEN @NumberOfPlans BETWEEN 1 AND 10 + THEN 1 -- Low + WHEN @NumberOfPlans BETWEEN 11 AND 30 + THEN 2 -- Medium + ELSE + 3 -- High + END , + RecommendationEffort = + CASE + WHEN @NumberOfPlans = 0 + THEN 0 -- None + WHEN @NumberOfPlans BETWEEN 1 AND 10 + THEN 1 -- Low + WHEN @NumberOfPlans BETWEEN 11 AND 30 + THEN 2 -- Medium + ELSE + 3 -- High + END , + RecommendationRisk = + CASE + WHEN @NumberOfPlans = 0 + THEN 0 -- None + ELSE + 2 -- Medium + END , AdditionalInfo = NULL; BREAK; diff --git a/SQLChecks/Statistics are Never Updated.sql b/SQLChecks/Statistics are Never Updated.sql index 9529db4..bc349f9 100644 --- a/SQLChecks/Statistics are Never Updated.sql +++ b/SQLChecks/Statistics are Never Updated.sql @@ -98,6 +98,7 @@ CheckId , Title , RequiresAttention , + WorstCaseImpact , CurrentStateImpact , RecommendationEffort , RecommendationRisk , @@ -113,9 +114,28 @@ ELSE 1 END , - CurrentStateImpact = 3 , -- High - RecommendationEffort = 1 , -- Low - RecommendationRisk = 1 , -- Low + WorstCaseImpact = 3 , -- High + CurrentStateImpact = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 -- None + ELSE + 3 -- High + END , + RecommendationEffort = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 -- None + ELSE + 1 -- Low + END , + RecommendationRisk = + CASE + WHEN @AdditionalInfo IS NULL + THEN 0 -- None + ELSE + 1 -- Low + END , AdditionalInfo = @AdditionalInfo; DROP TABLE diff --git a/Template/Template_Footer.sql b/Template/Template_Footer.sql index 4a84569..ba38bc3 100644 --- a/Template/Template_Footer.sql +++ b/Template/Template_Footer.sql @@ -5,7 +5,7 @@ SET NOEXEC OFF; -- View the results SELECT - InstanceScore = CAST (ROUND ((1.0 - CAST (SUM (CurrentStateImpact * CAST (RequiresAttention AS INT)) AS DECIMAL(19,2)) / CAST (SUM (CurrentStateImpact) AS DECIMAL(19,2))) * 100.0 , 0) AS TINYINT) + InstanceScore = CAST (ROUND ((1.0 - CAST (SUM (CurrentStateImpact) AS DECIMAL(19,2)) / CAST (SUM (WorstCaseImpact) AS DECIMAL(19,2))) * 100.0 , 0) AS TINYINT) FROM #Checks; @@ -15,18 +15,21 @@ SELECT [Requires Attention] = RequiresAttention , [Current State Impact] = CASE CurrentStateImpact + WHEN 0 THEN N'None' WHEN 1 THEN N'Low' WHEN 2 THEN N'Medium' WHEN 3 THEN N'High' END , [Recommendation Effort] = CASE RecommendationEffort + WHEN 0 THEN N'None' WHEN 1 THEN N'Low' WHEN 2 THEN N'Medium' WHEN 3 THEN N'High' END , [Recommendation Risk] = CASE RecommendationRisk + WHEN 0 THEN N'None' WHEN 1 THEN N'Low' WHEN 2 THEN N'Medium' WHEN 3 THEN N'High' diff --git a/Template/Template_Header.sql b/Template/Template_Header.sql index 8ba9f86..6d0db29 100644 --- a/Template/Template_Header.sql +++ b/Template/Template_Header.sql @@ -39,6 +39,7 @@ CREATE TABLE CheckId INT NOT NULL , Title NVARCHAR(100) NOT NULL , RequiresAttention BIT NOT NULL , + WorstCaseImpact TINYINT NOT NULL , CurrentStateImpact TINYINT NOT NULL , RecommendationEffort TINYINT NOT NULL , RecommendationRisk TINYINT NOT NULL ,