From a80c7fb371ad9689a81c1e9a56a7f658b9741ff3 Mon Sep 17 00:00:00 2001 From: Vlad Drumea <48413726+VladDBA@users.noreply.github.com> Date: Tue, 22 Oct 2024 18:37:26 +0300 Subject: [PATCH] Changes for #274, #275 --- PSBlitz.ps1 | 5 +- README.md | 4 +- Resources/spBlitzCache_NonSPLatest.sql | 2 +- Resources/spBlitzFirst_NonSPLatest.sql | 2 +- Resources/spBlitzIndex_NonSPLatest.sql | 142 +++++++++++++------------ Resources/spBlitzLock_NonSPLatest.sql | 24 +++-- Resources/spBlitzWho_NonSPLatest.sql | 2 +- Resources/spBlitz_NonSPLatest.sql | 132 ++++++++++++++++++++--- 8 files changed, 212 insertions(+), 101 deletions(-) diff --git a/PSBlitz.ps1 b/PSBlitz.ps1 index 4a418b1..7dee4cf 100644 --- a/PSBlitz.ps1 +++ b/PSBlitz.ps1 @@ -124,6 +124,7 @@ .PARAMETER CheckDB Used to provide the name of a specific database against which sp_BlitzIndex, sp_BlitzCache, and sp_BlitzLock will be ran. Omit to run against the whole instance. + Also used to provide the name of the Azure SQL DB database. .PARAMETER CacheTop Used to specify if more/less than the default top 10 queries should be returned for the @@ -264,8 +265,8 @@ param( ###Internal params #Version -$Vers = "4.4.0" -$VersDate = "2024-10-15" +$Vers = "4.4.1" +$VersDate = "2024-10-22" $TwoMonthsFromRelease = [datetime]::ParseExact("$VersDate", 'yyyy-MM-dd', $null).AddMonths(2) $NowDate = Get-Date #Get script path diff --git a/README.md b/README.md index ca4cecb..2faa20e 100644 --- a/README.md +++ b/README.md @@ -109,11 +109,11 @@ You can find the all the scripts in the repository's [Resources](/Resources) dir ## Paramaters | Parameter | Description| |-----------|------------| -|`-ServerName`| The name of your SQL Server instance or Azure SQL DB connection info.

Accepted input format:
`HostName\InstanceID` for named instances.
`HostName,Port` when using a port number instead of an instance ID.
`HostName` for default instances.

For Azure SQL DB the format is:
`YourServer.database.windows.net,PortNumber:YourDatabase`if you want to specify the port number.
`YourServer.database.windows.net:YourDatabase` if you don't want to specify the port number.

Other options:
If you provide `?` or `Help` as a value for `-ServerName`, the script will return a brief help menu.
If no value is provided, the script will go into interactive mode and prompt for the appropriate input | +|`-ServerName`| The name of your SQL Server instance or Azure SQL DB connection info.

Accepted input format:
`HostName\InstanceID` for named instances.
`HostName,Port` when using a port number instead of an instance ID.
`HostName` for default instances.

For Azure SQL DB the format is:
`YourServer.database.windows.net,PortNumber:YourDatabase` if you want to specify the port number.
`YourServer.database.windows.net:YourDatabase` if you don't want to specify the port number.
If your Azure SQL DB instance doesn't use the `database.windows.net` portion (e.g.: it's configured to use an IP instead) then you should provide the database name via the `-CheckDB` parameter.

Other options:
If you provide `?` or `Help` as a value for `-ServerName`, the script will return a brief help menu.
If no value is provided, the script will go into interactive mode and prompt for the appropriate input | |`-SQLLogin`| The name of the SQL login used to run the script. If not provided, the script will use integrated security. | |`-SQLPass` | The password for the SQL login provided via the -SQLLogin parameter, omit if `-SQLLogin` was not used. | |`-IsIndepth` | Providing Y as a value will tell PSBlitz.ps1 to run a more in-depth check against the instance/database. Omit for default check. | -|`-CheckDB` | Used to provide the name of a specific database against which sp_BlitzIndex, sp_BlitzCache, and sp_BlitzLock will be ran. Omit to run against the whole instance.| +|`-CheckDB` | Used to provide the name of a specific database against which sp_BlitzIndex, sp_BlitzCache, and sp_BlitzLock will be ran. Omit to run against the whole instance.

__For Azure SQL DB__
Can also be used to provide the name of the Azure SQL DB database if you haven't provided it as part of the
`-ServerName` paramter.
If the database name is not provided here, nor as part of the `-ServerName`, and the environment is detected as Azure SQL DB, then you'll be prompted to provide the database name.| |`-CacheTop`| Used to specify if more/less than the default top 10 queries should be returned for the sp_BlitzCache step. Only works for HTML output (`-ToHTM Y`). Has no effect on the `recent compilations` sort order.| |`-CacheMinutesBack`| Used to specify how many minutes back to begin plan cache analysis. Defaults to entire contents of the plan cache since instance startup.
In order to avoid missing the desired timeframe, the value is dynamically adjusted based on the runtime of PSBlitz up until the plan cache analysis point.| |`-OutputDir`| Used to provide a path where the output directory should be saved to. Defaults to PSBlitz.ps1's directory if not specified or a non-existent path is provided.| diff --git a/Resources/spBlitzCache_NonSPLatest.sql b/Resources/spBlitzCache_NonSPLatest.sql index c14550a..2e21126 100644 --- a/Resources/spBlitzCache_NonSPLatest.sql +++ b/Resources/spBlitzCache_NonSPLatest.sql @@ -103,7 +103,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.21', @VersionDate = '20240701'; +SELECT @Version = '8.22', @VersionDate = '20241019'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) diff --git a/Resources/spBlitzFirst_NonSPLatest.sql b/Resources/spBlitzFirst_NonSPLatest.sql index 51b672a..5361ce1 100644 --- a/Resources/spBlitzFirst_NonSPLatest.sql +++ b/Resources/spBlitzFirst_NonSPLatest.sql @@ -96,7 +96,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.21', @VersionDate = '20240701'; +SELECT @Version = '8.22', @VersionDate = '20241019'; IF(@VersionCheckMode = 1) BEGIN diff --git a/Resources/spBlitzIndex_NonSPLatest.sql b/Resources/spBlitzIndex_NonSPLatest.sql index 11b345c..6f7433f 100644 --- a/Resources/spBlitzIndex_NonSPLatest.sql +++ b/Resources/spBlitzIndex_NonSPLatest.sql @@ -76,14 +76,14 @@ SELECT /* Everything beyond this point is straight from sp_BlitzIndex except for the commented block -between lines 6503 and 6510 and without the GO at the end +between lines 6507 and 6514 and without the GO at the end */ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.21', @VersionDate = '20240701'; +SELECT @Version = '8.22', @VersionDate = '20241019'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -1914,6 +1914,7 @@ WITH ON ty.user_type_id = co.user_type_id WHERE id_inner.index_handle = id.index_handle AND id_inner.object_id = id.object_id + AND id_inner.database_id = DB_ID(''' + QUOTENAME(@DatabaseName) + N''') AND cn_inner.IndexColumnType = cn.IndexColumnType FOR XML PATH('''') ), @@ -1951,6 +1952,7 @@ WITH ) x (n) CROSS APPLY n.nodes(''x'') node(v) )AS cn + WHERE id.database_id = DB_ID(''' + QUOTENAME(@DatabaseName) + N''') GROUP BY id.index_handle, id.object_id, @@ -3533,7 +3535,7 @@ BEGIN SELECT 1 AS check_id, ip.index_sanity_id, 20 AS Priority, - 'Multiple Index Personalities' AS findings_group, + 'Redundant Indexes' AS findings_group, 'Duplicate keys' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/duplicateindex' AS URL, @@ -3570,8 +3572,8 @@ BEGIN SELECT 2 AS check_id, ip.index_sanity_id, 30 AS Priority, - 'Multiple Index Personalities' AS findings_group, - 'Borderline duplicate keys' AS finding, + 'Redundant Indexes' AS findings_group, + 'Approximate Duplicate Keys' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/duplicateindex' AS URL, ip.db_schema_object_indexid AS details, @@ -3604,7 +3606,7 @@ BEGIN SELECT 11 AS check_id, i.index_sanity_id, 70 AS Priority, - N'Aggressive ' + N'Locking-Prone ' + CASE COALESCE((SELECT SUM(1) FROM #IndexSanity iMe INNER JOIN #IndexSanity iOthers @@ -3665,7 +3667,7 @@ BEGIN SELECT 20 AS check_id, MAX(i.index_sanity_id) AS index_sanity_id, 10 AS Priority, - 'Index Hoarder' AS findings_group, + 'Over-Indexing' AS findings_group, 'Many NC Indexes on a Single Table' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, @@ -3689,13 +3691,13 @@ BEGIN ORDER BY i.db_schema_object_name DESC OPTION ( RECOMPILE ); - RAISERROR(N'check_id 22: NC indexes with 0 reads. (Borderline) and >= 10,000 writes', 0,1) WITH NOWAIT; + RAISERROR(N'check_id 22: NC indexes with 0 reads and >= 10,000 writes', 0,1) WITH NOWAIT; INSERT #BlitzIndexResults ( check_id, index_sanity_id, Priority, findings_group, finding, [database_name], URL, details, index_definition, secret_columns, index_usage_summary, index_size_summary ) SELECT 22 AS check_id, i.index_sanity_id, 10 AS Priority, - N'Index Hoarder' AS findings_group, + N'Over-Indexing' AS findings_group, N'Unused NC Index with High Writes' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, @@ -3728,7 +3730,7 @@ BEGIN SELECT 34 AS check_id, i.index_sanity_id, 80 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Filter Columns Not In Index Definition' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexFeatures' AS URL, @@ -3762,7 +3764,7 @@ BEGIN SELECT 40 AS check_id, i.index_sanity_id, 100 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Low Fill Factor on Nonclustered Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -3789,7 +3791,7 @@ BEGIN SELECT 40 AS check_id, i.index_sanity_id, 100 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Low Fill Factor on Clustered Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -3828,7 +3830,7 @@ BEGIN SELECT 43 AS check_id, i.index_sanity_id, 100 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Heaps with Forwarded Fetches' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -3871,7 +3873,7 @@ BEGIN SELECT 44 AS check_id, i.index_sanity_id, 100 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Large Active Heap' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -3909,7 +3911,7 @@ BEGIN SELECT 45 AS check_id, i.index_sanity_id, 100 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Medium Active heap' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -3948,7 +3950,7 @@ BEGIN SELECT 46 AS check_id, i.index_sanity_id, 100 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Small Active heap' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -3975,7 +3977,7 @@ BEGIN SELECT 47 AS check_id, i.index_sanity_id, 100 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Heap with a Nonclustered Primary Key' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -4003,7 +4005,7 @@ BEGIN SELECT 48 AS check_id, i.index_sanity_id, 100 AS Priority, - N'Index Hoarder' AS findings_group, + N'Over-Indexing' AS findings_group, N'NC index with High Writes:Reads' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, @@ -4033,7 +4035,7 @@ BEGIN --Indexaphobia --Missing indexes with value >= 5 million: : Check_id 50-59 ---------------------------------------- - RAISERROR(N'check_id 50: Indexaphobia.', 0,1) WITH NOWAIT; + RAISERROR(N'check_id 50: High Value Missing Index.', 0,1) WITH NOWAIT; WITH index_size_cte AS ( SELECT i.database_id, i.schema_name, @@ -4071,7 +4073,7 @@ BEGIN 50 AS check_id, sz.index_sanity_id, 40 AS Priority, - N'Indexaphobia' AS findings_group, + N'Index Suggestion' AS findings_group, N'High Value Missing Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/Indexaphobia' AS URL, @@ -4116,7 +4118,7 @@ BEGIN SELECT 68 AS check_id, i.index_sanity_id, 80 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Identity Column Within ' + CAST (calc1.percent_remaining AS NVARCHAR(256)) + N' Percent End of Range' AS finding, @@ -4181,7 +4183,7 @@ BEGIN SELECT 72 AS check_id, i.index_sanity_id, 80 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, 'Columnstore Indexes with Trace Flag 834' AS finding, [database_name] AS [Database Name], N'https://support.microsoft.com/en-us/kb/3210239' AS URL, @@ -4205,7 +4207,7 @@ BEGIN secret_columns, index_usage_summary, index_size_summary ) SELECT 90 AS check_id, 90 AS Priority, - 'Functioning Statistaholics' AS findings_group, + 'Statistics Warnings' AS findings_group, 'Statistics Not Updated Recently', s.database_name, 'https://www.brentozar.com/go/stats' AS URL, @@ -4232,7 +4234,7 @@ BEGIN secret_columns, index_usage_summary, index_size_summary ) SELECT 91 AS check_id, 90 AS Priority, - 'Functioning Statistaholics' AS findings_group, + 'Statistics Warnings' AS findings_group, 'Low Sampling Rates', s.database_name, 'https://www.brentozar.com/go/stats' AS URL, @@ -4251,7 +4253,7 @@ BEGIN secret_columns, index_usage_summary, index_size_summary ) SELECT 92 AS check_id, 90 AS Priority, - 'Functioning Statistaholics' AS findings_group, + 'Statistics Warnings' AS findings_group, 'Statistics With NO RECOMPUTE', s.database_name, 'https://www.brentozar.com/go/stats' AS URL, @@ -4270,7 +4272,7 @@ BEGIN secret_columns, index_usage_summary, index_size_summary ) SELECT 94 AS check_id, 100 AS Priority, - 'Serial Forcer' AS findings_group, + 'Forced Serialization' AS findings_group, 'Check Constraint with Scalar UDF' AS finding, cc.database_name, 'https://www.brentozar.com/go/computedscalar' AS URL, @@ -4289,7 +4291,7 @@ BEGIN secret_columns, index_usage_summary, index_size_summary ) SELECT 99 AS check_id, 100 AS Priority, - 'Serial Forcer' AS findings_group, + 'Forced Serialization' AS findings_group, 'Computed Column with Scalar UDF' AS finding, cc.database_name, 'https://www.brentozar.com/go/serialudf' AS URL, @@ -4346,7 +4348,7 @@ BEGIN SELECT 21 AS check_id, MAX(i.index_sanity_id) AS index_sanity_id, 150 AS Priority, - N'Index Hoarder' AS findings_group, + N'Over-Indexing' AS findings_group, N'More Than 5 Percent NC Indexes Are Unused' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, @@ -4381,8 +4383,8 @@ BEGIN SELECT 23 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Index Hoarder' AS findings_group, - N'Borderline: Wide Indexes (7 or More Columns)' AS finding, + N'Over-Indexing' AS findings_group, + N'Approximate: Wide Indexes (7 or More Columns)' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, CAST(count_key_columns + count_included_columns AS NVARCHAR(10)) + ' columns on ' @@ -4409,7 +4411,7 @@ BEGIN SELECT 24 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Index Hoarder' AS findings_group, + N'Over-Indexing' AS findings_group, N'Wide Clustered Index (> 3 columns OR > 16 bytes)' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, @@ -4441,7 +4443,7 @@ BEGIN AND i.is_CX_columnstore = 0 ORDER BY i.db_schema_object_name DESC OPTION ( RECOMPILE ); - RAISERROR(N'check_id 25: Addicted to nullable columns.', 0,1) WITH NOWAIT; + RAISERROR(N'check_id 25: High ratio of nullable columns.', 0,1) WITH NOWAIT; WITH count_columns AS ( SELECT [object_id], [database_id], @@ -4459,8 +4461,8 @@ BEGIN SELECT 25 AS check_id, i.index_sanity_id, 200 AS Priority, - N'Index Hoarder' AS findings_group, - N'Addicted to Nulls' AS finding, + N'Over-Indexing' AS findings_group, + N'High Ratio of Nulls' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, i.db_schema_object_name @@ -4500,7 +4502,7 @@ BEGIN SELECT 26 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Index Hoarder' AS findings_group, + N'Over-Indexing' AS findings_group, N'Wide Tables: 35+ cols or > 2000 non-LOB bytes' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, @@ -4527,7 +4529,7 @@ BEGIN cc.sum_max_length >= 2000) ORDER BY i.db_schema_object_name DESC OPTION ( RECOMPILE ); - RAISERROR(N'check_id 27: Addicted to strings.', 0,1) WITH NOWAIT; + RAISERROR(N'check_id 27: High Ratio of Strings.', 0,1) WITH NOWAIT; WITH count_columns AS ( SELECT [object_id], [database_id], @@ -4545,8 +4547,8 @@ BEGIN SELECT 27 AS check_id, i.index_sanity_id, 200 AS Priority, - N'Index Hoarder' AS findings_group, - N'Addicted to strings' AS finding, + N'Over-Indexing' AS findings_group, + N'High Ratio of Strings' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, i.db_schema_object_name @@ -4574,7 +4576,7 @@ BEGIN SELECT 28 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Index Hoarder' AS findings_group, + N'Over-Indexing' AS findings_group, N'Non-Unique Clustered Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, @@ -4600,13 +4602,13 @@ BEGIN AND is_CX_columnstore=0 /* not a clustered columnstore-- no unique option on those */ ORDER BY i.db_schema_object_name DESC OPTION ( RECOMPILE ); - RAISERROR(N'check_id 29: NC indexes with 0 reads. (Borderline) and < 10,000 writes', 0,1) WITH NOWAIT; + RAISERROR(N'check_id 29: NC indexes with 0 reads and < 10,000 writes', 0,1) WITH NOWAIT; INSERT #BlitzIndexResults ( check_id, index_sanity_id, Priority, findings_group, finding, [database_name], URL, details, index_definition, secret_columns, index_usage_summary, index_size_summary ) SELECT 29 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Index Hoarder' AS findings_group, + N'Over-Indexing' AS findings_group, N'Unused NC index with Low Writes' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexHoarder' AS URL, @@ -4652,7 +4654,7 @@ BEGIN SELECT 30 AS check_id, NULL AS index_sanity_id, 250 AS Priority, - N'Feature-Phobic Indexes' AS findings_group, + N'Omitted Index Features' AS findings_group, database_name AS [Database Name], N'No Indexes Use Includes' AS finding, 'https://www.brentozar.com/go/IndexFeatures' AS URL, N'No Indexes Use Includes' AS details, @@ -4670,7 +4672,7 @@ BEGIN SELECT 31 AS check_id, NULL AS index_sanity_id, 250 AS Priority, - N'Feature-Phobic Indexes' AS findings_group, + N'Omitted Index Features' AS findings_group, N'Few Indexes Use Includes' AS findings, database_name AS [Database Name], N'https://www.brentozar.com/go/IndexFeatures' AS URL, @@ -4691,7 +4693,7 @@ BEGIN 32 AS check_id, NULL AS index_sanity_id, 250 AS Priority, - N'Feature-Phobic Indexes' AS findings_group, + N'Omitted Index Features' AS findings_group, N'No Filtered Indexes or Indexed Views' AS finding, i.database_name AS [Database Name], N'https://www.brentozar.com/go/IndexFeatures' AS URL, @@ -4717,7 +4719,7 @@ BEGIN SELECT 33 AS check_id, i.index_sanity_id AS index_sanity_id, 250 AS Priority, - N'Feature-Phobic Indexes' AS findings_group, + N'Omitted Index Features' AS findings_group, N'Potential Filtered Index (Based on Column Name)' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/IndexFeatures' AS URL, @@ -4745,7 +4747,7 @@ BEGIN SELECT 41 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Hypothetical Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -4766,7 +4768,7 @@ BEGIN SELECT 42 AS check_id, index_sanity_id, 150 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Disabled Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -4796,7 +4798,7 @@ BEGIN SELECT 49 AS check_id, i.index_sanity_id, 200 AS Priority, - N'Self Loathing Indexes' AS findings_group, + N'Indexes Worth Reviewing' AS findings_group, N'Heaps with Deletes' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/SelfLoathing' AS URL, @@ -4824,7 +4826,7 @@ BEGIN SELECT 60 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'XML Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -4844,7 +4846,7 @@ BEGIN SELECT 61 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, CASE WHEN i.is_NC_columnstore=1 THEN N'NC Columnstore Index' ELSE N'Clustered Columnstore Index' @@ -4868,7 +4870,7 @@ BEGIN SELECT 62 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Spatial Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -4888,7 +4890,7 @@ BEGIN SELECT 63 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Compressed Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -4908,7 +4910,7 @@ BEGIN SELECT 64 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Partitioned Index' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -4928,7 +4930,7 @@ BEGIN SELECT 65 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Non-Aligned Index on a Partitioned Table' AS finding, i.[database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -4954,7 +4956,7 @@ BEGIN SELECT 66 AS check_id, i.index_sanity_id, 200 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Recently Created Tables/Indexes (1 week)' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -4977,7 +4979,7 @@ BEGIN SELECT 67 AS check_id, i.index_sanity_id, 200 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Recently Modified Tables/Indexes (2 days)' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -5014,7 +5016,7 @@ BEGIN SELECT 69 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Column Collation Does Not Match Database Collation' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -5053,7 +5055,7 @@ BEGIN SELECT 70 AS check_id, i.index_sanity_id, 200 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Replicated Columns' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -5083,7 +5085,7 @@ BEGIN SELECT 71 AS check_id, NULL AS index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Cascading Updates or Deletes' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -5111,7 +5113,7 @@ BEGIN SELECT 72 AS check_id, NULL AS index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Unindexed Foreign Keys' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -5135,7 +5137,7 @@ BEGIN SELECT 73 AS check_id, i.index_sanity_id, 150 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'In-Memory OLTP' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -5155,7 +5157,7 @@ BEGIN SELECT 74 AS check_id, i.index_sanity_id, 200 AS Priority, - N'Abnormal Psychology' AS findings_group, + N'Abnormal Design Pattern' AS findings_group, N'Identity Column Using a Negative Seed or Increment Other Than 1' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/AbnormalPsychology' AS URL, @@ -5207,7 +5209,7 @@ BEGIN 80 AS check_id, i.index_sanity_id AS index_sanity_id, 200 AS Priority, - N'Workaholics' AS findings_group, + N'High Workloads' AS findings_group, N'Scan-a-lots (index-usage-stats)' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/Workaholics' AS URL, @@ -5235,7 +5237,7 @@ BEGIN 81 AS check_id, i.index_sanity_id AS index_sanity_id, 200 AS Priority, - N'Workaholics' AS findings_group, + N'High Workloads' AS findings_group, N'Top Recent Accesses (index-op-stats)' AS finding, [database_name] AS [Database Name], N'https://www.brentozar.com/go/Workaholics' AS URL, @@ -5263,8 +5265,8 @@ BEGIN secret_columns, index_usage_summary, index_size_summary ) SELECT 93 AS check_id, 200 AS Priority, - 'Functioning Statistaholics' AS findings_group, - 'Filter Fixation', + 'Statistics Warnings' AS findings_group, + 'Statistics With Filters', s.database_name, 'https://www.brentozar.com/go/stats' AS URL, 'The statistic ' + QUOTENAME(s.statistics_name) + ' is filtered on [' + s.filter_definition + ']. It could be part of a filtered index, or just a filtered statistic. This is purely informational.' AS details, @@ -5282,8 +5284,8 @@ BEGIN secret_columns, index_usage_summary, index_size_summary ) SELECT 100 AS check_id, 200 AS Priority, - 'Cold Calculators' AS findings_group, - 'Definition Defeatists' AS finding, + 'Repeated Calculations' AS findings_group, + 'Computed Columns Not Persisted' AS finding, cc.database_name, '' AS URL, 'The computed column ' + QUOTENAME(cc.column_name) + ' on ' + QUOTENAME(cc.schema_name) + '.' + QUOTENAME(cc.table_name) + ' is not persisted, which means it will be calculated when a query runs.' + @@ -5303,7 +5305,7 @@ BEGIN SELECT 110 AS check_id, 200 AS Priority, - 'Abnormal Psychology' AS findings_group, + 'Abnormal Design Pattern' AS findings_group, 'Temporal Tables', t.database_name, '' AS URL, @@ -5323,7 +5325,7 @@ BEGIN SELECT 121 AS check_id, 200 AS Priority, - 'Medicated Indexes' AS findings_group, + 'Specialized Indexes' AS findings_group, 'Optimized For Sequential Keys', i.database_name, '' AS URL, diff --git a/Resources/spBlitzLock_NonSPLatest.sql b/Resources/spBlitzLock_NonSPLatest.sql index 1bb5951..b2e8b1b 100644 --- a/Resources/spBlitzLock_NonSPLatest.sql +++ b/Resources/spBlitzLock_NonSPLatest.sql @@ -95,7 +95,7 @@ BEGIN SET XACT_ABORT OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.21', @VersionDate = '20240701'; + SELECT @Version = '8.22', @VersionDate = '20241019'; IF @VersionCheckMode = 1 BEGIN @@ -3724,8 +3724,9 @@ BEGIN SET STATISTICS XML ON; END; - INSERT INTO - DeadLockTbl + SET @StringToExecute = N' + + INSERT INTO ' + QUOTENAME(DB_NAME()) + N'..DeadLockTbl ( ServerName, deadlock_type, @@ -3769,7 +3770,8 @@ BEGIN deadlock_graph ) EXEC sys.sp_executesql - @deadlock_result; + @deadlock_result;' + EXEC sys.sp_executesql @StringToExecute, N'@deadlock_result NVARCHAR(MAX)', @deadlock_result; IF @Debug = 1 BEGIN @@ -3783,8 +3785,9 @@ BEGIN SET @d = CONVERT(varchar(40), GETDATE(), 109); RAISERROR('Findings to table %s', 0, 1, @d) WITH NOWAIT; - INSERT INTO - DeadlockFindings + SET @StringToExecute = N' + + INSERT INTO ' + QUOTENAME(DB_NAME()) + N'..DeadlockFindings ( ServerName, check_id, @@ -3802,7 +3805,8 @@ BEGIN df.finding FROM #deadlock_findings AS df ORDER BY df.check_id - OPTION(RECOMPILE); + OPTION(RECOMPILE);' + EXEC sys.sp_executesql @StringToExecute; RAISERROR('Finished at %s', 0, 1, @d) WITH NOWAIT; @@ -4098,17 +4102,23 @@ BEGIN FROM @sysAssObjId AS s OPTION(RECOMPILE); + IF OBJECT_ID('tempdb..#available_plans') IS NOT NULL + BEGIN SELECT table_name = N'#available_plans', * FROM #available_plans AS ap OPTION(RECOMPILE); + END; + IF OBJECT_ID('tempdb..#dm_exec_query_stats') IS NOT NULL + BEGIN SELECT table_name = N'#dm_exec_query_stats', * FROM #dm_exec_query_stats OPTION(RECOMPILE); + END; SELECT procedure_parameters = diff --git a/Resources/spBlitzWho_NonSPLatest.sql b/Resources/spBlitzWho_NonSPLatest.sql index 43b92ab..48fbb9d 100644 --- a/Resources/spBlitzWho_NonSPLatest.sql +++ b/Resources/spBlitzWho_NonSPLatest.sql @@ -66,7 +66,7 @@ the GO at the end and without the block that creates the view at line 351*/ SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.21', @VersionDate = '20240701'; + SELECT @Version = '8.22', @VersionDate = '20241019'; IF(@VersionCheckMode = 1) BEGIN diff --git a/Resources/spBlitz_NonSPLatest.sql b/Resources/spBlitz_NonSPLatest.sql index b6d3066..fc46706 100644 --- a/Resources/spBlitz_NonSPLatest.sql +++ b/Resources/spBlitz_NonSPLatest.sql @@ -77,7 +77,7 @@ without the GO at the end SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.21', @VersionDate = '20240701'; + SELECT @Version = '8.22', @VersionDate = '20241019'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -373,18 +373,15 @@ without the GO at the end END CATCH; END; /*Need execute on sp_validatelogins*/ - IF ISNULL(@SkipGetAlertInfo, 0) != 1 /*If @SkipGetAlertInfo hasn't been set to 1 by the caller*/ - BEGIN - BEGIN TRY - /* Try to fill the table for check 73 */ - INSERT INTO #AlertInfo - EXEC [master].[dbo].[sp_MSgetalertinfo] @includeaddresses = 0; - - SET @SkipGetAlertInfo = 0; /*We can execute sp_MSgetalertinfo*/ - END TRY - BEGIN CATCH - SET @SkipGetAlertInfo = 1; /*We have don't have execute rights or sp_MSgetalertinfo throws an error so skip it*/ - END CATCH; + 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*/ @@ -1173,7 +1170,10 @@ without the GO at the end INSERT INTO #IgnorableWaits VALUES ('PARALLEL_REDO_WORKER_WAIT_WORK'); INSERT INTO #IgnorableWaits VALUES ('POPULATE_LOCK_ORDINALS'); INSERT INTO #IgnorableWaits VALUES ('PREEMPTIVE_HADR_LEASE_MECHANISM'); + INSERT INTO #IgnorableWaits VALUES ('PREEMPTIVE_OS_FLUSHFILEBUFFERS'); INSERT INTO #IgnorableWaits VALUES ('PREEMPTIVE_SP_SERVER_DIAGNOSTICS'); + INSERT INTO #IgnorableWaits VALUES ('PVS_PREALLOCATE'); + INSERT INTO #IgnorableWaits VALUES ('PWAIT_EXTENSIBILITY_CLEANUP_TASK'); 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'); @@ -1187,6 +1187,7 @@ without the GO at the end 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 ('VDI_CLIENT_OTHER'); INSERT INTO #IgnorableWaits VALUES ('WAIT_XTP_OFFLINE_CKPT_NEW_LOG'); INSERT INTO #IgnorableWaits VALUES ('WAITFOR'); INSERT INTO #IgnorableWaits VALUES ('XE_DISPATCHER_WAIT'); @@ -1875,9 +1876,18 @@ without the GO at the end IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 2301) WITH NOWAIT; /* - #InvalidLogins is filled at the start during the permissions check + #InvalidLogins is filled at the start during the permissions check IF we are not sysadmin + filling it now if we are sysadmin */ - + IF @sa = 1 + BEGIN + INSERT INTO #InvalidLogins + ( + [LoginSID] + ,[LoginName] + ) + EXEC sp_validatelogins; + END; INSERT INTO #BlitzResults ( CheckID , Priority , @@ -6134,6 +6144,8 @@ IF @ProductVersionMajor >= 10 FROM #SkipChecks WHERE DatabaseName IS NULL AND CheckID = 191 ) AND (SELECT COUNT(*) FROM sys.master_files WHERE database_id = 2) <> (SELECT COUNT(*) FROM tempdb.sys.database_files) + /* User may have no permissions to see tempdb files in sys.master_files. In that case count returned will be 0 and we want to skip the check */ + AND (SELECT COUNT(*) FROM sys.master_files WHERE database_id = 2) <> 0 BEGIN IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 191) WITH NOWAIT @@ -6891,6 +6903,41 @@ IF @ProductVersionMajor >= 10 AND desired_state <> actual_state OPTION (RECOMPILE)'; END; + + IF NOT EXISTS ( SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 265 ) + AND EXISTS(SELECT * FROM sys.all_objects WHERE name = 'database_query_store_options') + BEGIN + IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 265) WITH NOWAIT; + + EXEC dbo.sp_MSforeachdb 'USE [?]; + SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + INSERT INTO #BlitzResults + (CheckID, + DatabaseName, + Priority, + FindingsGroup, + Finding, + URL, + Details) + SELECT TOP 1 265, + N''?'', + 200, + ''Performance'', + ''Query Store Unusually Configured'', + ''https://www.sqlskills.com/blogs/erin/query-store-best-practices/'', + (''The '' + query_capture_mode_desc + '' query capture mode '' + + CASE query_capture_mode_desc + WHEN ''ALL'' THEN ''captures more data than you will probably use. If your workload is heavily ad-hoc, then it can also cause Query Store to capture so much that it turns itself off.'' + WHEN ''NONE'' THEN ''stops Query Store capturing data for new queries.'' + WHEN ''CUSTOM'' THEN ''suggests that somebody has gone out of their way to only capture exactly what they want.'' + ELSE ''is not documented.'' END) + FROM [?].sys.database_query_store_options + WHERE desired_state <> 0 /* No point in checking this if Query Store is off. */ + AND query_capture_mode_desc <> ''AUTO'' + OPTION (RECOMPILE)'; + END; IF @ProductVersionMajor = 13 AND @ProductVersionMinor < 2149 --2016 CU1 has the fix in it AND NOT EXISTS ( SELECT 1 @@ -8458,6 +8505,9 @@ IF @ProductVersionMajor >= 10 BEGIN IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 73) WITH NOWAIT; + + INSERT INTO #AlertInfo + EXEC [master].[dbo].[sp_MSgetalertinfo] @includeaddresses = 0; INSERT INTO #BlitzResults ( CheckID , @@ -8520,11 +8570,11 @@ IF @ProductVersionMajor >= 10 WHEN [T].[TraceFlag] = '3226' THEN '3226 enabled globally, which keeps the event log clean by not reporting successful backups.' WHEN [T].[TraceFlag] = '3505' THEN '3505 enabled globally, which disables Checkpoints. This is usually a very bad idea.' WHEN [T].[TraceFlag] = '4199' THEN '4199 enabled globally, which enables non-default Query Optimizer fixes, changing query plans from the default behaviors.' - WHEN [T].[TraceFlag] = '7745' AND @ProductVersionMajor > 12 AND @QueryStoreInUse = 1 THEN '7745 enabled globally, which makes shutdowns/failovers quicker by not waiting for Query Store to flush to disk. This good idea loses you the non-flushed Query Store data.' + WHEN [T].[TraceFlag] = '7745' AND @QueryStoreInUse = 1 THEN '7745 enabled globally, which makes shutdowns/failovers quicker by not waiting for Query Store to flush to disk. This good idea loses you the non-flushed Query Store data.' WHEN [T].[TraceFlag] = '7745' AND @ProductVersionMajor > 12 THEN '7745 enabled globally, which is for Query Store. None of your databases have Query Store enabled, so why do you have this turned on?' WHEN [T].[TraceFlag] = '7745' AND @ProductVersionMajor <= 12 THEN '7745 enabled globally, which is for Query Store. Query Store does not exist on your SQL Server version, so why do you have this turned on?' WHEN [T].[TraceFlag] = '7752' AND @ProductVersionMajor > 14 THEN '7752 enabled globally, which is for Query Store. However, it has no effect in your SQL Server version. Consider turning it off.' - WHEN [T].[TraceFlag] = '7752' AND @ProductVersionMajor > 12 AND @QueryStoreInUse = 1 THEN '7752 enabled globally, which stops queries needing to wait on Query Store loading up after database recovery.' + WHEN [T].[TraceFlag] = '7752' AND @QueryStoreInUse = 1 THEN '7752 enabled globally, which stops queries needing to wait on Query Store loading up after database recovery.' WHEN [T].[TraceFlag] = '7752' AND @ProductVersionMajor > 12 THEN '7752 enabled globally, which is for Query Store. None of your databases have Query Store enabled, so why do you have this turned on?' WHEN [T].[TraceFlag] = '7752' AND @ProductVersionMajor <= 12 THEN '7752 enabled globally, which is for Query Store. Query Store does not exist on your SQL Server version, so why do you have this turned on?' WHEN [T].[TraceFlag] = '8048' THEN '8048 enabled globally, which tries to reduce CMEMTHREAD waits on servers with a lot of logical processors.' @@ -8534,6 +8584,54 @@ IF @ProductVersionMajor >= 10 ELSE [T].[TraceFlag] + ' is enabled globally.' END AS Details FROM #TraceStatus T; + + + IF NOT EXISTS ( SELECT 1 + FROM #TraceStatus T + WHERE [T].[TraceFlag] = '7745' ) + AND @QueryStoreInUse = 1 + + BEGIN + INSERT INTO #BlitzResults + ( CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT 74 AS CheckID , + 200 AS Priority , + 'Informational' AS FindingsGroup , + 'Recommended Trace Flag Off' AS Finding , + 'https://www.sqlskills.com/blogs/erin/query-store-trace-flags/' AS URL , + 'Trace Flag 7745 not enabled globally. It makes shutdowns/failovers quicker by not waiting for Query Store to flush to disk. It is recommended, but it loses you the non-flushed Query Store data.' AS Details + FROM #TraceStatus T + END; + + IF NOT EXISTS ( SELECT 1 + FROM #TraceStatus T + WHERE [T].[TraceFlag] = '7752' ) + AND @ProductVersionMajor < 15 + AND @QueryStoreInUse = 1 + + BEGIN + INSERT INTO #BlitzResults + ( CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT 74 AS CheckID , + 200 AS Priority , + 'Informational' AS FindingsGroup , + 'Recommended Trace Flag Off' AS Finding , + 'https://www.sqlskills.com/blogs/erin/query-store-trace-flags/' AS URL , + 'Trace Flag 7752 not enabled globally. It stops queries needing to wait on Query Store loading up after database recovery. It is so recommended that it is enabled by default as of SQL Server 2019.' AS Details + FROM #TraceStatus T + END; END; /* High CMEMTHREAD waits that could need trace flag 8048.