From b4f1a673d646890ea8acb7d9302b68ca1809d6c7 Mon Sep 17 00:00:00 2001 From: Brent Ozar Date: Tue, 2 Jul 2019 10:40:08 -0700 Subject: [PATCH] 2019_07 release I am not proud of this, hahaha, but let's see if we can commit directly to master to fix this. --- Documentation/sp_Blitz Checks by Priority.md | 9 +- Install-All-Scripts.sql | 1744 +++++++++++++----- Install-Core-Blitz-No-Query-Store.sql | 1658 ++++++++++++----- Install-Core-Blitz-With-Query-Store.sql | 1666 ++++++++++++----- SqlServerVersions.sql | 12 +- sp_AllNightLog.sql | 2 +- sp_AllNightLog_Setup.sql | 2 +- sp_Blitz.sql | 677 ++++++- sp_BlitzBackups.sql | 2 +- sp_BlitzCache.sql | 726 ++++---- sp_BlitzFirst.sql | 104 +- sp_BlitzInMemoryOLTP.sql | 2 +- sp_BlitzIndex.sql | 123 +- sp_BlitzLock.sql | 14 +- sp_BlitzQueryStore.sql | 8 +- sp_BlitzWho.sql | 2 +- sp_DatabaseRestore.sql | 50 +- sp_foreachdb.sql | 2 +- sp_ineachdb.sql | 32 +- 19 files changed, 4905 insertions(+), 1930 deletions(-) diff --git a/Documentation/sp_Blitz Checks by Priority.md b/Documentation/sp_Blitz Checks by Priority.md index 74d6587cb..816155106 100644 --- a/Documentation/sp_Blitz Checks by Priority.md +++ b/Documentation/sp_Blitz Checks by Priority.md @@ -6,8 +6,8 @@ Before adding a new check, make sure to add a Github issue for it first, and hav If you want to change anything about a check - the priority, finding, URL, or ID - open a Github issue first. The relevant scripts have to be updated too. -CURRENT HIGH CHECKID: 224. -If you want to add a new one, start at 225. +CURRENT HIGH CHECKID: 229. +If you want to add a new one, start at 230. | Priority | FindingsGroup | Finding | URL | CheckID | |----------|-----------------------------|---------------------------------------------------------|------------------------------------------------------------------------|----------| @@ -24,6 +24,7 @@ If you want to add a new one, start at 225. | 1 | Corruption | Database Corruption Detected | https://www.BrentOzar.com/go/repair | 90 | | 1 | Performance | Memory Dangerously Low | https://www.BrentOzar.com/go/max | 51 | | 1 | Performance | Memory Dangerously Low in NUMA Nodes | https://www.BrentOzar.com/go/max | 159 | +| 1 | Reliability | Evaluation Edition | https://www.BrentOzar.com/go/workgroup | 229 | | 1 | Reliability | Last good DBCC CHECKDB over 2 weeks old | https://www.BrentOzar.com/go/checkdb | 68 | | 5 | Monitoring | Disabled Internal Monitoring Features | https://msdn.microsoft.com/en-us/library/ms190737.aspx | 177 | | 5 | Reliability | Dangerous Third Party Modules | https://support.microsoft.com/en-us/kb/2033238 | 179 | @@ -242,6 +243,7 @@ If you want to add a new one, start at 225. | 200 | Performance | User-Created Statistics In Place | https://www.BrentOzar.com/go/userstats | 122 | | 200 | Performance | SSAS/SSIS/SSRS Installed | https://www.BrentOzar.com/go/services | 224 | | 200 | Reliability | Extended Stored Procedures in Master | https://www.BrentOzar.com/go/clr | 105 | +| 200 | Reliability | Resumable Index Operation Paused | https://www.BrentOzar.com/go/resumable | 225 | | 200 | Surface Area | Endpoints Configured | https://www.BrentOzar.com/go/endpoints/ | 9 | | 210 | Non-Default Database Config | ANSI NULL Default Enabled | https://www.BrentOzar.com/go/dbdefaults | 135 | | 210 | Non-Default Database Config | Auto Create Stats Incremental Enabled | https://www.BrentOzar.com/go/dbdefaults | 134 | @@ -296,5 +298,8 @@ If you want to add a new one, start at 225. | 250 | Server Info | Windows Version | | 172 | | 250 | Server Info | Power Plan | | 211 | | 250 | Server Info | Stacked Instances | https://www.brentozar.com/go/babygotstacked/ | 212 | +| 253 | First Responder Kit | Version Check Failed | http://FirstResponderKit.org | 226 | +| 253 | First Responder Kit | Component Missing | http://FirstResponderKit.org | 227 | +| 253 | First Responder Kit | Component Outdated | http://FirstResponderKit.org | 228 | | 254 | Rundate | (Current Date) | | 156 | | 255 | Thanks! | From Your Community Volunteers | | -1 | \ No newline at end of file diff --git a/Install-All-Scripts.sql b/Install-All-Scripts.sql index 7185f1b93..0f935b626 100755 --- a/Install-All-Scripts.sql +++ b/Install-All-Scripts.sql @@ -30,7 +30,7 @@ SET NOCOUNT ON; BEGIN; -SELECT @Version = '3.4', @VersionDate = '20190320'; +SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -1522,7 +1522,7 @@ SET NOCOUNT ON; BEGIN; -SELECT @Version = '3.4', @VersionDate = '20190320'; +SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -2845,7 +2845,7 @@ AS SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '7.4', @VersionDate = '20190320'; + SELECT @Version = '7.6', @VersionDate = '20190702'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -2887,7 +2887,7 @@ AS @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 + @OutputType ''TABLE''=table | ''COUNT''=row with number found | ''MARKDOWN''=bulleted list | ''SCHEMA''=version and field list | ''XML'' =table output as XML | ''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. @@ -2925,8 +2925,8 @@ AS 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' */ + END;/* IF @OutputType = 'SCHEMA' */ + ELSE BEGIN DECLARE @StringToExecute NVARCHAR(4000) @@ -2959,7 +2959,38 @@ AS ,@TraceFileIssue bit -- Flag for Windows OS to help with Linux support ,@IsWindowsOperatingSystem BIT - ,@DaysUptime NUMERIC(23,2); + ,@DaysUptime NUMERIC(23,2) + /* For First Responder Kit consistency check:*/ + ,@spBlitzFullName VARCHAR(1024) + ,@BlitzIsOutdatedComparedToOthers BIT + ,@tsql NVARCHAR(MAX) + ,@VersionCheckModeExistsTSQL NVARCHAR(MAX) + ,@BlitzProcDbName VARCHAR(256) + ,@ExecRet INT + ,@InnerExecRet INT + ,@TmpCnt INT + ,@PreviousComponentName VARCHAR(256) + ,@PreviousComponentFullPath VARCHAR(1024) + ,@CurrentStatementId INT + ,@CurrentComponentSchema VARCHAR(256) + ,@CurrentComponentName VARCHAR(256) + ,@CurrentComponentType VARCHAR(256) + ,@CurrentComponentVersionDate DATETIME2 + ,@CurrentComponentFullName VARCHAR(1024) + ,@CurrentComponentMandatory BIT + ,@MaximumVersionDate DATETIME + ,@StatementCheckName VARCHAR(256) + ,@StatementOutputsCounter BIT + ,@OutputCounterExpectedValue INT + ,@StatementOutputsExecRet BIT + ,@StatementOutputsDateTime BIT + ,@CurrentComponentMandatoryCheckOK BIT + ,@CurrentComponentVersionCheckModeOK BIT + ,@canExitLoop BIT + ,@frkIsConsistent BIT + + /* End of declarations for First Responder Kit consistency check:*/ + ; SET @crlf = NCHAR(13) + NCHAR(10); SET @ResultText = 'sp_Blitz Results: ' + @crlf; @@ -3010,6 +3041,47 @@ AS Finding NVARCHAR(128) ); + /* First Responder Kit consistency (temporary tables) */ + + IF(OBJECT_ID('tempdb..#FRKObjects') IS NOT NULL) + BEGIN + EXEC sp_executesql N'DROP TABLE #FRKObjects;'; + END; + + -- this one represents FRK objects + CREATE TABLE #FRKObjects ( + DatabaseName VARCHAR(256) NOT NULL, + ObjectSchemaName VARCHAR(256) NULL, + ObjectName VARCHAR(256) NOT NULL, + ObjectType VARCHAR(256) NOT NULL, + MandatoryComponent BIT NOT NULL + ); + + + IF(OBJECT_ID('tempdb..#StatementsToRun4FRKVersionCheck') IS NOT NULL) + BEGIN + EXEC sp_executesql N'DROP TABLE #StatementsToRun4FRKVersionCheck;'; + END; + + + -- This one will contain the statements to be executed + -- order: 1- Mandatory, 2- VersionCheckMode, 3- VersionCheck + + CREATE TABLE #StatementsToRun4FRKVersionCheck ( + StatementId INT IDENTITY(1,1), + CheckName VARCHAR(256), + SubjectName VARCHAR(256), + SubjectFullPath VARCHAR(1024), + StatementText NVARCHAR(MAX), + StatementOutputsCounter BIT, + OutputCounterExpectedValue INT, + StatementOutputsExecRet BIT, + StatementOutputsDateTime BIT + ); + + /* End of First Responder Kit consistency (temporary tables) */ + + /* You can build your own table with a list of checks to skip. For example, you might have some databases that you don't care about, or some checks you don't @@ -5089,7 +5161,7 @@ AS 200 AS Priority , 'Monitoring' AS FindingsGroup , 'Alerts Disabled' AS Finding , - 'https://www.BrentOzar.com/go/alerts/' AS URL , + 'https://BrentOzar.com/go/alert' AS URL , ( 'The following Alert is disabled, please review and enable if desired: ' + name ) AS Details FROM msdb.dbo.sysalerts @@ -7066,6 +7138,513 @@ IF @ProductVersionMajor >= 10 END; END; + +/*This checks that First Responder Kit is consistent. +It assumes that all the objects of the kit resides in the same database, the one in which this SP is stored +It also is ready to check for installation in another schema. +*/ +IF( + NOT EXISTS ( + SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 226 + ) +) +BEGIN + + IF @Debug IN (1, 2) RAISERROR('Running check with id %d',0,1,2000); + + SET @spBlitzFullName = QUOTENAME(DB_NAME()) + '.' +QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)) + '.' + QUOTENAME(OBJECT_NAME(@@PROCID)); + SET @BlitzIsOutdatedComparedToOthers = 0; + SET @tsql = NULL; + SET @VersionCheckModeExistsTSQL = NULL; + SET @BlitzProcDbName = DB_NAME(); + SET @ExecRet = NULL; + SET @InnerExecRet = NULL; + SET @TmpCnt = NULL; + + SET @PreviousComponentName = NULL; + SET @PreviousComponentFullPath = NULL; + SET @CurrentStatementId = NULL; + SET @CurrentComponentSchema = NULL; + SET @CurrentComponentName = NULL; + SET @CurrentComponentType = NULL; + SET @CurrentComponentVersionDate = NULL; + SET @CurrentComponentFullName = NULL; + SET @CurrentComponentMandatory = NULL; + SET @MaximumVersionDate = NULL; + + SET @StatementCheckName = NULL; + SET @StatementOutputsCounter = NULL; + SET @OutputCounterExpectedValue = NULL; + SET @StatementOutputsExecRet = NULL; + SET @StatementOutputsDateTime = NULL; + + SET @CurrentComponentMandatoryCheckOK = NULL; + SET @CurrentComponentVersionCheckModeOK = NULL; + + SET @canExitLoop = 0; + SET @frkIsConsistent = 0; + + + SET @tsql = 'USE ' + QUOTENAME(@BlitzProcDbName) + ';' + @crlf + + 'WITH FRKComponents (' + @crlf + + ' ObjectName,' + @crlf + + ' ObjectType,' + @crlf + + ' MandatoryComponent' + @crlf + + ')' + @crlf + + 'AS (' + @crlf + + ' SELECT ''sp_AllNightLog'',''P'' ,0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''sp_AllNightLog_Setup'', ''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_Blitz'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzBackups'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzCache'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzFirst'',''P'',0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''sp_BlitzIndex'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzLock'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzQueryStore'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzWho'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_DatabaseRestore'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_foreachdb'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_ineachdb'',''P'',0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''SqlServerVersions'',''U'',0' + @crlf + + ')' + @crlf + + 'INSERT INTO #FRKObjects (' + @crlf + + ' DatabaseName,ObjectSchemaName,ObjectName, ObjectType,MandatoryComponent' + @crlf + + ')' + @crlf + + 'SELECT DB_NAME(),SCHEMA_NAME(o.schema_id), c.ObjectName,c.ObjectType,c.MandatoryComponent' + @crlf + + 'FROM ' + @crlf + + ' FRKComponents c' + @crlf + + 'LEFT JOIN ' + @crlf + + ' sys.objects o' + @crlf + + 'ON c.ObjectName = o.[name]' + @crlf + + 'AND c.ObjectType = o.[type]' + @crlf + + --'WHERE o.schema_id IS NOT NULL' + @crlf + + ';' + ; + + EXEC @ExecRet = sp_executesql @tsql ; + + -- TODO: add check for statement success + + -- TODO: based on SP requirements and presence (SchemaName is not null) ==> update MandatoryComponent column + + -- Filling #StatementsToRun4FRKVersionCheck + INSERT INTO #StatementsToRun4FRKVersionCheck ( + CheckName,StatementText,SubjectName,SubjectFullPath, StatementOutputsCounter,OutputCounterExpectedValue,StatementOutputsExecRet,StatementOutputsDateTime + ) + SELECT + 'Mandatory', + 'SELECT @cnt = COUNT(*) FROM #FRKObjects WHERE ObjectSchemaName IS NULL AND ObjectName = ''' + ObjectName + ''' AND MandatoryComponent = 1;', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 1, + 0, + 0, + 0 + FROM #FRKObjects + UNION ALL + SELECT + 'VersionCheckMode', + 'SELECT @cnt = COUNT(*) FROM ' + + QUOTENAME(DatabaseName) + '.sys.all_parameters ' + + 'where object_id = OBJECT_ID(''' + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName) + ''') AND [name] = ''@VersionCheckMode'';', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 1, + 1, + 0, + 0 + FROM #FRKObjects + WHERE ObjectType = 'P' + AND ObjectSchemaName IS NOT NULL + UNION ALL + SELECT + 'VersionCheck', + 'EXEC @ExecRet = ' + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName) + ' @VersionCheckMode = 1 , @VersionDate = @ObjDate OUTPUT;', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 0, + 0, + 1, + 1 + FROM #FRKObjects + WHERE ObjectType = 'P' + AND ObjectSchemaName IS NOT NULL + ; + IF(@Debug in (1,2)) + BEGIN + SELECT * + FROM #StatementsToRun4FRKVersionCheck ORDER BY SubjectName,SubjectFullPath,StatementId -- in case of schema change ; + END; + + + -- loop on queries... + WHILE(@canExitLoop = 0) + BEGIN + SET @CurrentStatementId = NULL; + + SELECT TOP 1 + @StatementCheckName = CheckName, + @CurrentStatementId = StatementId , + @CurrentComponentName = SubjectName, + @CurrentComponentFullName = SubjectFullPath, + @tsql = StatementText, + @StatementOutputsCounter = StatementOutputsCounter, + @OutputCounterExpectedValue = OutputCounterExpectedValue , + @StatementOutputsExecRet = StatementOutputsExecRet, + @StatementOutputsDateTime = StatementOutputsDateTime + FROM #StatementsToRun4FRKVersionCheck + ORDER BY SubjectName, SubjectFullPath,StatementId /* in case of schema change */ + ; + + -- loop exit condition + IF(@CurrentStatementId IS NULL) + BEGIN + BREAK; + END; + + IF @Debug IN (1, 2) RAISERROR(' Statement: %s',0,1,@tsql); + + -- we start a new component + IF(@PreviousComponentName IS NULL OR + (@PreviousComponentName IS NOT NULL AND @PreviousComponentName <> @CurrentComponentName) OR + (@PreviousComponentName IS NOT NULL AND @PreviousComponentName = @CurrentComponentName AND @PreviousComponentFullPath <> @CurrentComponentFullName) + ) + BEGIN + -- reset variables + SET @CurrentComponentMandatoryCheckOK = 0; + SET @CurrentComponentVersionCheckModeOK = 0; + SET @PreviousComponentName = @CurrentComponentName; + SET @PreviousComponentFullPath = @CurrentComponentFullName ; + END; + + IF(@StatementCheckName NOT IN ('Mandatory','VersionCheckMode','VersionCheck')) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (code generator changed)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Your version check failed because a change has been made to the version check code generator.' + @crlf + + 'Error: No handler for check with name "' + ISNULL(@StatementCheckName,'') + '"' AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@StatementCheckName = 'Mandatory') + BEGIN + -- outputs counter + EXEC @ExecRet = sp_executesql @tsql, N'@cnt INT OUTPUT',@cnt = @TmpCnt OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Your version check failed due to dynamic query failure.' + @crlf + + 'Error: following query failed at execution (check if component [' + ISNULL(@CurrentComponentName,@CurrentComponentName) + '] is mandatory and missing)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@TmpCnt <> @OutputCounterExpectedValue) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 227 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Missing: ' + @CurrentComponentName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated version of the First Responder Kit to install it.' AS Details + ; + + -- as it's missing, no value for SubjectFullPath + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectName = @CurrentComponentName ; + CONTINUE; + END; + + SET @CurrentComponentMandatoryCheckOK = 1; + END; + + IF(@StatementCheckName = 'VersionCheckMode') + BEGIN + IF(@CurrentComponentMandatoryCheckOK = 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (unexpectedly modified checks ordering)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because "Mandatory" check has not been completed before for current component' + @crlf + + 'Error: version check mode happenned before "Mandatory" check for component called "' + @CurrentComponentFullName + '"' + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + -- outputs counter + EXEC @ExecRet = sp_executesql @tsql, N'@cnt INT OUTPUT',@cnt = @TmpCnt OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because a change has been made to the code generator.' + @crlf + + 'Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] can run in VersionCheckMode)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@TmpCnt <> @OutputCounterExpectedValue) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 228 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Outdated: ' + @CurrentComponentFullName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Component ' + @CurrentComponentFullName + ' is not at the minimum version required to run this procedure' + @crlf + + 'VersionCheckMode has been introduced in component version date after "20190320". This means its version is lower than or equal to that date.' AS Details; + ; + + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + SET @CurrentComponentVersionCheckModeOK = 1; + END; + + IF(@StatementCheckName = 'VersionCheck') + BEGIN + IF(@CurrentComponentMandatoryCheckOK = 0 OR @CurrentComponentVersionCheckModeOK = 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (unexpectedly modified checks ordering)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because "VersionCheckMode" check has not been completed before for component called "' + @CurrentComponentFullName + '"' + @crlf + + 'Error: VersionCheck happenned before "VersionCheckMode" check for component called "' + @CurrentComponentFullName + '"' + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + EXEC @ExecRet = sp_executesql @tsql , N'@ExecRet INT OUTPUT, @ObjDate DATETIME OUTPUT', @ExecRet = @InnerExecRet OUTPUT, @ObjDate = @CurrentComponentVersionDate OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. The version check failed because a change has been made to the code generator.' + @crlf + + 'Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] is at the expected version)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + + IF(@InnerExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (Failed dynamic SP call to ' + @CurrentComponentFullName + ')' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] is at the expected version)' + @crlf + + 'Return code: ' + CONVERT(VARCHAR(10),@InnerExecRet) + @crlf + + 'T-SQL Query: ' + @crlf + + @tsql AS Details + ; + + -- advance to next component + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + IF(@CurrentComponentVersionDate < @VersionDate) + BEGIN + + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 228 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Outdated: ' + @CurrentComponentFullName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download and install the latest First Responder Kit - you''re running some older code, and it doesn''t get better with age.' AS Details + ; + + RAISERROR('Component %s is outdated',10,1,@CurrentComponentFullName); + -- advance to next component + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + ELSE IF(@CurrentComponentVersionDate > @VersionDate AND @BlitzIsOutdatedComparedToOthers = 0) + BEGIN + SET @BlitzIsOutdatedComparedToOthers = 1; + RAISERROR('Procedure %s is outdated',10,1,@spBlitzFullName); + IF(@MaximumVersionDate IS NULL OR @MaximumVersionDate < @CurrentComponentVersionDate) + BEGIN + SET @MaximumVersionDate = @CurrentComponentVersionDate; + END; + END; + /* Kept for debug purpose: + ELSE + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 2000 AS CheckID , + 250 AS Priority , + 'Informational' AS FindingsGroup , + 'First Responder kit component ' + @CurrentComponentFullName + ' is at the expected version' AS Finding , + 'https://www.BrentOzar.com/blitz/' AS URL , + 'Version date is: ' + CONVERT(VARCHAR(32),@CurrentComponentVersionDate,121) AS Details + ; + END; + */ + END; + + -- could be performed differently to minimize computation + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE StatementId = @CurrentStatementId ; + END; +END; + /*This counts memory dumps and gives min and max date of in view*/ IF @ProductVersionMajor >= 10 @@ -7881,9 +8460,9 @@ IF @ProductVersionMajor >= 10 DB_NAME(s.database_id) + '' has '' + CONVERT(NVARCHAR(20), COUNT_BIG(*)) - + '' open implicit transactions '' - + '' with an oldest begin time of '' - + CONVERT(NVARCHAR(30), MIN(tat.transaction_begin_time)) AS details + + '' open implicit transactions with an oldest begin time of '' + + CONVERT(NVARCHAR(30), MIN(tat.transaction_begin_time)) + + '' Run sp_BlitzWho and check the is_implicit_transaction column to see the culprits.'' AS details FROM sys.dm_tran_active_transactions AS tat LEFT JOIN sys.dm_tran_session_transactions AS tst ON tst.transaction_id = tat.transaction_id @@ -7940,6 +8519,32 @@ IF @ProductVersionMajor >= 10 END; + IF NOT EXISTS ( SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 229 ) + AND CAST(SERVERPROPERTY('Edition') AS NVARCHAR(4000)) LIKE '%Evaluation%' + BEGIN + + IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 216) WITH NOWAIT; + + INSERT INTO #BlitzResults + ( CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT 229 AS CheckID, + 1 AS Priority, + 'Reliability' AS FindingsGroup, + 'Evaluation Edition' AS Finding, + 'https://www.BrentOzar.com/go/workgroup' AS URL, + 'This server will stop working on: ' + CAST(CONVERT(DATETIME, DATEADD(DD, 180, create_date), 102) AS VARCHAR(100)) AS details + FROM sys.server_principals + WHERE sid = 0x010100000000000512000000; + + END; IF @CheckUserDatabaseObjects = 1 @@ -8924,6 +9529,37 @@ IF @ProductVersionMajor >= 10 HAVING COUNT(1) > 0;'; END; --of Check 218. + /* Check 225 - Reliability - Resumable Index Operation Paused */ + IF NOT EXISTS ( + SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL + AND CheckID = 225 + ) + AND EXISTS (SELECT * FROM sys.all_objects WHERE name = 'index_resumable_operations') + BEGIN + IF @Debug IN (1,2) + BEGIN + RAISERROR ('Running CheckId [%d].',0,1,218) WITH NOWAIT; + END + + EXECUTE sp_MSforeachdb 'USE [?]; + SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + INSERT INTO #BlitzResults (CheckID, DatabaseName, Priority, FindingsGroup, Finding, URL, Details) + SELECT 225 AS CheckID + ,''?'' AS DatabaseName + ,200 AS Priority + ,''Reliability'' AS FindingsGroup + ,''Resumable Index Operation Paused'' AS Finding + ,''https://BrentOzar.com/go/resumable'' AS URL + ,iro.state_desc + N'' since '' + CONVERT(NVARCHAR(50), last_pause_time, 120) + '', '' + + CAST(iro.percent_complete AS NVARCHAR(20)) + ''% complete: '' + + CAST(iro.sql_text AS NVARCHAR(1000)) AS Details + FROM sys.index_resumable_operations iro + JOIN sys.objects o ON iro.[object_id] = o.[object_id] + WHERE iro.state <> 0;'; + END; --of Check 225. + --/* Check 220 - Statistics Without Histograms */ --IF NOT EXISTS ( -- SELECT 1 @@ -9482,7 +10118,7 @@ IF @ProductVersionMajor >= 10 (@@SERVERNAME IS NOT NULL AND /* not a named instance */ - CHARINDEX('\',CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128))) = 0 + CHARINDEX(CHAR(92),CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128))) = 0 AND /* not clustered, when computername may be different than the servername */ SERVERPROPERTY('IsClustered') = 0 @@ -11046,6 +11682,25 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1 LEFT OUTER JOIN Results rNext ON r.rownum = rNext.rownum - 1 ORDER BY r.rownum FOR XML PATH(N''); END; + ELSE IF @OutputType = 'XML' + BEGIN + /* --TOURSTOP05-- */ + SELECT [Priority] , + [FindingsGroup] , + [Finding] , + [DatabaseName] , + [URL] , + [Details] , + [QueryPlanFiltered] , + CheckID + FROM #BlitzResults + ORDER BY Priority , + FindingsGroup , + Finding , + DatabaseName , + Details + FOR XML PATH('Result'), ROOT('sp_Blitz_Output'); + END; ELSE IF @OutputType <> 'NONE' BEGIN /* --TOURSTOP05-- */ @@ -11126,7 +11781,7 @@ GO /* --Sample execution call with the most common parameters: -EXEC [dbo].[sp_Blitz] +EXEC [dbo].[sp_Blitz] @CheckUserDatabaseObjects = 1 , @CheckProcedureCache = 0 , @OutputType = 'TABLE' , @@ -11159,7 +11814,7 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '3.4', @VersionDate = '20190320'; + SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -12814,7 +13469,7 @@ CREATE TABLE ##BlitzCacheProcs ( unparameterized_query BIT, near_parallel BIT, plan_warnings BIT, - plan_multiple_plans BIT, + plan_multiple_plans INT, long_running BIT, downlevel_estimator BIT, implicit_conversions BIT, @@ -12931,7 +13586,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) @@ -13571,7 +14226,7 @@ BEGIN unparameterized_query BIT, near_parallel BIT, plan_warnings BIT, - plan_multiple_plans BIT, + plan_multiple_plans INT, long_running BIT, downlevel_estimator BIT, implicit_conversions BIT, @@ -13722,10 +14377,6 @@ IF @SortOrder NOT IN ('cpu', 'avg cpu', 'reads', 'avg reads', 'writes', 'avg wri SET @SortOrder = 'cpu'; END; -SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName), - @OutputSchemaName = QUOTENAME(@OutputSchemaName), - @OutputTableName = QUOTENAME(@OutputTableName); - SET @QueryFilter = LOWER(@QueryFilter); IF LEFT(@QueryFilter, 3) NOT IN ('all', 'sta', 'pro', 'fun') @@ -13740,6 +14391,25 @@ IF @SkipAnalysis = 1 SET @HideSummary = 1; END; +DECLARE @AllSortSql NVARCHAR(MAX) = N''; +DECLARE @VersionShowsMemoryGrants BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') + SET @VersionShowsMemoryGrants = 1; +ELSE + SET @VersionShowsMemoryGrants = 0; + +DECLARE @VersionShowsSpills BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') + SET @VersionShowsSpills = 1; +ELSE + SET @VersionShowsSpills = 0; + +DECLARE @VersionShowsAirQuoteActualPlans BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') + SET @VersionShowsAirQuoteActualPlans = 1; +ELSE + SET @VersionShowsAirQuoteActualPlans = 0; + IF @Reanalyze = 1 AND OBJECT_ID('tempdb..##BlitzCacheResults') IS NULL BEGIN RAISERROR(N'##BlitzCacheResults does not exist, can''t reanalyze', 0, 1) WITH NOWAIT; @@ -13764,6 +14434,9 @@ IF @Reanalyze = 1 GOTO Results; END; + + + IF @SortOrder IN ('all', 'all avg') BEGIN RAISERROR(N'Checking all sort orders, please be patient', 0, 1) WITH NOWAIT; @@ -14393,22 +15066,15 @@ SELECT @v = common_version , FROM #checkversion OPTION (RECOMPILE); -IF (@SortOrder IN ('memory grant', 'avg memory grant')) -AND ((@v < 11) -OR (@v = 11 AND @build < 6020) -OR (@v = 12 AND @build < 5000) -OR (@v = 13 AND @build < 1601)) +IF (@SortOrder IN ('memory grant', 'avg memory grant')) AND @VersionShowsMemoryGrants = 0 BEGIN RAISERROR('Your version of SQL does not support sorting by memory grant or average memory grant. Please use another sort order.', 16, 1); RETURN; END; -IF (@SortOrder IN ('spills', 'avg spills')) -AND (@v < 13 - OR @v = 13 AND @build < 5026 - OR @v = 14 AND @build < 3015) +IF (@SortOrder IN ('spills', 'avg spills') AND @VersionShowsSpills = 0) BEGIN - RAISERROR('Your version of SQL does not support sorting by spills or average spills. Please use another sort order.', 16, 1); + RAISERROR('Your version of SQL does not support sorting by spills. Please use another sort order.', 16, 1); RETURN; END; @@ -14443,8 +15109,19 @@ FROM (SELECT TOP (@Top) x.*, xpa.*, CROSS APPLY (SELECT * FROM sys.dm_exec_plan_attributes(x.plan_handle) AS ixpa WHERE ixpa.attribute = ''dbid'') AS xpa ' + @nl ; + +IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @body += N' CROSS APPLY sys.dm_exec_query_plan_stats(x.plan_handle) AS deqps ' + @nl ; + END + SET @body += N' WHERE 1 = 1 ' + @nl ; +IF EXISTS (SELECT * FROM sys.all_objects o INNER JOIN sys.all_columns c ON o.object_id = c.object_id WHERE o.name = 'dm_hadr_database_replica_states' AND c.name = 'is_primary_replica') + BEGIN + RAISERROR(N'Ignoring readable secondaries databases by default', 0, 1) WITH NOWAIT; + SET @body += N' AND CAST(xpa.value AS INT) NOT IN (select database_id from sys.dm_hadr_database_replica_states where is_primary_replica = 0 AND DATABASEPROPERTYEX(DB_NAME(database_id), ''Updateability'') = ''READ_ONLY'')' + @nl ; + END IF @IgnoreSystemDBs = 1 BEGIN @@ -14559,6 +15236,11 @@ SET @body += N') AS qs CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS st CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp ' + @nl ; +IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @body += N' CROSS APPLY sys.dm_exec_query_plan_stats(qs.plan_handle) AS deqps ' + @nl ; + END + SET @body_where += N' AND pa.attribute = ' + QUOTENAME('dbid', @q ) + @nl ; @@ -14627,7 +15309,7 @@ SELECT TOP (@Top) NULL AS PercentMemoryGrantUsed, NULL AS AvgMaxMemoryGrant,'; - IF @v >=15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026) + IF @VersionShowsSpills = 1 BEGIN RAISERROR(N'Getting spill information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @plans_triggers_select_list += N' @@ -14646,10 +15328,20 @@ SELECT TOP (@Top) NULL AS AvgSpills, ' ; END; - SET @plans_triggers_select_list += - N'st.text AS QueryText , - query_plan AS QueryPlan, - t.t_TotalWorker, + SET @plans_triggers_select_list += + N'st.text AS QueryText ,'; + + IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @plans_triggers_select_list += N' COALESCE(deqps.query_plan, qp.query_plan) AS QueryPlan, ' + @nl ; + END; + ELSE + BEGIN + SET @plans_triggers_select_list += N' qp.query_plan AS QueryPlan, ' + @nl ; + END; + + SET @plans_triggers_select_list += + N't.t_TotalWorker, t.t_TotalElapsed, t.t_TotalReads, t.t_TotalExecs, @@ -14736,8 +15428,7 @@ BEGIN NULL AS LastReturnedRows, ' ; END; - IF (@v = 11 AND @build >= 6020) OR (@v = 12 AND @build >= 5000) OR (@v = 13 AND @build >= 1601) OR (@v >= 14) - + IF @VersionShowsMemoryGrants = 1 BEGIN RAISERROR(N'Getting memory grant information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @sql += N' @@ -14760,7 +15451,7 @@ BEGIN NULL AS AvgMaxMemoryGrant, ' ; END; - IF @v >=15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026) + IF @VersionShowsSpills = 1 BEGIN RAISERROR(N'Getting spill information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @sql += N' @@ -14783,8 +15474,19 @@ BEGIN SUBSTRING(st.text, ( qs.statement_start_offset / 2 ) + 1, ( ( CASE qs.statement_end_offset WHEN -1 THEN DATALENGTH(st.text) ELSE qs.statement_end_offset - END - qs.statement_start_offset ) / 2 ) + 1) AS QueryText , - query_plan AS QueryPlan, + END - qs.statement_start_offset ) / 2 ) + 1) AS QueryText , ' + @nl ; + + + IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @sql += N' COALESCE(deqps.query_plan, qp.query_plan) AS QueryPlan, ' + @nl ; + END + ELSE + BEGIN + SET @sql += N' query_plan AS QueryPlan, ' + @nl ; + END + + SET @sql += N' t.t_TotalWorker, t.t_TotalElapsed, t.t_TotalReads, @@ -14944,6 +15646,9 @@ FROM (SELECT SqlHandle, WHERE x.rn = 1 OPTION (RECOMPILE); +/* + This block was used to delete duplicate queries, but has been removed. + For more info: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2026 WITH d AS ( SELECT SPID, ROW_NUMBER() OVER (PARTITION BY SqlHandle, QueryHash ORDER BY #sortable# DESC) AS rn @@ -14953,7 +15658,8 @@ WHERE SPID = @@SPID DELETE d WHERE d.rn > 1 AND SPID = @@SPID -OPTION (RECOMPILE); +OPTION (RECOMPILE); +*/ '; SELECT @sort = CASE @SortOrder WHEN N'cpu' THEN N'TotalCPU' @@ -15058,11 +15764,11 @@ OPTION (RECOMPILE) ; * metric. */ RAISERROR('Computing CPU, duration, read, and write metrics', 0, 1) WITH NOWAIT; -DECLARE @total_duration MONEY, - @total_cpu MONEY, - @total_reads MONEY, - @total_writes MONEY, - @total_execution_count MONEY; +DECLARE @total_duration BIGINT, + @total_cpu BIGINT, + @total_reads BIGINT, + @total_writes BIGINT, + @total_execution_count BIGINT; SELECT @total_cpu = SUM(TotalCPU), @total_duration = SUM(TotalDuration), @@ -15245,7 +15951,7 @@ RAISERROR(N'Gathering high level plan information', 0, 1) WITH NOWAIT; UPDATE ##BlitzCacheProcs SET NumberOfDistinctPlans = distinct_plan_count, NumberOfPlans = number_of_plans , - plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN 1 END + plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN number_of_plans END FROM ( SELECT COUNT(DISTINCT QueryHash) AS distinct_plan_count, COUNT(QueryHash) AS number_of_plans, @@ -16055,7 +16761,7 @@ WITH XMLNAMESPACES('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS UPDATE ##BlitzCacheProcs SET NumberOfDistinctPlans = distinct_plan_count, NumberOfPlans = number_of_plans, - plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN 1 END + plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN number_of_plans END FROM ( SELECT COUNT(DISTINCT QueryHash) AS distinct_plan_count, COUNT(QueryHash) AS number_of_plans, @@ -16986,7 +17692,7 @@ SET Warnings = SUBSTRING( CASE WHEN downlevel_estimator = 1 THEN ', Downlevel CE' ELSE '' END + CASE WHEN implicit_conversions = 1 THEN ', Implicit Conversions' ELSE '' END + CASE WHEN tvf_join = 1 THEN ', Function Join' ELSE '' END + - CASE WHEN plan_multiple_plans = 1 THEN ', Multiple Plans' ELSE '' END + + CASE WHEN plan_multiple_plans > 0 THEN ', Multiple Plans' + COALESCE(' (' + CAST(plan_multiple_plans AS VARCHAR(10)) + ')', '') ELSE '' END + CASE WHEN is_trivial = 1 THEN ', Trivial Plans' ELSE '' END + CASE WHEN is_forced_serial = 1 THEN ', Forced Serialization' ELSE '' END + CASE WHEN is_key_lookup_expensive = 1 THEN ', Expensive Key Lookup' ELSE '' END + @@ -17064,7 +17770,7 @@ SELECT DISTINCT CASE WHEN downlevel_estimator = 1 THEN ', Downlevel CE' ELSE '' END + CASE WHEN implicit_conversions = 1 THEN ', Implicit Conversions' ELSE '' END + CASE WHEN tvf_join = 1 THEN ', Function Join' ELSE '' END + - CASE WHEN plan_multiple_plans = 1 THEN ', Multiple Plans' ELSE '' END + + CASE WHEN plan_multiple_plans > 0 THEN ', Multiple Plans' + COALESCE(' (' + CAST(plan_multiple_plans AS VARCHAR(10)) + ')', '') ELSE '' END + CASE WHEN is_trivial = 1 THEN ', Trivial Plans' ELSE '' END + CASE WHEN is_forced_serial = 1 THEN ', Forced Serialization' ELSE '' END + CASE WHEN is_key_lookup_expensive = 1 THEN ', Expensive Key Lookup' ELSE '' END + @@ -17155,198 +17861,7 @@ OPTION (RECOMPILE); Results: -IF @OutputDatabaseName IS NOT NULL - AND @OutputSchemaName IS NOT NULL - AND @OutputTableName IS NOT NULL -BEGIN - RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT; - - /* send results to a table */ - DECLARE @insert_sql NVARCHAR(MAX) = N'' ; - - SET @insert_sql = 'USE ' - + @OutputDatabaseName - + '; IF EXISTS(SELECT * FROM ' - + @OutputDatabaseName - + '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' - + @OutputSchemaName - + ''') AND NOT EXISTS (SELECT * FROM ' - + @OutputDatabaseName - + '.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = ''' - + @OutputSchemaName + ''' AND QUOTENAME(TABLE_NAME) = ''' - + @OutputTableName + ''') CREATE TABLE ' - + @OutputSchemaName + '.' - + @OutputTableName - + N'(ID bigint NOT NULL IDENTITY(1,1), - ServerName NVARCHAR(258), - CheckDate DATETIMEOFFSET, - Version NVARCHAR(258), - QueryType NVARCHAR(258), - Warnings varchar(max), - DatabaseName sysname, - SerialDesiredMemory float, - SerialRequiredMemory float, - AverageCPU bigint, - TotalCPU bigint, - PercentCPUByType money, - CPUWeight money, - AverageDuration bigint, - TotalDuration bigint, - DurationWeight money, - PercentDurationByType money, - AverageReads bigint, - TotalReads bigint, - ReadWeight money, - PercentReadsByType money, - AverageWrites bigint, - TotalWrites bigint, - WriteWeight money, - PercentWritesByType money, - ExecutionCount bigint, - ExecutionWeight money, - PercentExecutionsByType money,' + N' - ExecutionsPerMinute money, - PlanCreationTime datetime, - PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()), - LastExecutionTime datetime, - PlanHandle varbinary(64), - [Remove Plan Handle From Cache] AS - CASE WHEN [PlanHandle] IS NOT NULL - THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');'' - ELSE ''N/A'' END, - SqlHandle varbinary(64), - [Remove SQL Handle From Cache] AS - CASE WHEN [SqlHandle] IS NOT NULL - THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');'' - ELSE ''N/A'' END, - [SQL Handle More Info] AS - CASE WHEN [SqlHandle] IS NOT NULL - THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; '' - ELSE ''N/A'' END, - QueryHash binary(8), - [Query Hash More Info] AS - CASE WHEN [QueryHash] IS NOT NULL - THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; '' - ELSE ''N/A'' END, - QueryPlanHash binary(8), - StatementStartOffset int, - StatementEndOffset int, - MinReturnedRows bigint, - MaxReturnedRows bigint, - AverageReturnedRows money, - TotalReturnedRows bigint, - QueryText nvarchar(max), - QueryPlan xml, - NumberOfPlans int, - NumberOfDistinctPlans int, - MinGrantKB BIGINT, - MaxGrantKB BIGINT, - MinUsedGrantKB BIGINT, - MaxUsedGrantKB BIGINT, - PercentMemoryGrantUsed MONEY, - AvgMaxMemoryGrant MONEY, - MinSpills BIGINT, - MaxSpills BIGINT, - TotalSpills BIGINT, - AvgSpills MONEY, - QueryPlanCost FLOAT, - CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))'; - - IF @Debug = 1 - BEGIN - PRINT SUBSTRING(@insert_sql, 0, 4000); - PRINT SUBSTRING(@insert_sql, 4000, 8000); - PRINT SUBSTRING(@insert_sql, 8000, 12000); - PRINT SUBSTRING(@insert_sql, 12000, 16000); - PRINT SUBSTRING(@insert_sql, 16000, 20000); - PRINT SUBSTRING(@insert_sql, 20000, 24000); - PRINT SUBSTRING(@insert_sql, 24000, 28000); - PRINT SUBSTRING(@insert_sql, 28000, 32000); - PRINT SUBSTRING(@insert_sql, 32000, 36000); - PRINT SUBSTRING(@insert_sql, 36000, 40000); - END; - - EXEC sp_executesql @insert_sql ; - - IF @CheckDateOverride IS NULL - BEGIN - SET @CheckDateOverride = SYSDATETIMEOFFSET(); - END; - - - SET @insert_sql = N' IF EXISTS(SELECT * FROM ' - + @OutputDatabaseName - + N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' - + @OutputSchemaName + N''') ' - + N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;' - + 'INSERT ' - + @OutputDatabaseName + '.' - + @OutputSchemaName + '.' - + @OutputTableName - + N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' - + N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' - + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' - + N'SELECT TOP (@Top) ' - + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', @CheckDateOverride, ' - + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', ' - + N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' - + N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' - + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' - + N' FROM ##BlitzCacheProcs ' - + N' WHERE 1=1 '; - - IF @MinimumExecutionCount IS NOT NULL - BEGIN - SET @insert_sql += N' AND ExecutionCount >= @MinimumExecutionCount '; - END; - - IF @MinutesBack IS NOT NULL - BEGIN - SET @insert_sql += N' AND LastExecutionTime >= DATEADD(MINUTE, @min_back, GETDATE() ) '; - END; - - SET @insert_sql += N' AND SPID = @@SPID '; - - SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU ' - WHEN N'reads' THEN N' TotalReads ' - WHEN N'writes' THEN N' TotalWrites ' - WHEN N'duration' THEN N' TotalDuration ' - WHEN N'executions' THEN N' ExecutionCount ' - WHEN N'compiles' THEN N' PlanCreationTime ' - WHEN N'memory grant' THEN N' MaxGrantKB' - WHEN N'spills' THEN N' MaxSpills' - WHEN N'avg cpu' THEN N' AverageCPU' - WHEN N'avg reads' THEN N' AverageReads' - WHEN N'avg writes' THEN N' AverageWrites' - WHEN N'avg duration' THEN N' AverageDuration' - WHEN N'avg executions' THEN N' ExecutionsPerMinute' - WHEN N'avg memory grant' THEN N' AvgMaxMemoryGrant' - WHEN 'avg spills' THEN N' AvgSpills' - END + N' DESC '; - - SET @insert_sql += N' OPTION (RECOMPILE) ; '; - - IF @Debug = 1 - BEGIN - PRINT SUBSTRING(@insert_sql, 0, 4000); - PRINT SUBSTRING(@insert_sql, 4000, 8000); - PRINT SUBSTRING(@insert_sql, 8000, 12000); - PRINT SUBSTRING(@insert_sql, 12000, 16000); - PRINT SUBSTRING(@insert_sql, 16000, 20000); - PRINT SUBSTRING(@insert_sql, 20000, 24000); - PRINT SUBSTRING(@insert_sql, 24000, 28000); - PRINT SUBSTRING(@insert_sql, 28000, 32000); - PRINT SUBSTRING(@insert_sql, 32000, 36000); - PRINT SUBSTRING(@insert_sql, 36000, 40000); - END; - - EXEC sp_executesql @insert_sql, N'@Top INT, @min_duration INT, @min_back INT, @CheckDateOverride DATETIMEOFFSET, @MinimumExecutionCount INT', @Top, @DurationFilter_i, @MinutesBack, @CheckDateOverride, @MinimumExecutionCount; - - RETURN; -END; -ELSE IF @ExportToExcel = 1 +IF @ExportToExcel = 1 BEGIN RAISERROR('Displaying results with Excel formatting (no plans).', 0, 1) WITH NOWAIT; @@ -17477,31 +17992,31 @@ BEGIN missing_indexes AS [Missing Indexes], implicit_conversion_info AS [Implicit Conversion Info], cached_execution_parameters AS [Cached Execution Parameters], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS MONEY), 1), N''.00'', N'''') AS [# Executions], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS MONEY), 1), N''.00'', N'''') AS [Executions / Minute], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS MONEY), 1), N''.00'', N'''') AS [Execution Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalCPU) AS MONEY), 1), N''.00'', N'''') AS [Total CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageCPU) AS MONEY), 1), N''.00'', N'''') AS [Avg CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPU) AS MONEY), 1), N''.00'', N'''') AS [CPU Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalDuration) AS MONEY), 1), N''.00'', N'''') AS [Total Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageDuration) AS MONEY), 1), N''.00'', N'''') AS [Avg Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDuration) AS MONEY), 1), N''.00'', N'''') AS [Duration Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReads) AS MONEY), 1), N''.00'', N'''') AS [Total Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReads) AS MONEY), 1), N''.00'', N'''') AS [Avg Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReads) AS MONEY), 1), N''.00'', N'''') AS [Read Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalWrites) AS MONEY), 1), N''.00'', N'''') AS [Total Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageWrites) AS MONEY), 1), N''.00'', N'''') AS [Avg Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWrites) AS MONEY), 1), N''.00'', N'''') AS [Write Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Average Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS MONEY), 1), N''.00'', N'''') AS [Average Max Memory Grant], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinSpills) AS MONEY), 1), N''.00'', N'''') AS [Min Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxSpills) AS MONEY), 1), N''.00'', N'''') AS [Max Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalSpills) AS MONEY), 1), N''.00'', N'''') AS [Total Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1), N''.00'', N'''') AS [Avg Spills], + CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS BIGINT), 1) AS [# Executions], + CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS BIGINT), 1) AS [Executions / Minute], + CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS BIGINT), 1) AS [Execution Weight], + CONVERT(NVARCHAR(30), CAST((TotalCPU) AS BIGINT), 1) AS [Total CPU (ms)], + CONVERT(NVARCHAR(30), CAST((AverageCPU) AS BIGINT), 1) AS [Avg CPU (ms)], + CONVERT(NVARCHAR(30), CAST((PercentCPU) AS BIGINT), 1) AS [CPU Weight], + CONVERT(NVARCHAR(30), CAST((TotalDuration) AS BIGINT), 1) AS [Total Duration (ms)], + CONVERT(NVARCHAR(30), CAST((AverageDuration) AS BIGINT), 1) AS [Avg Duration (ms)], + CONVERT(NVARCHAR(30), CAST((PercentDuration) AS BIGINT), 1) AS [Duration Weight], + CONVERT(NVARCHAR(30), CAST((TotalReads) AS BIGINT), 1) AS [Total Reads], + CONVERT(NVARCHAR(30), CAST((AverageReads) AS BIGINT), 1) AS [Avg Reads], + CONVERT(NVARCHAR(30), CAST((PercentReads) AS BIGINT), 1) AS [Read Weight], + CONVERT(NVARCHAR(30), CAST((TotalWrites) AS BIGINT), 1) AS [Total Writes], + CONVERT(NVARCHAR(30), CAST((AverageWrites) AS BIGINT), 1) AS [Avg Writes], + CONVERT(NVARCHAR(30), CAST((PercentWrites) AS BIGINT), 1) AS [Write Weight], + CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS BIGINT), 1) AS [Average Rows], + CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS BIGINT), 1) AS [Minimum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS BIGINT), 1) AS [Maximum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS BIGINT), 1) AS [Minimum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS BIGINT), 1) AS [Maximum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS BIGINT), 1) AS [Average Max Memory Grant], + CONVERT(NVARCHAR(30), CAST((MinSpills) AS BIGINT), 1) AS [Min Spills], + CONVERT(NVARCHAR(30), CAST((MaxSpills) AS BIGINT), 1) AS [Max Spills], + CONVERT(NVARCHAR(30), CAST((TotalSpills) AS BIGINT), 1) AS [Total Spills], + CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1) AS [Avg Spills], PlanCreationTime AS [Created At], LastExecutionTime AS [Last Execution], PlanHandle AS [Plan Handle], @@ -17544,7 +18059,7 @@ BEGIN CASE WHEN downlevel_estimator = 1 THEN '', 13'' ELSE '''' END + CASE WHEN implicit_conversions = 1 THEN '', 14'' ELSE '''' END + CASE WHEN tvf_join = 1 THEN '', 17'' ELSE '''' END + - CASE WHEN plan_multiple_plans = 1 THEN '', 21'' ELSE '''' END + + CASE WHEN plan_multiple_plans > 0 THEN '', 21'' ELSE '''' END + CASE WHEN unmatched_index_count > 0 THEN '', 22'' ELSE '''' END + CASE WHEN is_trivial = 1 THEN '', 24'' ELSE '''' END + CASE WHEN is_forced_serial = 1 THEN '', 25'' ELSE '''' END + @@ -17591,49 +18106,49 @@ BEGIN END; SET @columns += N' - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS MONEY), 1), N''.00'', N'''') AS [# Executions], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS MONEY), 1), N''.00'', N'''') AS [Executions / Minute], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS MONEY), 1), N''.00'', N'''') AS [Execution Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((SerialDesiredMemory) AS MONEY), 1), N''.00'', N'''') AS [Serial Desired Memory], - REPLACE(CONVERT(NVARCHAR(30), CAST((SerialRequiredMemory) AS MONEY), 1), N''.00'', N'''') AS [Serial Required Memory], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalCPU) AS MONEY), 1), N''.00'', N'''') AS [Total CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageCPU) AS MONEY), 1), N''.00'', N'''') AS [Avg CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPU) AS MONEY), 1), N''.00'', N'''') AS [CPU Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalDuration) AS MONEY), 1), N''.00'', N'''') AS [Total Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageDuration) AS MONEY), 1), N''.00'', N'''') AS [Avg Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDuration) AS MONEY), 1), N''.00'', N'''') AS [Duration Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReads) AS MONEY), 1), N''.00'', N'''') AS [Total Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReads) AS MONEY), 1), N''.00'', N'''') AS [Average Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReads) AS MONEY), 1), N''.00'', N'''') AS [Read Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalWrites) AS MONEY), 1), N''.00'', N'''') AS [Total Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageWrites) AS MONEY), 1), N''.00'', N'''') AS [Average Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWrites) AS MONEY), 1), N''.00'', N'''') AS [Write Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutionsByType) AS MONEY), 1), N''.00'', N'''') AS [% Executions (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPUByType) AS MONEY), 1), N''.00'', N'''') AS [% CPU (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDurationByType) AS MONEY), 1), N''.00'', N'''') AS [% Duration (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReadsByType) AS MONEY), 1), N''.00'', N'''') AS [% Reads (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWritesByType) AS MONEY), 1), N''.00'', N'''') AS [% Writes (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Total Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Avg Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Min Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Max Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS MONEY), 1), N''.00'', N'''') AS [Average Max Memory Grant], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinSpills) AS MONEY), 1), N''.00'', N'''') AS [Min Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxSpills) AS MONEY), 1), N''.00'', N'''') AS [Max Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalSpills) AS MONEY), 1), N''.00'', N'''') AS [Total Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1), N''.00'', N'''') AS [Avg Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((NumberOfPlans) AS MONEY), 1), N''.00'', N'''') AS [# Plans], - REPLACE(CONVERT(NVARCHAR(30), CAST((NumberOfDistinctPlans) AS MONEY), 1), N''.00'', N'''') AS [# Distinct Plans], + CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS BIGINT), 1) AS [# Executions], + CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS BIGINT), 1) AS [Executions / Minute], + CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS BIGINT), 1) AS [Execution Weight], + CONVERT(NVARCHAR(30), CAST((SerialDesiredMemory) AS BIGINT), 1) AS [Serial Desired Memory], + CONVERT(NVARCHAR(30), CAST((SerialRequiredMemory) AS BIGINT), 1) AS [Serial Required Memory], + CONVERT(NVARCHAR(30), CAST((TotalCPU) AS BIGINT), 1) AS [Total CPU (ms)], + CONVERT(NVARCHAR(30), CAST((AverageCPU) AS BIGINT), 1) AS [Avg CPU (ms)], + CONVERT(NVARCHAR(30), CAST((PercentCPU) AS BIGINT), 1) AS [CPU Weight], + CONVERT(NVARCHAR(30), CAST((TotalDuration) AS BIGINT), 1) AS [Total Duration (ms)], + CONVERT(NVARCHAR(30), CAST((AverageDuration) AS BIGINT), 1) AS [Avg Duration (ms)], + CONVERT(NVARCHAR(30), CAST((PercentDuration) AS BIGINT), 1) AS [Duration Weight], + CONVERT(NVARCHAR(30), CAST((TotalReads) AS BIGINT), 1) AS [Total Reads], + CONVERT(NVARCHAR(30), CAST((AverageReads) AS BIGINT), 1) AS [Average Reads], + CONVERT(NVARCHAR(30), CAST((PercentReads) AS BIGINT), 1) AS [Read Weight], + CONVERT(NVARCHAR(30), CAST((TotalWrites) AS BIGINT), 1) AS [Total Writes], + CONVERT(NVARCHAR(30), CAST((AverageWrites) AS BIGINT), 1) AS [Average Writes], + CONVERT(NVARCHAR(30), CAST((PercentWrites) AS BIGINT), 1) AS [Write Weight], + CONVERT(NVARCHAR(30), CAST((PercentExecutionsByType) AS BIGINT), 1) AS [% Executions (Type)], + CONVERT(NVARCHAR(30), CAST((PercentCPUByType) AS BIGINT), 1) AS [% CPU (Type)], + CONVERT(NVARCHAR(30), CAST((PercentDurationByType) AS BIGINT), 1) AS [% Duration (Type)], + CONVERT(NVARCHAR(30), CAST((PercentReadsByType) AS BIGINT), 1) AS [% Reads (Type)], + CONVERT(NVARCHAR(30), CAST((PercentWritesByType) AS BIGINT), 1) AS [% Writes (Type)], + CONVERT(NVARCHAR(30), CAST((TotalReturnedRows) AS BIGINT), 1) AS [Total Rows], + CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS BIGINT), 1) AS [Avg Rows], + CONVERT(NVARCHAR(30), CAST((MinReturnedRows) AS BIGINT), 1) AS [Min Rows], + CONVERT(NVARCHAR(30), CAST((MaxReturnedRows) AS BIGINT), 1) AS [Max Rows], + CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS BIGINT), 1) AS [Minimum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS BIGINT), 1) AS [Maximum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS BIGINT), 1) AS [Minimum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS BIGINT), 1) AS [Maximum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS BIGINT), 1) AS [Average Max Memory Grant], + CONVERT(NVARCHAR(30), CAST((MinSpills) AS BIGINT), 1) AS [Min Spills], + CONVERT(NVARCHAR(30), CAST((MaxSpills) AS BIGINT), 1) AS [Max Spills], + CONVERT(NVARCHAR(30), CAST((TotalSpills) AS BIGINT), 1) AS [Total Spills], + CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1) AS [Avg Spills], + CONVERT(NVARCHAR(30), CAST((NumberOfPlans) AS BIGINT), 1) AS [# Plans], + CONVERT(NVARCHAR(30), CAST((NumberOfDistinctPlans) AS BIGINT), 1) AS [# Distinct Plans], PlanCreationTime AS [Created At], LastExecutionTime AS [Last Execution], - REPLACE(CONVERT(NVARCHAR(30), CAST((CachedPlanSize) AS MONEY), 1), N''.00'', N'''') AS [Cached Plan Size (KB)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileTime) AS MONEY), 1), N''.00'', N'''') AS [Compile Time (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileCPU) AS MONEY), 1), N''.00'', N'''') AS [Compile CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileMemory) AS MONEY), 1), N''.00'', N'''') AS [Compile memory (KB)], + CONVERT(NVARCHAR(30), CAST((CachedPlanSize) AS BIGINT), 1) AS [Cached Plan Size (KB)], + CONVERT(NVARCHAR(30), CAST((CompileTime) AS BIGINT), 1) AS [Compile Time (ms)], + CONVERT(NVARCHAR(30), CAST((CompileCPU) AS BIGINT), 1) AS [Compile CPU (ms)], + CONVERT(NVARCHAR(30), CAST((CompileMemory) AS BIGINT), 1) AS [Compile memory (KB)], COALESCE(SetOptions, '''') AS [SET Options], PlanHandle AS [Plan Handle], SqlHandle AS [SQL Handle], @@ -17990,7 +18505,7 @@ BEGIN IF EXISTS (SELECT 1/0 FROM ##BlitzCacheProcs - WHERE plan_multiple_plans = 1 + WHERE plan_multiple_plans > 0 AND SPID = @@SPID) INSERT INTO ##BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL, Details) VALUES (@@SPID, @@ -18761,7 +19276,10 @@ IF @Debug = 1 END; - + IF @OutputDatabaseName IS NOT NULL + AND @OutputSchemaName IS NOT NULL + AND @OutputTableName IS NOT NULL + GOTO OutputResultsToTable; RETURN; --Avoid going into the AllSort GOTO /*Begin code to sort by all*/ @@ -18856,29 +19374,6 @@ IF OBJECT_ID('tempdb.. #bou_allsort') IS NULL ); END; -DECLARE @AllSortSql NVARCHAR(MAX) = N''; -DECLARE @MemGrant BIT; -SELECT @MemGrant = CASE WHEN ( - ( @v < 11 ) - OR ( - @v = 11 - AND @build < 6020 - ) - OR ( - @v = 12 - AND @build < 5000 - ) - OR ( - @v = 13 - AND @build < 1601 - ) - ) THEN 0 - ELSE 1 - END; - -DECLARE @Spills BIT; -SELECT @Spills = CASE WHEN (@v >= 15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026)) THEN 1 ELSE 0 END; - IF LOWER(@SortOrder) = 'all' BEGIN @@ -18891,7 +19386,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''cpu'', @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''cpu'', @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''cpu'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -18902,7 +19397,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''reads'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -18913,7 +19408,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''writes'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -18924,7 +19419,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''duration'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -18935,13 +19430,13 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''executions'' WHERE Pattern IS NULL OPTION(RECOMPILE); '; - IF @MemGrant = 0 + IF @VersionShowsMemoryGrants = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -18960,7 +19455,7 @@ SET @AllSortSql += N' END; - IF @MemGrant = 1 + IF @VersionShowsMemoryGrants = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -18969,7 +19464,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -18989,7 +19484,7 @@ SET @AllSortSql += N' END; - IF @Spills = 0 + IF @VersionShowsSpills = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -19008,7 +19503,7 @@ SET @AllSortSql += N' END; - IF @Spills = 1 + IF @VersionShowsSpills = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -19017,7 +19512,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -19059,7 +19554,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg cpu'', @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg cpu'', @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg cpu'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -19070,7 +19565,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg reads'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -19081,7 +19576,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg writes'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -19092,7 +19587,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg duration'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -19103,13 +19598,13 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg executions'' WHERE Pattern IS NULL OPTION(RECOMPILE); '; - IF @MemGrant = 0 + IF @VersionShowsMemoryGrants = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -19128,7 +19623,7 @@ SET @AllSortSql += N' END; - IF @MemGrant = 1 + IF @VersionShowsMemoryGrants = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -19137,7 +19632,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -19157,7 +19652,7 @@ SET @AllSortSql += N' END; - IF @Spills = 0 + IF @VersionShowsSpills = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -19176,7 +19671,7 @@ SET @AllSortSql += N' END; - IF @Spills = 1 + IF @VersionShowsSpills = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -19185,7 +19680,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -19228,11 +19723,209 @@ END; PRINT SUBSTRING(@AllSortSql, 36000, 40000); END; - EXEC sys.sp_executesql @stmt = @AllSortSql, @params = N'@i_DatabaseName NVARCHAR(128), @i_Top INT', @i_DatabaseName = @DatabaseName, @i_Top = @Top; + EXEC sys.sp_executesql @stmt = @AllSortSql, @params = N'@i_DatabaseName NVARCHAR(128), @i_Top INT, @i_SkipAnalysis BIT, @i_OutputDatabaseName NVARCHAR(258), @i_OutputSchemaName NVARCHAR(258), @i_OutputTableName NVARCHAR(258)', + @i_DatabaseName = @DatabaseName, @i_Top = @Top, @i_SkipAnalysis = @SkipAnalysis, @i_OutputDatabaseName = @OutputDatabaseName, @i_OutputSchemaName = @OutputSchemaName, @i_OutputTableName = @OutputTableName; /*End of AllSort section*/ +/*Begin code to sort by all*/ +OutputResultsToTable: + +IF @OutputDatabaseName IS NOT NULL + AND @OutputSchemaName IS NOT NULL + AND @OutputTableName IS NOT NULL +BEGIN + RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT; + + SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName), + @OutputSchemaName = QUOTENAME(@OutputSchemaName), + @OutputTableName = QUOTENAME(@OutputTableName); + + /* send results to a table */ + DECLARE @insert_sql NVARCHAR(MAX) = N'' ; + + SET @insert_sql = 'USE ' + + @OutputDatabaseName + + '; IF EXISTS(SELECT * FROM ' + + @OutputDatabaseName + + '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' + + @OutputSchemaName + + ''') AND NOT EXISTS (SELECT * FROM ' + + @OutputDatabaseName + + '.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = ''' + + @OutputSchemaName + ''' AND QUOTENAME(TABLE_NAME) = ''' + + @OutputTableName + ''') CREATE TABLE ' + + @OutputSchemaName + '.' + + @OutputTableName + + N'(ID bigint NOT NULL IDENTITY(1,1), + ServerName NVARCHAR(258), + CheckDate DATETIMEOFFSET, + Version NVARCHAR(258), + QueryType NVARCHAR(258), + Warnings varchar(max), + DatabaseName sysname, + SerialDesiredMemory float, + SerialRequiredMemory float, + AverageCPU bigint, + TotalCPU bigint, + PercentCPUByType money, + CPUWeight money, + AverageDuration bigint, + TotalDuration bigint, + DurationWeight money, + PercentDurationByType money, + AverageReads bigint, + TotalReads bigint, + ReadWeight money, + PercentReadsByType money, + AverageWrites bigint, + TotalWrites bigint, + WriteWeight money, + PercentWritesByType money, + ExecutionCount bigint, + ExecutionWeight money, + PercentExecutionsByType money,' + N' + ExecutionsPerMinute money, + PlanCreationTime datetime, + PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()), + LastExecutionTime datetime, + PlanHandle varbinary(64), + [Remove Plan Handle From Cache] AS + CASE WHEN [PlanHandle] IS NOT NULL + THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');'' + ELSE ''N/A'' END, + SqlHandle varbinary(64), + [Remove SQL Handle From Cache] AS + CASE WHEN [SqlHandle] IS NOT NULL + THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');'' + ELSE ''N/A'' END, + [SQL Handle More Info] AS + CASE WHEN [SqlHandle] IS NOT NULL + THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; '' + ELSE ''N/A'' END, + QueryHash binary(8), + [Query Hash More Info] AS + CASE WHEN [QueryHash] IS NOT NULL + THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; '' + ELSE ''N/A'' END, + QueryPlanHash binary(8), + StatementStartOffset int, + StatementEndOffset int, + MinReturnedRows bigint, + MaxReturnedRows bigint, + AverageReturnedRows money, + TotalReturnedRows bigint, + QueryText nvarchar(max), + QueryPlan xml, + NumberOfPlans int, + NumberOfDistinctPlans int, + MinGrantKB BIGINT, + MaxGrantKB BIGINT, + MinUsedGrantKB BIGINT, + MaxUsedGrantKB BIGINT, + PercentMemoryGrantUsed MONEY, + AvgMaxMemoryGrant MONEY, + MinSpills BIGINT, + MaxSpills BIGINT, + TotalSpills BIGINT, + AvgSpills MONEY, + QueryPlanCost FLOAT, + CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))'; + + IF @Debug = 1 + BEGIN + PRINT SUBSTRING(@insert_sql, 0, 4000); + PRINT SUBSTRING(@insert_sql, 4000, 8000); + PRINT SUBSTRING(@insert_sql, 8000, 12000); + PRINT SUBSTRING(@insert_sql, 12000, 16000); + PRINT SUBSTRING(@insert_sql, 16000, 20000); + PRINT SUBSTRING(@insert_sql, 20000, 24000); + PRINT SUBSTRING(@insert_sql, 24000, 28000); + PRINT SUBSTRING(@insert_sql, 28000, 32000); + PRINT SUBSTRING(@insert_sql, 32000, 36000); + PRINT SUBSTRING(@insert_sql, 36000, 40000); + END; + + EXEC sp_executesql @insert_sql ; + + IF @CheckDateOverride IS NULL + BEGIN + SET @CheckDateOverride = SYSDATETIMEOFFSET(); + END; + + + SET @insert_sql = N' IF EXISTS(SELECT * FROM ' + + @OutputDatabaseName + + N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' + + @OutputSchemaName + N''') ' + + N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;' + + 'INSERT ' + + @OutputDatabaseName + '.' + + @OutputSchemaName + '.' + + @OutputTableName + + N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + + N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' + + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + N'SELECT TOP (@Top) ' + + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', @CheckDateOverride, ' + + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', ' + + N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + + N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' + + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + N' FROM ##BlitzCacheProcs ' + + N' WHERE 1=1 '; + + IF @MinimumExecutionCount IS NOT NULL + BEGIN + SET @insert_sql += N' AND ExecutionCount >= @MinimumExecutionCount '; + END; + + IF @MinutesBack IS NOT NULL + BEGIN + SET @insert_sql += N' AND LastExecutionTime >= DATEADD(MINUTE, @min_back, GETDATE() ) '; + END; + + SET @insert_sql += N' AND SPID = @@SPID '; + + SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU ' + WHEN N'reads' THEN N' TotalReads ' + WHEN N'writes' THEN N' TotalWrites ' + WHEN N'duration' THEN N' TotalDuration ' + WHEN N'executions' THEN N' ExecutionCount ' + WHEN N'compiles' THEN N' PlanCreationTime ' + WHEN N'memory grant' THEN N' MaxGrantKB' + WHEN N'spills' THEN N' MaxSpills' + WHEN N'avg cpu' THEN N' AverageCPU' + WHEN N'avg reads' THEN N' AverageReads' + WHEN N'avg writes' THEN N' AverageWrites' + WHEN N'avg duration' THEN N' AverageDuration' + WHEN N'avg executions' THEN N' ExecutionsPerMinute' + WHEN N'avg memory grant' THEN N' AvgMaxMemoryGrant' + WHEN 'avg spills' THEN N' AvgSpills' + END + N' DESC '; + + SET @insert_sql += N' OPTION (RECOMPILE) ; '; + + IF @Debug = 1 + BEGIN + PRINT SUBSTRING(@insert_sql, 0, 4000); + PRINT SUBSTRING(@insert_sql, 4000, 8000); + PRINT SUBSTRING(@insert_sql, 8000, 12000); + PRINT SUBSTRING(@insert_sql, 12000, 16000); + PRINT SUBSTRING(@insert_sql, 16000, 20000); + PRINT SUBSTRING(@insert_sql, 20000, 24000); + PRINT SUBSTRING(@insert_sql, 24000, 28000); + PRINT SUBSTRING(@insert_sql, 28000, 32000); + PRINT SUBSTRING(@insert_sql, 32000, 36000); + PRINT SUBSTRING(@insert_sql, 36000, 40000); + END; + + EXEC sp_executesql @insert_sql, N'@Top INT, @min_duration INT, @min_back INT, @CheckDateOverride DATETIMEOFFSET, @MinimumExecutionCount INT', @Top, @DurationFilter_i, @MinutesBack, @CheckDateOverride, @MinimumExecutionCount; +END; /* End of writing results to table */ + END; /*Final End*/ GO @@ -19280,7 +19973,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -19366,7 +20059,6 @@ DECLARE @StringToExecute NVARCHAR(MAX), @ObjectFullName NVARCHAR(2000), @BlitzWho NVARCHAR(MAX) = N'EXEC dbo.sp_BlitzWho @ShowSleepingSPIDs = ' + CONVERT(NVARCHAR(1), @ShowSleepingSPIDs) + N';', @BlitzCacheMinutesBack INT, - @BlitzCacheSortOrder VARCHAR(50), @UnquotedOutputServerName NVARCHAR(256) = @OutputServerName , @UnquotedOutputDatabaseName NVARCHAR(256) = @OutputDatabaseName , @UnquotedOutputSchemaName NVARCHAR(256) = @OutputSchemaName ; @@ -20523,8 +21215,9 @@ BEGIN 'Maintenance Tasks Running' AS FindingGroup, 'Backup Running' AS Finding, 'http://www.BrentOzar.com/askbrent/backups/' AS URL, - 'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) is ' + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' - + CASE WHEN COALESCE(s.nt_user_name, s.login_name) IS NOT NULL THEN (' Login: ' + COALESCE(s.nt_user_name, s.login_name) + ' ') ELSE '' END AS Details, + 'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) ' + @LineFeed + + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' + @LineFeed + + CASE WHEN COALESCE(s.nt_user_name, s.login_name) IS NOT NULL THEN (' Login: ' + COALESCE(s.nt_user_name, s.login_name) + ' ') ELSE '' END AS Details, 'KILL ' + CAST(r.session_id AS NVARCHAR(100)) + ';' AS HowToStopIt, pl.query_plan AS QueryPlan, r.start_time AS StartTime, @@ -20662,9 +21355,9 @@ BEGIN ''Long-Running Query Blocking Others'' AS Finding, ''http://www.BrentOzar.com/go/blocking'' AS URL, ''Query in '' + COALESCE(DB_NAME(COALESCE((SELECT TOP 1 dbid FROM sys.dm_exec_sql_text(r.sql_handle)), - (SELECT TOP 1 t.dbid FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) t WHERE spBlocker.spid = tBlocked.blocking_session_id))), ''(Unknown)'') + '' has a last request start time of '' + CAST(s.last_request_start_time AS NVARCHAR(100)) + ''. Query follows:'' ' + (SELECT TOP 1 t.dbid FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) t WHERE spBlocker.spid = tBlocked.blocking_session_id))), ''(Unknown)'') + '' has a last request start time of '' + CAST(s.last_request_start_time AS NVARCHAR(100)) + ''. Query follows: ' + @LineFeed + @LineFeed + - '+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(r.sql_handle)), + '''+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(r.sql_handle)), (SELECT TOP 1 [text] FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) WHERE spBlocker.spid = tBlocked.blocking_session_id), '''') AS NVARCHAR(2000)) AS Details, ''KILL '' + CAST(tBlocked.blocking_session_id AS NVARCHAR(100)) + '';'' AS HowToStopIt, (SELECT TOP 1 query_plan FROM sys.dm_exec_query_plan(r.plan_handle)) AS QueryPlan, @@ -20682,7 +21375,9 @@ BEGIN INNER JOIN sys.dm_exec_sessions s ON tBlocked.blocking_session_id = s.session_id LEFT OUTER JOIN sys.dm_exec_requests r ON s.session_id = r.session_id INNER JOIN sys.dm_exec_connections c ON s.session_id = c.session_id - WHERE tBlocked.wait_type LIKE ''LCK%'' AND tBlocked.wait_duration_ms > 30000;'; + WHERE tBlocked.wait_type LIKE ''LCK%'' AND tBlocked.wait_duration_ms > 30000 + /* And the blocking session ID is not blocked by anyone else: */ + AND NOT EXISTS(SELECT * FROM sys.dm_os_waiting_tasks tBlocking WHERE s.session_id = tBlocking.session_id AND tBlocking.session_id <> tBlocking.blocking_session_id AND tBlocking.blocking_session_id IS NOT NULL);'; EXECUTE sp_executesql @StringToExecute; END; @@ -20750,17 +21445,18 @@ BEGIN SET @StringToExecute = N'INSERT INTO #BlitzFirstResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, QueryText, OpenTransactionCount) SELECT 37 AS CheckId, 50 AS Priority, - ''Implicit Transactions'' AS FindingsGroup, - ''Queries were found running using implicit transactions'', + ''Query Problems'' AS FindingsGroup, + ''Implicit Transactions'', ''https://www.brentozar.com/go/ImplicitTransactions/'' AS URL, - ''Database: '' + DB_NAME(s.database_id) + '' '' + - ''Host: '' + s.[host_name] + '' '' + - ''Program: '' + s.[program_name] + '' '' + + ''Database: '' + DB_NAME(s.database_id) + '' '' + CHAR(13) + CHAR(10) + + ''Host: '' + s.[host_name] + '' '' + CHAR(13) + CHAR(10) + + ''Program: '' + s.[program_name] + '' '' + CHAR(13) + CHAR(10) + CONVERT(NVARCHAR(10), s.open_transaction_count) + '' open transactions since: '' + CONVERT(NVARCHAR(30), tat.transaction_begin_time) + ''. '' AS Details, - ''Check client configuration options'' AS HowToStopit, + ''Run sp_BlitzWho and check the is_implicit_transaction column to spot the culprits. +If one of them is a lead blocker, consider killing that query.'' AS HowToStopit, tat.transaction_begin_time, s.login_name, s.nt_user_name, @@ -21978,55 +22674,6 @@ BEGIN RAISERROR('Calling sp_BlitzCache',10,1) WITH NOWAIT; - /* Set the sp_BlitzCache sort order based on their top wait type */ - - /* First, check for poison waits - CheckID 30 */ - IF EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 30) - BEGIN - SELECT TOP 1 @BlitzCacheSortOrder = CASE - WHEN Finding = 'Poison Wait Detected: RESOURCE_SEMAPHORE' AND @memGrantSortSupported = 1 THEN 'memory grant' - WHEN Finding = 'Poison Wait Detected: RESOURCE_SEMAPHORE_QUERY_COMPILE' AND @memGrantSortSupported = 1 THEN 'memory grant' - WHEN Finding = 'Poison Wait Detected: THREADPOOL' THEN 'executions' - WHEN Finding = 'Poison Wait Detected: LOG_RATE_GOVERNOR' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_CATCHUP_THROTTLE' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_COMMIT_ACK' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_ROLLBACK_ACK' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_SLOW_SECONDARY_THROTTLE' THEN 'writes' - ELSE NULL - END - FROM #BlitzFirstResults - WHERE CheckID = 30 - ORDER BY DetailsInt DESC; - END; - - /* Too much free memory - which probably indicates queries finished w/huge grants - CheckID 34 */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 34) AND @memGrantSortSupported = 1 - SET @BlitzCacheSortOrder = 'memory grant'; - - /* Next, Compilations/Sec High - CheckID 15 and 16 */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID IN (15,16)) - SET @BlitzCacheSortOrder = 'recent compilations'; - - /* Still not set? Use the top wait type. */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 6) - BEGIN - SELECT TOP 1 @BlitzCacheSortOrder = CASE - WHEN Finding = 'ASYNC_NETWORK_IO' THEN 'duration' - WHEN Finding = 'CXPACKET' THEN 'reads' - WHEN Finding = 'LATCH_EX' THEN 'reads' - WHEN Finding LIKE 'LCK%' THEN 'duration' - WHEN Finding LIKE 'PAGEIOLATCH%' THEN 'reads' - WHEN Finding = 'SOS_SCHEDULER_YIELD' THEN 'cpu' - WHEN Finding = 'WRITELOG' THEN 'writes' - ELSE NULL - END - FROM #BlitzFirstResults - WHERE CheckID = 6 - ORDER BY DetailsInt DESC; - END; - /* Still null? Just use the default. */ - - /* If they have an newer version of sp_BlitzCache that supports @MinutesBack and @CheckDateOverride */ IF EXISTS (SELECT * FROM sys.objects o @@ -22050,23 +22697,15 @@ BEGIN IF @BlitzCacheMinutesBack IS NULL OR @BlitzCacheMinutesBack < 1 OR @BlitzCacheMinutesBack > 60 SET @BlitzCacheMinutesBack = 15; - IF @BlitzCacheSortOrder IS NOT NULL - EXEC sp_BlitzCache - @OutputDatabaseName = @UnquotedOutputDatabaseName, - @OutputSchemaName = @UnquotedOutputSchemaName, - @OutputTableName = @OutputTableNameBlitzCache, - @CheckDateOverride = @StartSampleTime, - @SortOrder = @BlitzCacheSortOrder, - @MinutesBack = @BlitzCacheMinutesBack, - @Debug = @Debug; - ELSE - EXEC sp_BlitzCache - @OutputDatabaseName = @UnquotedOutputDatabaseName, - @OutputSchemaName = @UnquotedOutputSchemaName, - @OutputTableName = @OutputTableNameBlitzCache, - @CheckDateOverride = @StartSampleTime, - @MinutesBack = @BlitzCacheMinutesBack, - @Debug = @Debug; + EXEC sp_BlitzCache + @OutputDatabaseName = @UnquotedOutputDatabaseName, + @OutputSchemaName = @UnquotedOutputSchemaName, + @OutputTableName = @OutputTableNameBlitzCache, + @CheckDateOverride = @StartSampleTime, + @SortOrder = 'all', + @SkipAnalysis = 1, + @MinutesBack = @BlitzCacheMinutesBack, + @Debug = @Debug; /* Delete history older than @OutputTableRetentionDays */ SET @StringToExecute = N' IF EXISTS(SELECT * FROM ' @@ -23279,6 +23918,7 @@ ALTER PROCEDURE dbo.sp_BlitzIndex @SkipStatistics BIT = 1, @GetAllDatabases BIT = 0, @BringThePain BIT = 0, + @IgnoreDatabases NVARCHAR(MAX) = NULL, /* Comma-delimited list of databases you want to skip */ @ThresholdMB INT = 250 /* Number of megabytes that an object must be before we include it in basic results */, @OutputType VARCHAR(20) = 'TABLE' , @OutputServerName NVARCHAR(256) = NULL , @@ -23294,7 +23934,7 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -23374,12 +24014,14 @@ DECLARE @collation NVARCHAR(256); DECLARE @NumDatabases INT; DECLARE @LineFeed NVARCHAR(5); DECLARE @DaysUptimeInsertValue NVARCHAR(256); +DECLARE @DatabaseToIgnore NVARCHAR(MAX); SET @LineFeed = CHAR(13) + CHAR(10); SELECT @SQLServerProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)); SELECT @SQLServerEdition =CAST(SERVERPROPERTY('EngineEdition') AS INT); /* We default to online index creates where EngineEdition=3*/ SET @FilterMB=250; SELECT @ScriptVersionName = 'sp_BlitzIndex(TM) v' + @Version + ' - ' + DATENAME(MM, @VersionDate) + ' ' + RIGHT('0'+DATENAME(DD, @VersionDate),2) + ', ' + DATENAME(YY, @VersionDate); +SET @IgnoreDatabases = LTRIM(RTRIM(@IgnoreDatabases)); RAISERROR(N'Starting run. %s', 0,1, @ScriptVersionName) WITH NOWAIT; @@ -23458,6 +24100,9 @@ IF OBJECT_ID('tempdb..#CheckConstraints') IS NOT NULL IF OBJECT_ID('tempdb..#FilteredIndexes') IS NOT NULL DROP TABLE #FilteredIndexes; +IF OBJECT_ID('tempdb..#Ignore_Databases') IS NOT NULL + DROP TABLE #Ignore_Databases + RAISERROR (N'Create temp tables.',0,1) WITH NOWAIT; CREATE TABLE #BlitzIndexResults ( @@ -23940,6 +24585,12 @@ IF OBJECT_ID('tempdb..#FilteredIndexes') IS NOT NULL column_name NVARCHAR(128) NULL ); + CREATE TABLE #Ignore_Databases + ( + DatabaseName NVARCHAR(128), + Reason NVARCHAR(100) + ); + /* Sanitize our inputs */ SELECT @OutputServerName = QUOTENAME(@OutputServerName), @@ -23988,6 +24639,37 @@ IF @GetAllDatabases = 1 END; END; + IF @IgnoreDatabases IS NOT NULL + AND LEN(@IgnoreDatabases) > 0 + BEGIN + RAISERROR(N'Setting up filter to ignore databases', 0, 1) WITH NOWAIT; + SET @DatabaseToIgnore = ''; + + WHILE LEN(@IgnoreDatabases) > 0 + BEGIN + IF PATINDEX('%,%', @IgnoreDatabases) > 0 + BEGIN + SET @DatabaseToIgnore = SUBSTRING(@IgnoreDatabases, 0, PATINDEX('%,%',@IgnoreDatabases)) ; + + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseToIgnore, 'Specified in the @IgnoreDatabases parameter' + OPTION (RECOMPILE) ; + + SET @IgnoreDatabases = SUBSTRING(@IgnoreDatabases, LEN(@DatabaseToIgnore + ',') + 1, LEN(@IgnoreDatabases)) ; + END; + ELSE + BEGIN + SET @DatabaseToIgnore = @IgnoreDatabases ; + SET @IgnoreDatabases = NULL ; + + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseToIgnore, 'Specified in the @IgnoreDatabases parameter' + OPTION (RECOMPILE) ; + END; + END; + + END + END; ELSE BEGIN @@ -24073,16 +24755,72 @@ BEGIN CATCH RETURN; END CATCH; + +RAISERROR (N'Checking partition counts to exclude databases with over 100 partitions',0,1) WITH NOWAIT; +IF @BringThePain = 0 AND @SkipPartitions = 0 AND @TableName IS NULL + BEGIN + DECLARE partition_cursor CURSOR FOR + SELECT dl.DatabaseName + FROM #DatabaseList dl + LEFT OUTER JOIN #Ignore_Databases i ON dl.DatabaseName = i.DatabaseName + WHERE COALESCE(dl.secondary_role_allow_connections_desc, 'OK') <> 'NO' + AND i.DatabaseName IS NULL + + OPEN partition_cursor + FETCH NEXT FROM partition_cursor INTO @DatabaseName + + WHILE @@FETCH_STATUS = 0 + BEGIN + /* Count the total number of partitions */ + SET @dsql = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + SELECT @RowcountOUT = SUM(1) FROM ' + QUOTENAME(@DatabaseName) + '.sys.partitions WHERE partition_number > 1 OPTION ( RECOMPILE );'; + EXEC sp_executesql @dsql, N'@RowcountOUT BIGINT OUTPUT', @RowcountOUT = @Rowcount OUTPUT; + IF @Rowcount > 100 + BEGIN + RAISERROR (N'Skipping database %s because > 100 partitions were found. To check this database, you must set @BringThePain = 1.',0,1,@DatabaseName) WITH NOWAIT; + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseName, 'Over 100 partitions found - use @BringThePain = 1 to analyze' + END; + FETCH NEXT FROM partition_cursor INTO @DatabaseName + END; + CLOSE partition_cursor + DEALLOCATE partition_cursor + + END; + +INSERT #BlitzIndexResults ( Priority, check_id, findings_group, finding, URL, details, index_definition, + index_usage_summary, index_size_summary ) +SELECT 1, 0 , + 'Database Skipped', + i.DatabaseName, + 'http://FirstResponderKit.org', + i.Reason, '', '', '' +FROM #Ignore_Databases i; + + +/* 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 OR @DaysUptime IS NULL + SET @DaysUptime = .01; + +SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPERTY('ServerName')))) + ' Days Uptime: ' + RTRIM(@DaysUptime); + + /* Permission granted or unnecessary? Ok, let's go! */ +RAISERROR (N'Starting loop through databases',0,1) WITH NOWAIT; DECLARE c1 CURSOR LOCAL FAST_FORWARD FOR -SELECT DatabaseName -FROM #DatabaseList -WHERE COALESCE(secondary_role_allow_connections_desc, 'OK') -<> 'NO' -ORDER BY DatabaseName; +SELECT dl.DatabaseName +FROM #DatabaseList dl +LEFT OUTER JOIN #Ignore_Databases i ON dl.DatabaseName = i.DatabaseName +WHERE COALESCE(dl.secondary_role_allow_connections_desc, 'OK') <> 'NO' + AND i.DatabaseName IS NULL +ORDER BY dl.DatabaseName; OPEN c1; FETCH NEXT FROM c1 INTO @DatabaseName; @@ -24100,16 +24838,6 @@ FROM sys.databases AND user_access_desc='MULTI_USER' AND state_desc = 'ONLINE'; -/* 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 OR @DaysUptime IS NULL - SET @DaysUptime = .01; - -SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPERTY('ServerName')))) + ' Days Uptime: ' + RTRIM(@DaysUptime); - ---------------------------------------- --STEP 1: OBSERVE THE PATIENT --This step puts index information into temp tables. @@ -24117,7 +24845,7 @@ SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPE BEGIN TRY BEGIN - --Validate SQL Server Verson + --Validate SQL Server Version IF (SELECT LEFT(@SQLServerProductVersion, CHARINDEX('.',@SQLServerProductVersion,0)-1 @@ -28199,7 +28927,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '2.4', @VersionDate = '20190320'; +SELECT @Version = '2.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) @@ -28355,7 +29083,13 @@ You need to use an Azure storage account, and the path has to look like this: ht DECLARE @d VARCHAR(40), @StringToExecute NVARCHAR(4000); CREATE TABLE #t (id INT NOT NULL); - UPDATE STATISTICS #t WITH ROWCOUNT = 100000000, PAGECOUNT = 100000000; + + /* WITH ROWCOUNT doesn't work on Amazon RDS - see: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2037 */ + 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-' + AND db_id('rdsadmin') IS NULL + UPDATE STATISTICS #t WITH ROWCOUNT = 100000000, PAGECOUNT = 100000000; /*Grab the initial set of XML to parse*/ SET @d = CONVERT(VARCHAR(40), GETDATE(), 109); @@ -29287,14 +30021,14 @@ You need to use an Azure storage account, and the path has to look like this: ht DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en, ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn, NULL AS is_victim, - cao.wait_type AS owner_mode, + cao.wait_type COLLATE DATABASE_DEFAULT AS owner_mode, cao.waiter_type AS owner_waiter_type, cao.owner_activity AS owner_activity, cao.waiter_activity AS owner_waiter_activity, cao.merging AS owner_merging, cao.spilling AS owner_spilling, cao.waiting_to_close AS owner_waiting_to_close, - caw.wait_type AS waiter_mode, + caw.wait_type COLLATE DATABASE_DEFAULT AS waiter_mode, caw.waiter_type AS waiter_waiter_type, caw.owner_activity AS waiter_owner_activity, caw.waiter_activity AS waiter_waiter_activity, @@ -29461,7 +30195,7 @@ BEGIN /*First BEGIN*/ SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '3.4', @VersionDate = '20190320'; +SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN RETURN; @@ -32554,9 +33288,9 @@ WITH XMLNAMESPACES('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS UPDATE b SET b.is_fast_forward_cursor = 1 FROM #working_warnings b -JOIN #statements AS qs -ON b.sql_handle = qs.sql_handle -CROSS APPLY qs.statement.nodes('/p:StmtCursor') AS n1(fn) +JOIN #statements AS s +ON b.sql_handle = s.sql_handle +CROSS APPLY s.statement.nodes('/p:StmtCursor') AS n1(fn) WHERE n1.fn.exist('//p:CursorPlan/@CursorActualType[.="FastForward"]') = 1 AND s.is_cursor = 1 OPTION (RECOMPILE); @@ -35186,7 +35920,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '7.4', @VersionDate = '20190320'; + SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -36072,7 +36806,7 @@ SET NOCOUNT ON; /*Versioning details*/ -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -36424,6 +37158,25 @@ SET @RestoreDatabaseName = QUOTENAME(@RestoreDatabaseName); IF NOT EXISTS (SELECT * FROM sys.configurations WHERE name = 'xp_cmdshell' AND value_in_use = 1) SET @SimpleFolderEnumeration = 1; +SET @HeadersSQL = +N'INSERT INTO #Headers WITH (TABLOCK) + (BackupName, BackupDescription, BackupType, ExpirationDate, Compressed, Position, DeviceType, UserName, ServerName + ,DatabaseName, DatabaseVersion, DatabaseCreationDate, BackupSize, FirstLSN, LastLSN, CheckpointLSN, DatabaseBackupLSN + ,BackupStartDate, BackupFinishDate, SortOrder, CodePage, UnicodeLocaleId, UnicodeComparisonStyle, CompatibilityLevel + ,SoftwareVendorId, SoftwareVersionMajor, SoftwareVersionMinor, SoftwareVersionBuild, MachineName, Flags, BindingID + ,RecoveryForkID, Collation, FamilyGUID, HasBulkLoggedData, IsSnapshot, IsReadOnly, IsSingleUser, HasBackupChecksums + ,IsDamaged, BeginsLogChain, HasIncompleteMetaData, IsForceOffline, IsCopyOnly, FirstRecoveryForkID, ForkPointLSN + ,RecoveryModel, DifferentialBaseLSN, DifferentialBaseGUID, BackupTypeDescription, BackupSetGUID, CompressedBackupSize'; + +IF @MajorVersion >= 11 + SET @HeadersSQL += NCHAR(13) + NCHAR(10) + N', Containment'; + +IF @MajorVersion >= 13 OR (@MajorVersion = 12 AND @BuildVersion >= 2342) + SET @HeadersSQL += N', KeyAlgorithm, EncryptorThumbprint, EncryptorType'; + +SET @HeadersSQL += N')' + NCHAR(13) + NCHAR(10); +SET @HeadersSQL += N'EXEC (''RESTORE HEADERONLY FROM DISK=''''{Path}'''''')'; + IF @BackupPathFull IS NOT NULL BEGIN IF @SimpleFolderEnumeration = 1 @@ -36564,25 +37317,6 @@ BEGIN SELECT '#SplitBackups' AS table_name, * FROM #SplitBackups END - SET @HeadersSQL = - N'INSERT INTO #Headers WITH (TABLOCK) - (BackupName, BackupDescription, BackupType, ExpirationDate, Compressed, Position, DeviceType, UserName, ServerName - ,DatabaseName, DatabaseVersion, DatabaseCreationDate, BackupSize, FirstLSN, LastLSN, CheckpointLSN, DatabaseBackupLSN - ,BackupStartDate, BackupFinishDate, SortOrder, CodePage, UnicodeLocaleId, UnicodeComparisonStyle, CompatibilityLevel - ,SoftwareVendorId, SoftwareVersionMajor, SoftwareVersionMinor, SoftwareVersionBuild, MachineName, Flags, BindingID - ,RecoveryForkID, Collation, FamilyGUID, HasBulkLoggedData, IsSnapshot, IsReadOnly, IsSingleUser, HasBackupChecksums - ,IsDamaged, BeginsLogChain, HasIncompleteMetaData, IsForceOffline, IsCopyOnly, FirstRecoveryForkID, ForkPointLSN - ,RecoveryModel, DifferentialBaseLSN, DifferentialBaseGUID, BackupTypeDescription, BackupSetGUID, CompressedBackupSize'; - - IF @MajorVersion >= 11 - SET @HeadersSQL += NCHAR(13) + NCHAR(10) + N', Containment'; - - IF @MajorVersion >= 13 OR (@MajorVersion = 12 AND @BuildVersion >= 2342) - SET @HeadersSQL += N', KeyAlgorithm, EncryptorThumbprint, EncryptorType'; - - SET @HeadersSQL += N')' + NCHAR(13) + NCHAR(10); - SET @HeadersSQL += N'EXEC (''RESTORE HEADERONLY FROM DISK=''''{Path}'''''')'; - --get the backup completed data so we can apply tlogs from that point forwards SET @sql = REPLACE(@HeadersSQL, N'{Path}', @BackupPathFull + @LastFullBackup); IF @Debug = 1 @@ -36755,6 +37489,16 @@ BEGIN END; END; +IF @BackupPathFull IS NULL AND @ContinueLogs = 1 +BEGIN + + SELECT @DatabaseLastLSN = CAST(f.redo_start_lsn AS NUMERIC(25, 0)) + FROM master.sys.databases d + JOIN master.sys.master_files f ON d.database_id = f.database_id + WHERE d.name = SUBSTRING(@RestoreDatabaseName, 2, LEN(@RestoreDatabaseName) - 2) AND f.file_id = 1; + +END; + IF @BackupPathDiff IS NOT NULL BEGIN DELETE FROM @FileList; @@ -37193,7 +37937,7 @@ ALTER PROCEDURE dbo.sp_foreachdb AS BEGIN SET NOCOUNT ON; - SELECT @Version = '3.4', @VersionDate = '20190320'; + SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -37444,10 +38188,10 @@ IF @Help = 1 END GO IF OBJECT_ID('dbo.sp_ineachdb') IS NULL - EXEC ('CREATE PROCEDURE dbo.sp_ineachdb AS RETURN 0'); + EXEC ('CREATE PROCEDURE dbo.sp_ineachdb AS RETURN 0') GO -ALTER PROCEDURE dbo.sp_ineachdb +ALTER PROCEDURE [dbo].[sp_ineachdb] -- mssqltips.com/sqlservertip/5694/execute-a-command-in-the-context-of-each-database-in-sql-server--part-2/ @command nvarchar(max) = NULL, @replace_character nchar(1) = N'?', @@ -37478,7 +38222,7 @@ AS BEGIN SET NOCOUNT ON; - SELECT @Version = '2.4', @VersionDate = '20190320'; + SELECT @Version = '2.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -37532,6 +38276,9 @@ IF @Help = 1 */ '; + + RETURN -1; + END DECLARE @exec nvarchar(150), @sx nvarchar(18) = N'.sys.sp_executesql', @@ -37541,6 +38288,9 @@ IF @Help = 1 @thisdb sysname, @cr char(2) = CHAR(13) + CHAR(10); +DECLARE @SQLVersion AS tinyint = (@@microsoftversion / 0x1000000) & 0xff -- Stores the SQL Server Version Number(8(2000),9(2005),10(2008 & 2008R2),11(2012),12(2014),13(2016),14(2017)) +DECLARE @ServerName AS sysname = CONVERT(sysname, SERVERPROPERTY('ServerName')) -- Stores the SQL Server Instance name. + CREATE TABLE #ineachdb(id int, name nvarchar(512)); IF @database_list > N'' @@ -37632,12 +38382,14 @@ IF @Help = 1 -- https://docs.microsoft.com/en-us/sql/t-sql/functions/databasepropertyex-transact-sql ) OR (@state_desc <> N'ONLINE' AND state_desc <> @state_desc) - OR - ( - -- from Andy Mallon / First Responders Kit. Make sure that if we're an - -- AG secondary, we skip any database where allow connections is off - SERVERPROPERTY('IsHadrEnabled') = 1 - AND EXISTS + ) + ); + +-- from Andy Mallon / First Responders Kit. Make sure that if we're an +-- AG secondary, we skip any database where allow connections is off +if @SQLVersion >= 11 + DELETE dbs FROM #ineachdb AS dbs + WHERE EXISTS ( SELECT 1 FROM sys.dm_hadr_database_replica_states AS drs INNER JOIN sys.availability_replicas AS ar @@ -37646,10 +38398,7 @@ IF @Help = 1 ON ags.group_id = ar.group_id WHERE drs.database_id = dbs.id AND ar.secondary_role_allow_connections = 0 - AND ags.primary_replica <> @@SERVERNAME - ) - ) - ) + AND ags.primary_replica <> @ServerName ); -- Well, if we deleted them all... @@ -37710,5 +38459,4 @@ IF @Help = 1 CLOSE dbs; DEALLOCATE dbs; END -END GO diff --git a/Install-Core-Blitz-No-Query-Store.sql b/Install-Core-Blitz-No-Query-Store.sql index c9a26726a..bf9069969 100755 --- a/Install-Core-Blitz-No-Query-Store.sql +++ b/Install-Core-Blitz-No-Query-Store.sql @@ -36,7 +36,7 @@ AS SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '7.4', @VersionDate = '20190320'; + SELECT @Version = '7.6', @VersionDate = '20190702'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -78,7 +78,7 @@ AS @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 + @OutputType ''TABLE''=table | ''COUNT''=row with number found | ''MARKDOWN''=bulleted list | ''SCHEMA''=version and field list | ''XML'' =table output as XML | ''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. @@ -116,8 +116,8 @@ AS 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' */ + END;/* IF @OutputType = 'SCHEMA' */ + ELSE BEGIN DECLARE @StringToExecute NVARCHAR(4000) @@ -150,7 +150,38 @@ AS ,@TraceFileIssue bit -- Flag for Windows OS to help with Linux support ,@IsWindowsOperatingSystem BIT - ,@DaysUptime NUMERIC(23,2); + ,@DaysUptime NUMERIC(23,2) + /* For First Responder Kit consistency check:*/ + ,@spBlitzFullName VARCHAR(1024) + ,@BlitzIsOutdatedComparedToOthers BIT + ,@tsql NVARCHAR(MAX) + ,@VersionCheckModeExistsTSQL NVARCHAR(MAX) + ,@BlitzProcDbName VARCHAR(256) + ,@ExecRet INT + ,@InnerExecRet INT + ,@TmpCnt INT + ,@PreviousComponentName VARCHAR(256) + ,@PreviousComponentFullPath VARCHAR(1024) + ,@CurrentStatementId INT + ,@CurrentComponentSchema VARCHAR(256) + ,@CurrentComponentName VARCHAR(256) + ,@CurrentComponentType VARCHAR(256) + ,@CurrentComponentVersionDate DATETIME2 + ,@CurrentComponentFullName VARCHAR(1024) + ,@CurrentComponentMandatory BIT + ,@MaximumVersionDate DATETIME + ,@StatementCheckName VARCHAR(256) + ,@StatementOutputsCounter BIT + ,@OutputCounterExpectedValue INT + ,@StatementOutputsExecRet BIT + ,@StatementOutputsDateTime BIT + ,@CurrentComponentMandatoryCheckOK BIT + ,@CurrentComponentVersionCheckModeOK BIT + ,@canExitLoop BIT + ,@frkIsConsistent BIT + + /* End of declarations for First Responder Kit consistency check:*/ + ; SET @crlf = NCHAR(13) + NCHAR(10); SET @ResultText = 'sp_Blitz Results: ' + @crlf; @@ -201,6 +232,47 @@ AS Finding NVARCHAR(128) ); + /* First Responder Kit consistency (temporary tables) */ + + IF(OBJECT_ID('tempdb..#FRKObjects') IS NOT NULL) + BEGIN + EXEC sp_executesql N'DROP TABLE #FRKObjects;'; + END; + + -- this one represents FRK objects + CREATE TABLE #FRKObjects ( + DatabaseName VARCHAR(256) NOT NULL, + ObjectSchemaName VARCHAR(256) NULL, + ObjectName VARCHAR(256) NOT NULL, + ObjectType VARCHAR(256) NOT NULL, + MandatoryComponent BIT NOT NULL + ); + + + IF(OBJECT_ID('tempdb..#StatementsToRun4FRKVersionCheck') IS NOT NULL) + BEGIN + EXEC sp_executesql N'DROP TABLE #StatementsToRun4FRKVersionCheck;'; + END; + + + -- This one will contain the statements to be executed + -- order: 1- Mandatory, 2- VersionCheckMode, 3- VersionCheck + + CREATE TABLE #StatementsToRun4FRKVersionCheck ( + StatementId INT IDENTITY(1,1), + CheckName VARCHAR(256), + SubjectName VARCHAR(256), + SubjectFullPath VARCHAR(1024), + StatementText NVARCHAR(MAX), + StatementOutputsCounter BIT, + OutputCounterExpectedValue INT, + StatementOutputsExecRet BIT, + StatementOutputsDateTime BIT + ); + + /* End of First Responder Kit consistency (temporary tables) */ + + /* You can build your own table with a list of checks to skip. For example, you might have some databases that you don't care about, or some checks you don't @@ -2280,7 +2352,7 @@ AS 200 AS Priority , 'Monitoring' AS FindingsGroup , 'Alerts Disabled' AS Finding , - 'https://www.BrentOzar.com/go/alerts/' AS URL , + 'https://BrentOzar.com/go/alert' AS URL , ( 'The following Alert is disabled, please review and enable if desired: ' + name ) AS Details FROM msdb.dbo.sysalerts @@ -4257,6 +4329,513 @@ IF @ProductVersionMajor >= 10 END; END; + +/*This checks that First Responder Kit is consistent. +It assumes that all the objects of the kit resides in the same database, the one in which this SP is stored +It also is ready to check for installation in another schema. +*/ +IF( + NOT EXISTS ( + SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 226 + ) +) +BEGIN + + IF @Debug IN (1, 2) RAISERROR('Running check with id %d',0,1,2000); + + SET @spBlitzFullName = QUOTENAME(DB_NAME()) + '.' +QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)) + '.' + QUOTENAME(OBJECT_NAME(@@PROCID)); + SET @BlitzIsOutdatedComparedToOthers = 0; + SET @tsql = NULL; + SET @VersionCheckModeExistsTSQL = NULL; + SET @BlitzProcDbName = DB_NAME(); + SET @ExecRet = NULL; + SET @InnerExecRet = NULL; + SET @TmpCnt = NULL; + + SET @PreviousComponentName = NULL; + SET @PreviousComponentFullPath = NULL; + SET @CurrentStatementId = NULL; + SET @CurrentComponentSchema = NULL; + SET @CurrentComponentName = NULL; + SET @CurrentComponentType = NULL; + SET @CurrentComponentVersionDate = NULL; + SET @CurrentComponentFullName = NULL; + SET @CurrentComponentMandatory = NULL; + SET @MaximumVersionDate = NULL; + + SET @StatementCheckName = NULL; + SET @StatementOutputsCounter = NULL; + SET @OutputCounterExpectedValue = NULL; + SET @StatementOutputsExecRet = NULL; + SET @StatementOutputsDateTime = NULL; + + SET @CurrentComponentMandatoryCheckOK = NULL; + SET @CurrentComponentVersionCheckModeOK = NULL; + + SET @canExitLoop = 0; + SET @frkIsConsistent = 0; + + + SET @tsql = 'USE ' + QUOTENAME(@BlitzProcDbName) + ';' + @crlf + + 'WITH FRKComponents (' + @crlf + + ' ObjectName,' + @crlf + + ' ObjectType,' + @crlf + + ' MandatoryComponent' + @crlf + + ')' + @crlf + + 'AS (' + @crlf + + ' SELECT ''sp_AllNightLog'',''P'' ,0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''sp_AllNightLog_Setup'', ''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_Blitz'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzBackups'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzCache'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzFirst'',''P'',0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''sp_BlitzIndex'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzLock'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzQueryStore'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzWho'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_DatabaseRestore'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_foreachdb'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_ineachdb'',''P'',0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''SqlServerVersions'',''U'',0' + @crlf + + ')' + @crlf + + 'INSERT INTO #FRKObjects (' + @crlf + + ' DatabaseName,ObjectSchemaName,ObjectName, ObjectType,MandatoryComponent' + @crlf + + ')' + @crlf + + 'SELECT DB_NAME(),SCHEMA_NAME(o.schema_id), c.ObjectName,c.ObjectType,c.MandatoryComponent' + @crlf + + 'FROM ' + @crlf + + ' FRKComponents c' + @crlf + + 'LEFT JOIN ' + @crlf + + ' sys.objects o' + @crlf + + 'ON c.ObjectName = o.[name]' + @crlf + + 'AND c.ObjectType = o.[type]' + @crlf + + --'WHERE o.schema_id IS NOT NULL' + @crlf + + ';' + ; + + EXEC @ExecRet = sp_executesql @tsql ; + + -- TODO: add check for statement success + + -- TODO: based on SP requirements and presence (SchemaName is not null) ==> update MandatoryComponent column + + -- Filling #StatementsToRun4FRKVersionCheck + INSERT INTO #StatementsToRun4FRKVersionCheck ( + CheckName,StatementText,SubjectName,SubjectFullPath, StatementOutputsCounter,OutputCounterExpectedValue,StatementOutputsExecRet,StatementOutputsDateTime + ) + SELECT + 'Mandatory', + 'SELECT @cnt = COUNT(*) FROM #FRKObjects WHERE ObjectSchemaName IS NULL AND ObjectName = ''' + ObjectName + ''' AND MandatoryComponent = 1;', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 1, + 0, + 0, + 0 + FROM #FRKObjects + UNION ALL + SELECT + 'VersionCheckMode', + 'SELECT @cnt = COUNT(*) FROM ' + + QUOTENAME(DatabaseName) + '.sys.all_parameters ' + + 'where object_id = OBJECT_ID(''' + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName) + ''') AND [name] = ''@VersionCheckMode'';', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 1, + 1, + 0, + 0 + FROM #FRKObjects + WHERE ObjectType = 'P' + AND ObjectSchemaName IS NOT NULL + UNION ALL + SELECT + 'VersionCheck', + 'EXEC @ExecRet = ' + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName) + ' @VersionCheckMode = 1 , @VersionDate = @ObjDate OUTPUT;', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 0, + 0, + 1, + 1 + FROM #FRKObjects + WHERE ObjectType = 'P' + AND ObjectSchemaName IS NOT NULL + ; + IF(@Debug in (1,2)) + BEGIN + SELECT * + FROM #StatementsToRun4FRKVersionCheck ORDER BY SubjectName,SubjectFullPath,StatementId -- in case of schema change ; + END; + + + -- loop on queries... + WHILE(@canExitLoop = 0) + BEGIN + SET @CurrentStatementId = NULL; + + SELECT TOP 1 + @StatementCheckName = CheckName, + @CurrentStatementId = StatementId , + @CurrentComponentName = SubjectName, + @CurrentComponentFullName = SubjectFullPath, + @tsql = StatementText, + @StatementOutputsCounter = StatementOutputsCounter, + @OutputCounterExpectedValue = OutputCounterExpectedValue , + @StatementOutputsExecRet = StatementOutputsExecRet, + @StatementOutputsDateTime = StatementOutputsDateTime + FROM #StatementsToRun4FRKVersionCheck + ORDER BY SubjectName, SubjectFullPath,StatementId /* in case of schema change */ + ; + + -- loop exit condition + IF(@CurrentStatementId IS NULL) + BEGIN + BREAK; + END; + + IF @Debug IN (1, 2) RAISERROR(' Statement: %s',0,1,@tsql); + + -- we start a new component + IF(@PreviousComponentName IS NULL OR + (@PreviousComponentName IS NOT NULL AND @PreviousComponentName <> @CurrentComponentName) OR + (@PreviousComponentName IS NOT NULL AND @PreviousComponentName = @CurrentComponentName AND @PreviousComponentFullPath <> @CurrentComponentFullName) + ) + BEGIN + -- reset variables + SET @CurrentComponentMandatoryCheckOK = 0; + SET @CurrentComponentVersionCheckModeOK = 0; + SET @PreviousComponentName = @CurrentComponentName; + SET @PreviousComponentFullPath = @CurrentComponentFullName ; + END; + + IF(@StatementCheckName NOT IN ('Mandatory','VersionCheckMode','VersionCheck')) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (code generator changed)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Your version check failed because a change has been made to the version check code generator.' + @crlf + + 'Error: No handler for check with name "' + ISNULL(@StatementCheckName,'') + '"' AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@StatementCheckName = 'Mandatory') + BEGIN + -- outputs counter + EXEC @ExecRet = sp_executesql @tsql, N'@cnt INT OUTPUT',@cnt = @TmpCnt OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Your version check failed due to dynamic query failure.' + @crlf + + 'Error: following query failed at execution (check if component [' + ISNULL(@CurrentComponentName,@CurrentComponentName) + '] is mandatory and missing)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@TmpCnt <> @OutputCounterExpectedValue) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 227 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Missing: ' + @CurrentComponentName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated version of the First Responder Kit to install it.' AS Details + ; + + -- as it's missing, no value for SubjectFullPath + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectName = @CurrentComponentName ; + CONTINUE; + END; + + SET @CurrentComponentMandatoryCheckOK = 1; + END; + + IF(@StatementCheckName = 'VersionCheckMode') + BEGIN + IF(@CurrentComponentMandatoryCheckOK = 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (unexpectedly modified checks ordering)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because "Mandatory" check has not been completed before for current component' + @crlf + + 'Error: version check mode happenned before "Mandatory" check for component called "' + @CurrentComponentFullName + '"' + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + -- outputs counter + EXEC @ExecRet = sp_executesql @tsql, N'@cnt INT OUTPUT',@cnt = @TmpCnt OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because a change has been made to the code generator.' + @crlf + + 'Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] can run in VersionCheckMode)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@TmpCnt <> @OutputCounterExpectedValue) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 228 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Outdated: ' + @CurrentComponentFullName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Component ' + @CurrentComponentFullName + ' is not at the minimum version required to run this procedure' + @crlf + + 'VersionCheckMode has been introduced in component version date after "20190320". This means its version is lower than or equal to that date.' AS Details; + ; + + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + SET @CurrentComponentVersionCheckModeOK = 1; + END; + + IF(@StatementCheckName = 'VersionCheck') + BEGIN + IF(@CurrentComponentMandatoryCheckOK = 0 OR @CurrentComponentVersionCheckModeOK = 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (unexpectedly modified checks ordering)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because "VersionCheckMode" check has not been completed before for component called "' + @CurrentComponentFullName + '"' + @crlf + + 'Error: VersionCheck happenned before "VersionCheckMode" check for component called "' + @CurrentComponentFullName + '"' + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + EXEC @ExecRet = sp_executesql @tsql , N'@ExecRet INT OUTPUT, @ObjDate DATETIME OUTPUT', @ExecRet = @InnerExecRet OUTPUT, @ObjDate = @CurrentComponentVersionDate OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. The version check failed because a change has been made to the code generator.' + @crlf + + 'Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] is at the expected version)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + + IF(@InnerExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (Failed dynamic SP call to ' + @CurrentComponentFullName + ')' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] is at the expected version)' + @crlf + + 'Return code: ' + CONVERT(VARCHAR(10),@InnerExecRet) + @crlf + + 'T-SQL Query: ' + @crlf + + @tsql AS Details + ; + + -- advance to next component + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + IF(@CurrentComponentVersionDate < @VersionDate) + BEGIN + + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 228 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Outdated: ' + @CurrentComponentFullName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download and install the latest First Responder Kit - you''re running some older code, and it doesn''t get better with age.' AS Details + ; + + RAISERROR('Component %s is outdated',10,1,@CurrentComponentFullName); + -- advance to next component + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + ELSE IF(@CurrentComponentVersionDate > @VersionDate AND @BlitzIsOutdatedComparedToOthers = 0) + BEGIN + SET @BlitzIsOutdatedComparedToOthers = 1; + RAISERROR('Procedure %s is outdated',10,1,@spBlitzFullName); + IF(@MaximumVersionDate IS NULL OR @MaximumVersionDate < @CurrentComponentVersionDate) + BEGIN + SET @MaximumVersionDate = @CurrentComponentVersionDate; + END; + END; + /* Kept for debug purpose: + ELSE + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 2000 AS CheckID , + 250 AS Priority , + 'Informational' AS FindingsGroup , + 'First Responder kit component ' + @CurrentComponentFullName + ' is at the expected version' AS Finding , + 'https://www.BrentOzar.com/blitz/' AS URL , + 'Version date is: ' + CONVERT(VARCHAR(32),@CurrentComponentVersionDate,121) AS Details + ; + END; + */ + END; + + -- could be performed differently to minimize computation + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE StatementId = @CurrentStatementId ; + END; +END; + /*This counts memory dumps and gives min and max date of in view*/ IF @ProductVersionMajor >= 10 @@ -5072,9 +5651,9 @@ IF @ProductVersionMajor >= 10 DB_NAME(s.database_id) + '' has '' + CONVERT(NVARCHAR(20), COUNT_BIG(*)) - + '' open implicit transactions '' - + '' with an oldest begin time of '' - + CONVERT(NVARCHAR(30), MIN(tat.transaction_begin_time)) AS details + + '' open implicit transactions with an oldest begin time of '' + + CONVERT(NVARCHAR(30), MIN(tat.transaction_begin_time)) + + '' Run sp_BlitzWho and check the is_implicit_transaction column to see the culprits.'' AS details FROM sys.dm_tran_active_transactions AS tat LEFT JOIN sys.dm_tran_session_transactions AS tst ON tst.transaction_id = tat.transaction_id @@ -5131,6 +5710,32 @@ IF @ProductVersionMajor >= 10 END; + IF NOT EXISTS ( SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 229 ) + AND CAST(SERVERPROPERTY('Edition') AS NVARCHAR(4000)) LIKE '%Evaluation%' + BEGIN + + IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 216) WITH NOWAIT; + + INSERT INTO #BlitzResults + ( CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT 229 AS CheckID, + 1 AS Priority, + 'Reliability' AS FindingsGroup, + 'Evaluation Edition' AS Finding, + 'https://www.BrentOzar.com/go/workgroup' AS URL, + 'This server will stop working on: ' + CAST(CONVERT(DATETIME, DATEADD(DD, 180, create_date), 102) AS VARCHAR(100)) AS details + FROM sys.server_principals + WHERE sid = 0x010100000000000512000000; + + END; IF @CheckUserDatabaseObjects = 1 @@ -6115,6 +6720,37 @@ IF @ProductVersionMajor >= 10 HAVING COUNT(1) > 0;'; END; --of Check 218. + /* Check 225 - Reliability - Resumable Index Operation Paused */ + IF NOT EXISTS ( + SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL + AND CheckID = 225 + ) + AND EXISTS (SELECT * FROM sys.all_objects WHERE name = 'index_resumable_operations') + BEGIN + IF @Debug IN (1,2) + BEGIN + RAISERROR ('Running CheckId [%d].',0,1,218) WITH NOWAIT; + END + + EXECUTE sp_MSforeachdb 'USE [?]; + SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + INSERT INTO #BlitzResults (CheckID, DatabaseName, Priority, FindingsGroup, Finding, URL, Details) + SELECT 225 AS CheckID + ,''?'' AS DatabaseName + ,200 AS Priority + ,''Reliability'' AS FindingsGroup + ,''Resumable Index Operation Paused'' AS Finding + ,''https://BrentOzar.com/go/resumable'' AS URL + ,iro.state_desc + N'' since '' + CONVERT(NVARCHAR(50), last_pause_time, 120) + '', '' + + CAST(iro.percent_complete AS NVARCHAR(20)) + ''% complete: '' + + CAST(iro.sql_text AS NVARCHAR(1000)) AS Details + FROM sys.index_resumable_operations iro + JOIN sys.objects o ON iro.[object_id] = o.[object_id] + WHERE iro.state <> 0;'; + END; --of Check 225. + --/* Check 220 - Statistics Without Histograms */ --IF NOT EXISTS ( -- SELECT 1 @@ -6673,7 +7309,7 @@ IF @ProductVersionMajor >= 10 (@@SERVERNAME IS NOT NULL AND /* not a named instance */ - CHARINDEX('\',CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128))) = 0 + CHARINDEX(CHAR(92),CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128))) = 0 AND /* not clustered, when computername may be different than the servername */ SERVERPROPERTY('IsClustered') = 0 @@ -8237,6 +8873,25 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1 LEFT OUTER JOIN Results rNext ON r.rownum = rNext.rownum - 1 ORDER BY r.rownum FOR XML PATH(N''); END; + ELSE IF @OutputType = 'XML' + BEGIN + /* --TOURSTOP05-- */ + SELECT [Priority] , + [FindingsGroup] , + [Finding] , + [DatabaseName] , + [URL] , + [Details] , + [QueryPlanFiltered] , + CheckID + FROM #BlitzResults + ORDER BY Priority , + FindingsGroup , + Finding , + DatabaseName , + Details + FOR XML PATH('Result'), ROOT('sp_Blitz_Output'); + END; ELSE IF @OutputType <> 'NONE' BEGIN /* --TOURSTOP05-- */ @@ -8317,7 +8972,7 @@ GO /* --Sample execution call with the most common parameters: -EXEC [dbo].[sp_Blitz] +EXEC [dbo].[sp_Blitz] @CheckUserDatabaseObjects = 1 , @CheckProcedureCache = 0 , @OutputType = 'TABLE' , @@ -8350,7 +9005,7 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '3.4', @VersionDate = '20190320'; + SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -10005,7 +10660,7 @@ CREATE TABLE ##BlitzCacheProcs ( unparameterized_query BIT, near_parallel BIT, plan_warnings BIT, - plan_multiple_plans BIT, + plan_multiple_plans INT, long_running BIT, downlevel_estimator BIT, implicit_conversions BIT, @@ -10122,7 +10777,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) @@ -10762,7 +11417,7 @@ BEGIN unparameterized_query BIT, near_parallel BIT, plan_warnings BIT, - plan_multiple_plans BIT, + plan_multiple_plans INT, long_running BIT, downlevel_estimator BIT, implicit_conversions BIT, @@ -10913,10 +11568,6 @@ IF @SortOrder NOT IN ('cpu', 'avg cpu', 'reads', 'avg reads', 'writes', 'avg wri SET @SortOrder = 'cpu'; END; -SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName), - @OutputSchemaName = QUOTENAME(@OutputSchemaName), - @OutputTableName = QUOTENAME(@OutputTableName); - SET @QueryFilter = LOWER(@QueryFilter); IF LEFT(@QueryFilter, 3) NOT IN ('all', 'sta', 'pro', 'fun') @@ -10931,6 +11582,25 @@ IF @SkipAnalysis = 1 SET @HideSummary = 1; END; +DECLARE @AllSortSql NVARCHAR(MAX) = N''; +DECLARE @VersionShowsMemoryGrants BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') + SET @VersionShowsMemoryGrants = 1; +ELSE + SET @VersionShowsMemoryGrants = 0; + +DECLARE @VersionShowsSpills BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') + SET @VersionShowsSpills = 1; +ELSE + SET @VersionShowsSpills = 0; + +DECLARE @VersionShowsAirQuoteActualPlans BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') + SET @VersionShowsAirQuoteActualPlans = 1; +ELSE + SET @VersionShowsAirQuoteActualPlans = 0; + IF @Reanalyze = 1 AND OBJECT_ID('tempdb..##BlitzCacheResults') IS NULL BEGIN RAISERROR(N'##BlitzCacheResults does not exist, can''t reanalyze', 0, 1) WITH NOWAIT; @@ -10955,6 +11625,9 @@ IF @Reanalyze = 1 GOTO Results; END; + + + IF @SortOrder IN ('all', 'all avg') BEGIN RAISERROR(N'Checking all sort orders, please be patient', 0, 1) WITH NOWAIT; @@ -11584,22 +12257,15 @@ SELECT @v = common_version , FROM #checkversion OPTION (RECOMPILE); -IF (@SortOrder IN ('memory grant', 'avg memory grant')) -AND ((@v < 11) -OR (@v = 11 AND @build < 6020) -OR (@v = 12 AND @build < 5000) -OR (@v = 13 AND @build < 1601)) +IF (@SortOrder IN ('memory grant', 'avg memory grant')) AND @VersionShowsMemoryGrants = 0 BEGIN RAISERROR('Your version of SQL does not support sorting by memory grant or average memory grant. Please use another sort order.', 16, 1); RETURN; END; -IF (@SortOrder IN ('spills', 'avg spills')) -AND (@v < 13 - OR @v = 13 AND @build < 5026 - OR @v = 14 AND @build < 3015) +IF (@SortOrder IN ('spills', 'avg spills') AND @VersionShowsSpills = 0) BEGIN - RAISERROR('Your version of SQL does not support sorting by spills or average spills. Please use another sort order.', 16, 1); + RAISERROR('Your version of SQL does not support sorting by spills. Please use another sort order.', 16, 1); RETURN; END; @@ -11634,8 +12300,19 @@ FROM (SELECT TOP (@Top) x.*, xpa.*, CROSS APPLY (SELECT * FROM sys.dm_exec_plan_attributes(x.plan_handle) AS ixpa WHERE ixpa.attribute = ''dbid'') AS xpa ' + @nl ; + +IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @body += N' CROSS APPLY sys.dm_exec_query_plan_stats(x.plan_handle) AS deqps ' + @nl ; + END + SET @body += N' WHERE 1 = 1 ' + @nl ; +IF EXISTS (SELECT * FROM sys.all_objects o INNER JOIN sys.all_columns c ON o.object_id = c.object_id WHERE o.name = 'dm_hadr_database_replica_states' AND c.name = 'is_primary_replica') + BEGIN + RAISERROR(N'Ignoring readable secondaries databases by default', 0, 1) WITH NOWAIT; + SET @body += N' AND CAST(xpa.value AS INT) NOT IN (select database_id from sys.dm_hadr_database_replica_states where is_primary_replica = 0 AND DATABASEPROPERTYEX(DB_NAME(database_id), ''Updateability'') = ''READ_ONLY'')' + @nl ; + END IF @IgnoreSystemDBs = 1 BEGIN @@ -11750,6 +12427,11 @@ SET @body += N') AS qs CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS st CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp ' + @nl ; +IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @body += N' CROSS APPLY sys.dm_exec_query_plan_stats(qs.plan_handle) AS deqps ' + @nl ; + END + SET @body_where += N' AND pa.attribute = ' + QUOTENAME('dbid', @q ) + @nl ; @@ -11818,7 +12500,7 @@ SELECT TOP (@Top) NULL AS PercentMemoryGrantUsed, NULL AS AvgMaxMemoryGrant,'; - IF @v >=15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026) + IF @VersionShowsSpills = 1 BEGIN RAISERROR(N'Getting spill information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @plans_triggers_select_list += N' @@ -11837,10 +12519,20 @@ SELECT TOP (@Top) NULL AS AvgSpills, ' ; END; - SET @plans_triggers_select_list += - N'st.text AS QueryText , - query_plan AS QueryPlan, - t.t_TotalWorker, + SET @plans_triggers_select_list += + N'st.text AS QueryText ,'; + + IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @plans_triggers_select_list += N' COALESCE(deqps.query_plan, qp.query_plan) AS QueryPlan, ' + @nl ; + END; + ELSE + BEGIN + SET @plans_triggers_select_list += N' qp.query_plan AS QueryPlan, ' + @nl ; + END; + + SET @plans_triggers_select_list += + N't.t_TotalWorker, t.t_TotalElapsed, t.t_TotalReads, t.t_TotalExecs, @@ -11927,8 +12619,7 @@ BEGIN NULL AS LastReturnedRows, ' ; END; - IF (@v = 11 AND @build >= 6020) OR (@v = 12 AND @build >= 5000) OR (@v = 13 AND @build >= 1601) OR (@v >= 14) - + IF @VersionShowsMemoryGrants = 1 BEGIN RAISERROR(N'Getting memory grant information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @sql += N' @@ -11951,7 +12642,7 @@ BEGIN NULL AS AvgMaxMemoryGrant, ' ; END; - IF @v >=15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026) + IF @VersionShowsSpills = 1 BEGIN RAISERROR(N'Getting spill information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @sql += N' @@ -11974,8 +12665,19 @@ BEGIN SUBSTRING(st.text, ( qs.statement_start_offset / 2 ) + 1, ( ( CASE qs.statement_end_offset WHEN -1 THEN DATALENGTH(st.text) ELSE qs.statement_end_offset - END - qs.statement_start_offset ) / 2 ) + 1) AS QueryText , - query_plan AS QueryPlan, + END - qs.statement_start_offset ) / 2 ) + 1) AS QueryText , ' + @nl ; + + + IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @sql += N' COALESCE(deqps.query_plan, qp.query_plan) AS QueryPlan, ' + @nl ; + END + ELSE + BEGIN + SET @sql += N' query_plan AS QueryPlan, ' + @nl ; + END + + SET @sql += N' t.t_TotalWorker, t.t_TotalElapsed, t.t_TotalReads, @@ -12135,6 +12837,9 @@ FROM (SELECT SqlHandle, WHERE x.rn = 1 OPTION (RECOMPILE); +/* + This block was used to delete duplicate queries, but has been removed. + For more info: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2026 WITH d AS ( SELECT SPID, ROW_NUMBER() OVER (PARTITION BY SqlHandle, QueryHash ORDER BY #sortable# DESC) AS rn @@ -12144,7 +12849,8 @@ WHERE SPID = @@SPID DELETE d WHERE d.rn > 1 AND SPID = @@SPID -OPTION (RECOMPILE); +OPTION (RECOMPILE); +*/ '; SELECT @sort = CASE @SortOrder WHEN N'cpu' THEN N'TotalCPU' @@ -12249,11 +12955,11 @@ OPTION (RECOMPILE) ; * metric. */ RAISERROR('Computing CPU, duration, read, and write metrics', 0, 1) WITH NOWAIT; -DECLARE @total_duration MONEY, - @total_cpu MONEY, - @total_reads MONEY, - @total_writes MONEY, - @total_execution_count MONEY; +DECLARE @total_duration BIGINT, + @total_cpu BIGINT, + @total_reads BIGINT, + @total_writes BIGINT, + @total_execution_count BIGINT; SELECT @total_cpu = SUM(TotalCPU), @total_duration = SUM(TotalDuration), @@ -12436,7 +13142,7 @@ RAISERROR(N'Gathering high level plan information', 0, 1) WITH NOWAIT; UPDATE ##BlitzCacheProcs SET NumberOfDistinctPlans = distinct_plan_count, NumberOfPlans = number_of_plans , - plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN 1 END + plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN number_of_plans END FROM ( SELECT COUNT(DISTINCT QueryHash) AS distinct_plan_count, COUNT(QueryHash) AS number_of_plans, @@ -13246,7 +13952,7 @@ WITH XMLNAMESPACES('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS UPDATE ##BlitzCacheProcs SET NumberOfDistinctPlans = distinct_plan_count, NumberOfPlans = number_of_plans, - plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN 1 END + plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN number_of_plans END FROM ( SELECT COUNT(DISTINCT QueryHash) AS distinct_plan_count, COUNT(QueryHash) AS number_of_plans, @@ -14177,7 +14883,7 @@ SET Warnings = SUBSTRING( CASE WHEN downlevel_estimator = 1 THEN ', Downlevel CE' ELSE '' END + CASE WHEN implicit_conversions = 1 THEN ', Implicit Conversions' ELSE '' END + CASE WHEN tvf_join = 1 THEN ', Function Join' ELSE '' END + - CASE WHEN plan_multiple_plans = 1 THEN ', Multiple Plans' ELSE '' END + + CASE WHEN plan_multiple_plans > 0 THEN ', Multiple Plans' + COALESCE(' (' + CAST(plan_multiple_plans AS VARCHAR(10)) + ')', '') ELSE '' END + CASE WHEN is_trivial = 1 THEN ', Trivial Plans' ELSE '' END + CASE WHEN is_forced_serial = 1 THEN ', Forced Serialization' ELSE '' END + CASE WHEN is_key_lookup_expensive = 1 THEN ', Expensive Key Lookup' ELSE '' END + @@ -14255,7 +14961,7 @@ SELECT DISTINCT CASE WHEN downlevel_estimator = 1 THEN ', Downlevel CE' ELSE '' END + CASE WHEN implicit_conversions = 1 THEN ', Implicit Conversions' ELSE '' END + CASE WHEN tvf_join = 1 THEN ', Function Join' ELSE '' END + - CASE WHEN plan_multiple_plans = 1 THEN ', Multiple Plans' ELSE '' END + + CASE WHEN plan_multiple_plans > 0 THEN ', Multiple Plans' + COALESCE(' (' + CAST(plan_multiple_plans AS VARCHAR(10)) + ')', '') ELSE '' END + CASE WHEN is_trivial = 1 THEN ', Trivial Plans' ELSE '' END + CASE WHEN is_forced_serial = 1 THEN ', Forced Serialization' ELSE '' END + CASE WHEN is_key_lookup_expensive = 1 THEN ', Expensive Key Lookup' ELSE '' END + @@ -14346,205 +15052,14 @@ OPTION (RECOMPILE); Results: -IF @OutputDatabaseName IS NOT NULL - AND @OutputSchemaName IS NOT NULL - AND @OutputTableName IS NOT NULL +IF @ExportToExcel = 1 BEGIN - RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT; + RAISERROR('Displaying results with Excel formatting (no plans).', 0, 1) WITH NOWAIT; - /* send results to a table */ - DECLARE @insert_sql NVARCHAR(MAX) = N'' ; - - SET @insert_sql = 'USE ' - + @OutputDatabaseName - + '; IF EXISTS(SELECT * FROM ' - + @OutputDatabaseName - + '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' - + @OutputSchemaName - + ''') AND NOT EXISTS (SELECT * FROM ' - + @OutputDatabaseName - + '.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = ''' - + @OutputSchemaName + ''' AND QUOTENAME(TABLE_NAME) = ''' - + @OutputTableName + ''') CREATE TABLE ' - + @OutputSchemaName + '.' - + @OutputTableName - + N'(ID bigint NOT NULL IDENTITY(1,1), - ServerName NVARCHAR(258), - CheckDate DATETIMEOFFSET, - Version NVARCHAR(258), - QueryType NVARCHAR(258), - Warnings varchar(max), - DatabaseName sysname, - SerialDesiredMemory float, - SerialRequiredMemory float, - AverageCPU bigint, - TotalCPU bigint, - PercentCPUByType money, - CPUWeight money, - AverageDuration bigint, - TotalDuration bigint, - DurationWeight money, - PercentDurationByType money, - AverageReads bigint, - TotalReads bigint, - ReadWeight money, - PercentReadsByType money, - AverageWrites bigint, - TotalWrites bigint, - WriteWeight money, - PercentWritesByType money, - ExecutionCount bigint, - ExecutionWeight money, - PercentExecutionsByType money,' + N' - ExecutionsPerMinute money, - PlanCreationTime datetime, - PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()), - LastExecutionTime datetime, - PlanHandle varbinary(64), - [Remove Plan Handle From Cache] AS - CASE WHEN [PlanHandle] IS NOT NULL - THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');'' - ELSE ''N/A'' END, - SqlHandle varbinary(64), - [Remove SQL Handle From Cache] AS - CASE WHEN [SqlHandle] IS NOT NULL - THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');'' - ELSE ''N/A'' END, - [SQL Handle More Info] AS - CASE WHEN [SqlHandle] IS NOT NULL - THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; '' - ELSE ''N/A'' END, - QueryHash binary(8), - [Query Hash More Info] AS - CASE WHEN [QueryHash] IS NOT NULL - THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; '' - ELSE ''N/A'' END, - QueryPlanHash binary(8), - StatementStartOffset int, - StatementEndOffset int, - MinReturnedRows bigint, - MaxReturnedRows bigint, - AverageReturnedRows money, - TotalReturnedRows bigint, - QueryText nvarchar(max), - QueryPlan xml, - NumberOfPlans int, - NumberOfDistinctPlans int, - MinGrantKB BIGINT, - MaxGrantKB BIGINT, - MinUsedGrantKB BIGINT, - MaxUsedGrantKB BIGINT, - PercentMemoryGrantUsed MONEY, - AvgMaxMemoryGrant MONEY, - MinSpills BIGINT, - MaxSpills BIGINT, - TotalSpills BIGINT, - AvgSpills MONEY, - QueryPlanCost FLOAT, - CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))'; - - IF @Debug = 1 - BEGIN - PRINT SUBSTRING(@insert_sql, 0, 4000); - PRINT SUBSTRING(@insert_sql, 4000, 8000); - PRINT SUBSTRING(@insert_sql, 8000, 12000); - PRINT SUBSTRING(@insert_sql, 12000, 16000); - PRINT SUBSTRING(@insert_sql, 16000, 20000); - PRINT SUBSTRING(@insert_sql, 20000, 24000); - PRINT SUBSTRING(@insert_sql, 24000, 28000); - PRINT SUBSTRING(@insert_sql, 28000, 32000); - PRINT SUBSTRING(@insert_sql, 32000, 36000); - PRINT SUBSTRING(@insert_sql, 36000, 40000); - END; - - EXEC sp_executesql @insert_sql ; - - IF @CheckDateOverride IS NULL - BEGIN - SET @CheckDateOverride = SYSDATETIMEOFFSET(); - END; - - - SET @insert_sql = N' IF EXISTS(SELECT * FROM ' - + @OutputDatabaseName - + N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' - + @OutputSchemaName + N''') ' - + N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;' - + 'INSERT ' - + @OutputDatabaseName + '.' - + @OutputSchemaName + '.' - + @OutputTableName - + N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' - + N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' - + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' - + N'SELECT TOP (@Top) ' - + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', @CheckDateOverride, ' - + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', ' - + N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' - + N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' - + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' - + N' FROM ##BlitzCacheProcs ' - + N' WHERE 1=1 '; - - IF @MinimumExecutionCount IS NOT NULL - BEGIN - SET @insert_sql += N' AND ExecutionCount >= @MinimumExecutionCount '; - END; - - IF @MinutesBack IS NOT NULL - BEGIN - SET @insert_sql += N' AND LastExecutionTime >= DATEADD(MINUTE, @min_back, GETDATE() ) '; - END; - - SET @insert_sql += N' AND SPID = @@SPID '; - - SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU ' - WHEN N'reads' THEN N' TotalReads ' - WHEN N'writes' THEN N' TotalWrites ' - WHEN N'duration' THEN N' TotalDuration ' - WHEN N'executions' THEN N' ExecutionCount ' - WHEN N'compiles' THEN N' PlanCreationTime ' - WHEN N'memory grant' THEN N' MaxGrantKB' - WHEN N'spills' THEN N' MaxSpills' - WHEN N'avg cpu' THEN N' AverageCPU' - WHEN N'avg reads' THEN N' AverageReads' - WHEN N'avg writes' THEN N' AverageWrites' - WHEN N'avg duration' THEN N' AverageDuration' - WHEN N'avg executions' THEN N' ExecutionsPerMinute' - WHEN N'avg memory grant' THEN N' AvgMaxMemoryGrant' - WHEN 'avg spills' THEN N' AvgSpills' - END + N' DESC '; - - SET @insert_sql += N' OPTION (RECOMPILE) ; '; - - IF @Debug = 1 - BEGIN - PRINT SUBSTRING(@insert_sql, 0, 4000); - PRINT SUBSTRING(@insert_sql, 4000, 8000); - PRINT SUBSTRING(@insert_sql, 8000, 12000); - PRINT SUBSTRING(@insert_sql, 12000, 16000); - PRINT SUBSTRING(@insert_sql, 16000, 20000); - PRINT SUBSTRING(@insert_sql, 20000, 24000); - PRINT SUBSTRING(@insert_sql, 24000, 28000); - PRINT SUBSTRING(@insert_sql, 28000, 32000); - PRINT SUBSTRING(@insert_sql, 32000, 36000); - PRINT SUBSTRING(@insert_sql, 36000, 40000); - END; - - EXEC sp_executesql @insert_sql, N'@Top INT, @min_duration INT, @min_back INT, @CheckDateOverride DATETIMEOFFSET, @MinimumExecutionCount INT', @Top, @DurationFilter_i, @MinutesBack, @CheckDateOverride, @MinimumExecutionCount; - - RETURN; -END; -ELSE IF @ExportToExcel = 1 -BEGIN - RAISERROR('Displaying results with Excel formatting (no plans).', 0, 1) WITH NOWAIT; - - /* excel output */ - UPDATE ##BlitzCacheProcs - SET QueryText = SUBSTRING(REPLACE(REPLACE(REPLACE(LTRIM(RTRIM(QueryText)),' ','<>'),'><',''),'<>',' '), 1, 32000) - OPTION(RECOMPILE); + /* excel output */ + UPDATE ##BlitzCacheProcs + SET QueryText = SUBSTRING(REPLACE(REPLACE(REPLACE(LTRIM(RTRIM(QueryText)),' ','<>'),'><',''),'<>',' '), 1, 32000) + OPTION(RECOMPILE); SET @sql = N' SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; @@ -14668,31 +15183,31 @@ BEGIN missing_indexes AS [Missing Indexes], implicit_conversion_info AS [Implicit Conversion Info], cached_execution_parameters AS [Cached Execution Parameters], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS MONEY), 1), N''.00'', N'''') AS [# Executions], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS MONEY), 1), N''.00'', N'''') AS [Executions / Minute], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS MONEY), 1), N''.00'', N'''') AS [Execution Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalCPU) AS MONEY), 1), N''.00'', N'''') AS [Total CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageCPU) AS MONEY), 1), N''.00'', N'''') AS [Avg CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPU) AS MONEY), 1), N''.00'', N'''') AS [CPU Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalDuration) AS MONEY), 1), N''.00'', N'''') AS [Total Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageDuration) AS MONEY), 1), N''.00'', N'''') AS [Avg Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDuration) AS MONEY), 1), N''.00'', N'''') AS [Duration Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReads) AS MONEY), 1), N''.00'', N'''') AS [Total Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReads) AS MONEY), 1), N''.00'', N'''') AS [Avg Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReads) AS MONEY), 1), N''.00'', N'''') AS [Read Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalWrites) AS MONEY), 1), N''.00'', N'''') AS [Total Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageWrites) AS MONEY), 1), N''.00'', N'''') AS [Avg Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWrites) AS MONEY), 1), N''.00'', N'''') AS [Write Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Average Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS MONEY), 1), N''.00'', N'''') AS [Average Max Memory Grant], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinSpills) AS MONEY), 1), N''.00'', N'''') AS [Min Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxSpills) AS MONEY), 1), N''.00'', N'''') AS [Max Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalSpills) AS MONEY), 1), N''.00'', N'''') AS [Total Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1), N''.00'', N'''') AS [Avg Spills], + CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS BIGINT), 1) AS [# Executions], + CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS BIGINT), 1) AS [Executions / Minute], + CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS BIGINT), 1) AS [Execution Weight], + CONVERT(NVARCHAR(30), CAST((TotalCPU) AS BIGINT), 1) AS [Total CPU (ms)], + CONVERT(NVARCHAR(30), CAST((AverageCPU) AS BIGINT), 1) AS [Avg CPU (ms)], + CONVERT(NVARCHAR(30), CAST((PercentCPU) AS BIGINT), 1) AS [CPU Weight], + CONVERT(NVARCHAR(30), CAST((TotalDuration) AS BIGINT), 1) AS [Total Duration (ms)], + CONVERT(NVARCHAR(30), CAST((AverageDuration) AS BIGINT), 1) AS [Avg Duration (ms)], + CONVERT(NVARCHAR(30), CAST((PercentDuration) AS BIGINT), 1) AS [Duration Weight], + CONVERT(NVARCHAR(30), CAST((TotalReads) AS BIGINT), 1) AS [Total Reads], + CONVERT(NVARCHAR(30), CAST((AverageReads) AS BIGINT), 1) AS [Avg Reads], + CONVERT(NVARCHAR(30), CAST((PercentReads) AS BIGINT), 1) AS [Read Weight], + CONVERT(NVARCHAR(30), CAST((TotalWrites) AS BIGINT), 1) AS [Total Writes], + CONVERT(NVARCHAR(30), CAST((AverageWrites) AS BIGINT), 1) AS [Avg Writes], + CONVERT(NVARCHAR(30), CAST((PercentWrites) AS BIGINT), 1) AS [Write Weight], + CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS BIGINT), 1) AS [Average Rows], + CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS BIGINT), 1) AS [Minimum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS BIGINT), 1) AS [Maximum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS BIGINT), 1) AS [Minimum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS BIGINT), 1) AS [Maximum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS BIGINT), 1) AS [Average Max Memory Grant], + CONVERT(NVARCHAR(30), CAST((MinSpills) AS BIGINT), 1) AS [Min Spills], + CONVERT(NVARCHAR(30), CAST((MaxSpills) AS BIGINT), 1) AS [Max Spills], + CONVERT(NVARCHAR(30), CAST((TotalSpills) AS BIGINT), 1) AS [Total Spills], + CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1) AS [Avg Spills], PlanCreationTime AS [Created At], LastExecutionTime AS [Last Execution], PlanHandle AS [Plan Handle], @@ -14735,7 +15250,7 @@ BEGIN CASE WHEN downlevel_estimator = 1 THEN '', 13'' ELSE '''' END + CASE WHEN implicit_conversions = 1 THEN '', 14'' ELSE '''' END + CASE WHEN tvf_join = 1 THEN '', 17'' ELSE '''' END + - CASE WHEN plan_multiple_plans = 1 THEN '', 21'' ELSE '''' END + + CASE WHEN plan_multiple_plans > 0 THEN '', 21'' ELSE '''' END + CASE WHEN unmatched_index_count > 0 THEN '', 22'' ELSE '''' END + CASE WHEN is_trivial = 1 THEN '', 24'' ELSE '''' END + CASE WHEN is_forced_serial = 1 THEN '', 25'' ELSE '''' END + @@ -14782,49 +15297,49 @@ BEGIN END; SET @columns += N' - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS MONEY), 1), N''.00'', N'''') AS [# Executions], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS MONEY), 1), N''.00'', N'''') AS [Executions / Minute], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS MONEY), 1), N''.00'', N'''') AS [Execution Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((SerialDesiredMemory) AS MONEY), 1), N''.00'', N'''') AS [Serial Desired Memory], - REPLACE(CONVERT(NVARCHAR(30), CAST((SerialRequiredMemory) AS MONEY), 1), N''.00'', N'''') AS [Serial Required Memory], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalCPU) AS MONEY), 1), N''.00'', N'''') AS [Total CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageCPU) AS MONEY), 1), N''.00'', N'''') AS [Avg CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPU) AS MONEY), 1), N''.00'', N'''') AS [CPU Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalDuration) AS MONEY), 1), N''.00'', N'''') AS [Total Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageDuration) AS MONEY), 1), N''.00'', N'''') AS [Avg Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDuration) AS MONEY), 1), N''.00'', N'''') AS [Duration Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReads) AS MONEY), 1), N''.00'', N'''') AS [Total Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReads) AS MONEY), 1), N''.00'', N'''') AS [Average Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReads) AS MONEY), 1), N''.00'', N'''') AS [Read Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalWrites) AS MONEY), 1), N''.00'', N'''') AS [Total Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageWrites) AS MONEY), 1), N''.00'', N'''') AS [Average Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWrites) AS MONEY), 1), N''.00'', N'''') AS [Write Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutionsByType) AS MONEY), 1), N''.00'', N'''') AS [% Executions (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPUByType) AS MONEY), 1), N''.00'', N'''') AS [% CPU (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDurationByType) AS MONEY), 1), N''.00'', N'''') AS [% Duration (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReadsByType) AS MONEY), 1), N''.00'', N'''') AS [% Reads (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWritesByType) AS MONEY), 1), N''.00'', N'''') AS [% Writes (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Total Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Avg Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Min Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Max Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS MONEY), 1), N''.00'', N'''') AS [Average Max Memory Grant], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinSpills) AS MONEY), 1), N''.00'', N'''') AS [Min Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxSpills) AS MONEY), 1), N''.00'', N'''') AS [Max Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalSpills) AS MONEY), 1), N''.00'', N'''') AS [Total Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1), N''.00'', N'''') AS [Avg Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((NumberOfPlans) AS MONEY), 1), N''.00'', N'''') AS [# Plans], - REPLACE(CONVERT(NVARCHAR(30), CAST((NumberOfDistinctPlans) AS MONEY), 1), N''.00'', N'''') AS [# Distinct Plans], + CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS BIGINT), 1) AS [# Executions], + CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS BIGINT), 1) AS [Executions / Minute], + CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS BIGINT), 1) AS [Execution Weight], + CONVERT(NVARCHAR(30), CAST((SerialDesiredMemory) AS BIGINT), 1) AS [Serial Desired Memory], + CONVERT(NVARCHAR(30), CAST((SerialRequiredMemory) AS BIGINT), 1) AS [Serial Required Memory], + CONVERT(NVARCHAR(30), CAST((TotalCPU) AS BIGINT), 1) AS [Total CPU (ms)], + CONVERT(NVARCHAR(30), CAST((AverageCPU) AS BIGINT), 1) AS [Avg CPU (ms)], + CONVERT(NVARCHAR(30), CAST((PercentCPU) AS BIGINT), 1) AS [CPU Weight], + CONVERT(NVARCHAR(30), CAST((TotalDuration) AS BIGINT), 1) AS [Total Duration (ms)], + CONVERT(NVARCHAR(30), CAST((AverageDuration) AS BIGINT), 1) AS [Avg Duration (ms)], + CONVERT(NVARCHAR(30), CAST((PercentDuration) AS BIGINT), 1) AS [Duration Weight], + CONVERT(NVARCHAR(30), CAST((TotalReads) AS BIGINT), 1) AS [Total Reads], + CONVERT(NVARCHAR(30), CAST((AverageReads) AS BIGINT), 1) AS [Average Reads], + CONVERT(NVARCHAR(30), CAST((PercentReads) AS BIGINT), 1) AS [Read Weight], + CONVERT(NVARCHAR(30), CAST((TotalWrites) AS BIGINT), 1) AS [Total Writes], + CONVERT(NVARCHAR(30), CAST((AverageWrites) AS BIGINT), 1) AS [Average Writes], + CONVERT(NVARCHAR(30), CAST((PercentWrites) AS BIGINT), 1) AS [Write Weight], + CONVERT(NVARCHAR(30), CAST((PercentExecutionsByType) AS BIGINT), 1) AS [% Executions (Type)], + CONVERT(NVARCHAR(30), CAST((PercentCPUByType) AS BIGINT), 1) AS [% CPU (Type)], + CONVERT(NVARCHAR(30), CAST((PercentDurationByType) AS BIGINT), 1) AS [% Duration (Type)], + CONVERT(NVARCHAR(30), CAST((PercentReadsByType) AS BIGINT), 1) AS [% Reads (Type)], + CONVERT(NVARCHAR(30), CAST((PercentWritesByType) AS BIGINT), 1) AS [% Writes (Type)], + CONVERT(NVARCHAR(30), CAST((TotalReturnedRows) AS BIGINT), 1) AS [Total Rows], + CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS BIGINT), 1) AS [Avg Rows], + CONVERT(NVARCHAR(30), CAST((MinReturnedRows) AS BIGINT), 1) AS [Min Rows], + CONVERT(NVARCHAR(30), CAST((MaxReturnedRows) AS BIGINT), 1) AS [Max Rows], + CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS BIGINT), 1) AS [Minimum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS BIGINT), 1) AS [Maximum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS BIGINT), 1) AS [Minimum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS BIGINT), 1) AS [Maximum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS BIGINT), 1) AS [Average Max Memory Grant], + CONVERT(NVARCHAR(30), CAST((MinSpills) AS BIGINT), 1) AS [Min Spills], + CONVERT(NVARCHAR(30), CAST((MaxSpills) AS BIGINT), 1) AS [Max Spills], + CONVERT(NVARCHAR(30), CAST((TotalSpills) AS BIGINT), 1) AS [Total Spills], + CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1) AS [Avg Spills], + CONVERT(NVARCHAR(30), CAST((NumberOfPlans) AS BIGINT), 1) AS [# Plans], + CONVERT(NVARCHAR(30), CAST((NumberOfDistinctPlans) AS BIGINT), 1) AS [# Distinct Plans], PlanCreationTime AS [Created At], LastExecutionTime AS [Last Execution], - REPLACE(CONVERT(NVARCHAR(30), CAST((CachedPlanSize) AS MONEY), 1), N''.00'', N'''') AS [Cached Plan Size (KB)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileTime) AS MONEY), 1), N''.00'', N'''') AS [Compile Time (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileCPU) AS MONEY), 1), N''.00'', N'''') AS [Compile CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileMemory) AS MONEY), 1), N''.00'', N'''') AS [Compile memory (KB)], + CONVERT(NVARCHAR(30), CAST((CachedPlanSize) AS BIGINT), 1) AS [Cached Plan Size (KB)], + CONVERT(NVARCHAR(30), CAST((CompileTime) AS BIGINT), 1) AS [Compile Time (ms)], + CONVERT(NVARCHAR(30), CAST((CompileCPU) AS BIGINT), 1) AS [Compile CPU (ms)], + CONVERT(NVARCHAR(30), CAST((CompileMemory) AS BIGINT), 1) AS [Compile memory (KB)], COALESCE(SetOptions, '''') AS [SET Options], PlanHandle AS [Plan Handle], SqlHandle AS [SQL Handle], @@ -15181,7 +15696,7 @@ BEGIN IF EXISTS (SELECT 1/0 FROM ##BlitzCacheProcs - WHERE plan_multiple_plans = 1 + WHERE plan_multiple_plans > 0 AND SPID = @@SPID) INSERT INTO ##BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL, Details) VALUES (@@SPID, @@ -15952,7 +16467,10 @@ IF @Debug = 1 END; - + IF @OutputDatabaseName IS NOT NULL + AND @OutputSchemaName IS NOT NULL + AND @OutputTableName IS NOT NULL + GOTO OutputResultsToTable; RETURN; --Avoid going into the AllSort GOTO /*Begin code to sort by all*/ @@ -16047,29 +16565,6 @@ IF OBJECT_ID('tempdb.. #bou_allsort') IS NULL ); END; -DECLARE @AllSortSql NVARCHAR(MAX) = N''; -DECLARE @MemGrant BIT; -SELECT @MemGrant = CASE WHEN ( - ( @v < 11 ) - OR ( - @v = 11 - AND @build < 6020 - ) - OR ( - @v = 12 - AND @build < 5000 - ) - OR ( - @v = 13 - AND @build < 1601 - ) - ) THEN 0 - ELSE 1 - END; - -DECLARE @Spills BIT; -SELECT @Spills = CASE WHEN (@v >= 15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026)) THEN 1 ELSE 0 END; - IF LOWER(@SortOrder) = 'all' BEGIN @@ -16082,7 +16577,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''cpu'', @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''cpu'', @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''cpu'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16093,7 +16588,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''reads'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16104,7 +16599,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''writes'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16115,7 +16610,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''duration'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16126,13 +16621,13 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''executions'' WHERE Pattern IS NULL OPTION(RECOMPILE); '; - IF @MemGrant = 0 + IF @VersionShowsMemoryGrants = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -16151,7 +16646,7 @@ SET @AllSortSql += N' END; - IF @MemGrant = 1 + IF @VersionShowsMemoryGrants = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -16160,7 +16655,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -16180,7 +16675,7 @@ SET @AllSortSql += N' END; - IF @Spills = 0 + IF @VersionShowsSpills = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -16199,7 +16694,7 @@ SET @AllSortSql += N' END; - IF @Spills = 1 + IF @VersionShowsSpills = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -16208,7 +16703,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -16250,7 +16745,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg cpu'', @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg cpu'', @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg cpu'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16261,7 +16756,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg reads'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16272,7 +16767,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg writes'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16283,7 +16778,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg duration'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16294,13 +16789,13 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg executions'' WHERE Pattern IS NULL OPTION(RECOMPILE); '; - IF @MemGrant = 0 + IF @VersionShowsMemoryGrants = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -16319,7 +16814,7 @@ SET @AllSortSql += N' END; - IF @MemGrant = 1 + IF @VersionShowsMemoryGrants = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -16328,7 +16823,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -16348,7 +16843,7 @@ SET @AllSortSql += N' END; - IF @Spills = 0 + IF @VersionShowsSpills = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -16367,7 +16862,7 @@ SET @AllSortSql += N' END; - IF @Spills = 1 + IF @VersionShowsSpills = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -16376,7 +16871,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -16419,11 +16914,209 @@ END; PRINT SUBSTRING(@AllSortSql, 36000, 40000); END; - EXEC sys.sp_executesql @stmt = @AllSortSql, @params = N'@i_DatabaseName NVARCHAR(128), @i_Top INT', @i_DatabaseName = @DatabaseName, @i_Top = @Top; + EXEC sys.sp_executesql @stmt = @AllSortSql, @params = N'@i_DatabaseName NVARCHAR(128), @i_Top INT, @i_SkipAnalysis BIT, @i_OutputDatabaseName NVARCHAR(258), @i_OutputSchemaName NVARCHAR(258), @i_OutputTableName NVARCHAR(258)', + @i_DatabaseName = @DatabaseName, @i_Top = @Top, @i_SkipAnalysis = @SkipAnalysis, @i_OutputDatabaseName = @OutputDatabaseName, @i_OutputSchemaName = @OutputSchemaName, @i_OutputTableName = @OutputTableName; /*End of AllSort section*/ +/*Begin code to sort by all*/ +OutputResultsToTable: + +IF @OutputDatabaseName IS NOT NULL + AND @OutputSchemaName IS NOT NULL + AND @OutputTableName IS NOT NULL +BEGIN + RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT; + + SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName), + @OutputSchemaName = QUOTENAME(@OutputSchemaName), + @OutputTableName = QUOTENAME(@OutputTableName); + + /* send results to a table */ + DECLARE @insert_sql NVARCHAR(MAX) = N'' ; + + SET @insert_sql = 'USE ' + + @OutputDatabaseName + + '; IF EXISTS(SELECT * FROM ' + + @OutputDatabaseName + + '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' + + @OutputSchemaName + + ''') AND NOT EXISTS (SELECT * FROM ' + + @OutputDatabaseName + + '.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = ''' + + @OutputSchemaName + ''' AND QUOTENAME(TABLE_NAME) = ''' + + @OutputTableName + ''') CREATE TABLE ' + + @OutputSchemaName + '.' + + @OutputTableName + + N'(ID bigint NOT NULL IDENTITY(1,1), + ServerName NVARCHAR(258), + CheckDate DATETIMEOFFSET, + Version NVARCHAR(258), + QueryType NVARCHAR(258), + Warnings varchar(max), + DatabaseName sysname, + SerialDesiredMemory float, + SerialRequiredMemory float, + AverageCPU bigint, + TotalCPU bigint, + PercentCPUByType money, + CPUWeight money, + AverageDuration bigint, + TotalDuration bigint, + DurationWeight money, + PercentDurationByType money, + AverageReads bigint, + TotalReads bigint, + ReadWeight money, + PercentReadsByType money, + AverageWrites bigint, + TotalWrites bigint, + WriteWeight money, + PercentWritesByType money, + ExecutionCount bigint, + ExecutionWeight money, + PercentExecutionsByType money,' + N' + ExecutionsPerMinute money, + PlanCreationTime datetime, + PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()), + LastExecutionTime datetime, + PlanHandle varbinary(64), + [Remove Plan Handle From Cache] AS + CASE WHEN [PlanHandle] IS NOT NULL + THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');'' + ELSE ''N/A'' END, + SqlHandle varbinary(64), + [Remove SQL Handle From Cache] AS + CASE WHEN [SqlHandle] IS NOT NULL + THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');'' + ELSE ''N/A'' END, + [SQL Handle More Info] AS + CASE WHEN [SqlHandle] IS NOT NULL + THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; '' + ELSE ''N/A'' END, + QueryHash binary(8), + [Query Hash More Info] AS + CASE WHEN [QueryHash] IS NOT NULL + THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; '' + ELSE ''N/A'' END, + QueryPlanHash binary(8), + StatementStartOffset int, + StatementEndOffset int, + MinReturnedRows bigint, + MaxReturnedRows bigint, + AverageReturnedRows money, + TotalReturnedRows bigint, + QueryText nvarchar(max), + QueryPlan xml, + NumberOfPlans int, + NumberOfDistinctPlans int, + MinGrantKB BIGINT, + MaxGrantKB BIGINT, + MinUsedGrantKB BIGINT, + MaxUsedGrantKB BIGINT, + PercentMemoryGrantUsed MONEY, + AvgMaxMemoryGrant MONEY, + MinSpills BIGINT, + MaxSpills BIGINT, + TotalSpills BIGINT, + AvgSpills MONEY, + QueryPlanCost FLOAT, + CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))'; + + IF @Debug = 1 + BEGIN + PRINT SUBSTRING(@insert_sql, 0, 4000); + PRINT SUBSTRING(@insert_sql, 4000, 8000); + PRINT SUBSTRING(@insert_sql, 8000, 12000); + PRINT SUBSTRING(@insert_sql, 12000, 16000); + PRINT SUBSTRING(@insert_sql, 16000, 20000); + PRINT SUBSTRING(@insert_sql, 20000, 24000); + PRINT SUBSTRING(@insert_sql, 24000, 28000); + PRINT SUBSTRING(@insert_sql, 28000, 32000); + PRINT SUBSTRING(@insert_sql, 32000, 36000); + PRINT SUBSTRING(@insert_sql, 36000, 40000); + END; + + EXEC sp_executesql @insert_sql ; + + IF @CheckDateOverride IS NULL + BEGIN + SET @CheckDateOverride = SYSDATETIMEOFFSET(); + END; + + + SET @insert_sql = N' IF EXISTS(SELECT * FROM ' + + @OutputDatabaseName + + N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' + + @OutputSchemaName + N''') ' + + N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;' + + 'INSERT ' + + @OutputDatabaseName + '.' + + @OutputSchemaName + '.' + + @OutputTableName + + N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + + N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' + + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + N'SELECT TOP (@Top) ' + + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', @CheckDateOverride, ' + + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', ' + + N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + + N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' + + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + N' FROM ##BlitzCacheProcs ' + + N' WHERE 1=1 '; + + IF @MinimumExecutionCount IS NOT NULL + BEGIN + SET @insert_sql += N' AND ExecutionCount >= @MinimumExecutionCount '; + END; + + IF @MinutesBack IS NOT NULL + BEGIN + SET @insert_sql += N' AND LastExecutionTime >= DATEADD(MINUTE, @min_back, GETDATE() ) '; + END; + + SET @insert_sql += N' AND SPID = @@SPID '; + + SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU ' + WHEN N'reads' THEN N' TotalReads ' + WHEN N'writes' THEN N' TotalWrites ' + WHEN N'duration' THEN N' TotalDuration ' + WHEN N'executions' THEN N' ExecutionCount ' + WHEN N'compiles' THEN N' PlanCreationTime ' + WHEN N'memory grant' THEN N' MaxGrantKB' + WHEN N'spills' THEN N' MaxSpills' + WHEN N'avg cpu' THEN N' AverageCPU' + WHEN N'avg reads' THEN N' AverageReads' + WHEN N'avg writes' THEN N' AverageWrites' + WHEN N'avg duration' THEN N' AverageDuration' + WHEN N'avg executions' THEN N' ExecutionsPerMinute' + WHEN N'avg memory grant' THEN N' AvgMaxMemoryGrant' + WHEN 'avg spills' THEN N' AvgSpills' + END + N' DESC '; + + SET @insert_sql += N' OPTION (RECOMPILE) ; '; + + IF @Debug = 1 + BEGIN + PRINT SUBSTRING(@insert_sql, 0, 4000); + PRINT SUBSTRING(@insert_sql, 4000, 8000); + PRINT SUBSTRING(@insert_sql, 8000, 12000); + PRINT SUBSTRING(@insert_sql, 12000, 16000); + PRINT SUBSTRING(@insert_sql, 16000, 20000); + PRINT SUBSTRING(@insert_sql, 20000, 24000); + PRINT SUBSTRING(@insert_sql, 24000, 28000); + PRINT SUBSTRING(@insert_sql, 28000, 32000); + PRINT SUBSTRING(@insert_sql, 32000, 36000); + PRINT SUBSTRING(@insert_sql, 36000, 40000); + END; + + EXEC sp_executesql @insert_sql, N'@Top INT, @min_duration INT, @min_back INT, @CheckDateOverride DATETIMEOFFSET, @MinimumExecutionCount INT', @Top, @DurationFilter_i, @MinutesBack, @CheckDateOverride, @MinimumExecutionCount; +END; /* End of writing results to table */ + END; /*Final End*/ GO @@ -16471,7 +17164,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -16557,7 +17250,6 @@ DECLARE @StringToExecute NVARCHAR(MAX), @ObjectFullName NVARCHAR(2000), @BlitzWho NVARCHAR(MAX) = N'EXEC dbo.sp_BlitzWho @ShowSleepingSPIDs = ' + CONVERT(NVARCHAR(1), @ShowSleepingSPIDs) + N';', @BlitzCacheMinutesBack INT, - @BlitzCacheSortOrder VARCHAR(50), @UnquotedOutputServerName NVARCHAR(256) = @OutputServerName , @UnquotedOutputDatabaseName NVARCHAR(256) = @OutputDatabaseName , @UnquotedOutputSchemaName NVARCHAR(256) = @OutputSchemaName ; @@ -17714,8 +18406,9 @@ BEGIN 'Maintenance Tasks Running' AS FindingGroup, 'Backup Running' AS Finding, 'http://www.BrentOzar.com/askbrent/backups/' AS URL, - 'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) is ' + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' - + CASE WHEN COALESCE(s.nt_user_name, s.login_name) IS NOT NULL THEN (' Login: ' + COALESCE(s.nt_user_name, s.login_name) + ' ') ELSE '' END AS Details, + 'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) ' + @LineFeed + + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' + @LineFeed + + CASE WHEN COALESCE(s.nt_user_name, s.login_name) IS NOT NULL THEN (' Login: ' + COALESCE(s.nt_user_name, s.login_name) + ' ') ELSE '' END AS Details, 'KILL ' + CAST(r.session_id AS NVARCHAR(100)) + ';' AS HowToStopIt, pl.query_plan AS QueryPlan, r.start_time AS StartTime, @@ -17853,9 +18546,9 @@ BEGIN ''Long-Running Query Blocking Others'' AS Finding, ''http://www.BrentOzar.com/go/blocking'' AS URL, ''Query in '' + COALESCE(DB_NAME(COALESCE((SELECT TOP 1 dbid FROM sys.dm_exec_sql_text(r.sql_handle)), - (SELECT TOP 1 t.dbid FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) t WHERE spBlocker.spid = tBlocked.blocking_session_id))), ''(Unknown)'') + '' has a last request start time of '' + CAST(s.last_request_start_time AS NVARCHAR(100)) + ''. Query follows:'' ' + (SELECT TOP 1 t.dbid FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) t WHERE spBlocker.spid = tBlocked.blocking_session_id))), ''(Unknown)'') + '' has a last request start time of '' + CAST(s.last_request_start_time AS NVARCHAR(100)) + ''. Query follows: ' + @LineFeed + @LineFeed + - '+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(r.sql_handle)), + '''+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(r.sql_handle)), (SELECT TOP 1 [text] FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) WHERE spBlocker.spid = tBlocked.blocking_session_id), '''') AS NVARCHAR(2000)) AS Details, ''KILL '' + CAST(tBlocked.blocking_session_id AS NVARCHAR(100)) + '';'' AS HowToStopIt, (SELECT TOP 1 query_plan FROM sys.dm_exec_query_plan(r.plan_handle)) AS QueryPlan, @@ -17873,7 +18566,9 @@ BEGIN INNER JOIN sys.dm_exec_sessions s ON tBlocked.blocking_session_id = s.session_id LEFT OUTER JOIN sys.dm_exec_requests r ON s.session_id = r.session_id INNER JOIN sys.dm_exec_connections c ON s.session_id = c.session_id - WHERE tBlocked.wait_type LIKE ''LCK%'' AND tBlocked.wait_duration_ms > 30000;'; + WHERE tBlocked.wait_type LIKE ''LCK%'' AND tBlocked.wait_duration_ms > 30000 + /* And the blocking session ID is not blocked by anyone else: */ + AND NOT EXISTS(SELECT * FROM sys.dm_os_waiting_tasks tBlocking WHERE s.session_id = tBlocking.session_id AND tBlocking.session_id <> tBlocking.blocking_session_id AND tBlocking.blocking_session_id IS NOT NULL);'; EXECUTE sp_executesql @StringToExecute; END; @@ -17941,17 +18636,18 @@ BEGIN SET @StringToExecute = N'INSERT INTO #BlitzFirstResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, QueryText, OpenTransactionCount) SELECT 37 AS CheckId, 50 AS Priority, - ''Implicit Transactions'' AS FindingsGroup, - ''Queries were found running using implicit transactions'', + ''Query Problems'' AS FindingsGroup, + ''Implicit Transactions'', ''https://www.brentozar.com/go/ImplicitTransactions/'' AS URL, - ''Database: '' + DB_NAME(s.database_id) + '' '' + - ''Host: '' + s.[host_name] + '' '' + - ''Program: '' + s.[program_name] + '' '' + + ''Database: '' + DB_NAME(s.database_id) + '' '' + CHAR(13) + CHAR(10) + + ''Host: '' + s.[host_name] + '' '' + CHAR(13) + CHAR(10) + + ''Program: '' + s.[program_name] + '' '' + CHAR(13) + CHAR(10) + CONVERT(NVARCHAR(10), s.open_transaction_count) + '' open transactions since: '' + CONVERT(NVARCHAR(30), tat.transaction_begin_time) + ''. '' AS Details, - ''Check client configuration options'' AS HowToStopit, + ''Run sp_BlitzWho and check the is_implicit_transaction column to spot the culprits. +If one of them is a lead blocker, consider killing that query.'' AS HowToStopit, tat.transaction_begin_time, s.login_name, s.nt_user_name, @@ -19169,55 +19865,6 @@ BEGIN RAISERROR('Calling sp_BlitzCache',10,1) WITH NOWAIT; - /* Set the sp_BlitzCache sort order based on their top wait type */ - - /* First, check for poison waits - CheckID 30 */ - IF EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 30) - BEGIN - SELECT TOP 1 @BlitzCacheSortOrder = CASE - WHEN Finding = 'Poison Wait Detected: RESOURCE_SEMAPHORE' AND @memGrantSortSupported = 1 THEN 'memory grant' - WHEN Finding = 'Poison Wait Detected: RESOURCE_SEMAPHORE_QUERY_COMPILE' AND @memGrantSortSupported = 1 THEN 'memory grant' - WHEN Finding = 'Poison Wait Detected: THREADPOOL' THEN 'executions' - WHEN Finding = 'Poison Wait Detected: LOG_RATE_GOVERNOR' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_CATCHUP_THROTTLE' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_COMMIT_ACK' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_ROLLBACK_ACK' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_SLOW_SECONDARY_THROTTLE' THEN 'writes' - ELSE NULL - END - FROM #BlitzFirstResults - WHERE CheckID = 30 - ORDER BY DetailsInt DESC; - END; - - /* Too much free memory - which probably indicates queries finished w/huge grants - CheckID 34 */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 34) AND @memGrantSortSupported = 1 - SET @BlitzCacheSortOrder = 'memory grant'; - - /* Next, Compilations/Sec High - CheckID 15 and 16 */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID IN (15,16)) - SET @BlitzCacheSortOrder = 'recent compilations'; - - /* Still not set? Use the top wait type. */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 6) - BEGIN - SELECT TOP 1 @BlitzCacheSortOrder = CASE - WHEN Finding = 'ASYNC_NETWORK_IO' THEN 'duration' - WHEN Finding = 'CXPACKET' THEN 'reads' - WHEN Finding = 'LATCH_EX' THEN 'reads' - WHEN Finding LIKE 'LCK%' THEN 'duration' - WHEN Finding LIKE 'PAGEIOLATCH%' THEN 'reads' - WHEN Finding = 'SOS_SCHEDULER_YIELD' THEN 'cpu' - WHEN Finding = 'WRITELOG' THEN 'writes' - ELSE NULL - END - FROM #BlitzFirstResults - WHERE CheckID = 6 - ORDER BY DetailsInt DESC; - END; - /* Still null? Just use the default. */ - - /* If they have an newer version of sp_BlitzCache that supports @MinutesBack and @CheckDateOverride */ IF EXISTS (SELECT * FROM sys.objects o @@ -19241,23 +19888,15 @@ BEGIN IF @BlitzCacheMinutesBack IS NULL OR @BlitzCacheMinutesBack < 1 OR @BlitzCacheMinutesBack > 60 SET @BlitzCacheMinutesBack = 15; - IF @BlitzCacheSortOrder IS NOT NULL - EXEC sp_BlitzCache - @OutputDatabaseName = @UnquotedOutputDatabaseName, - @OutputSchemaName = @UnquotedOutputSchemaName, - @OutputTableName = @OutputTableNameBlitzCache, - @CheckDateOverride = @StartSampleTime, - @SortOrder = @BlitzCacheSortOrder, - @MinutesBack = @BlitzCacheMinutesBack, - @Debug = @Debug; - ELSE - EXEC sp_BlitzCache - @OutputDatabaseName = @UnquotedOutputDatabaseName, - @OutputSchemaName = @UnquotedOutputSchemaName, - @OutputTableName = @OutputTableNameBlitzCache, - @CheckDateOverride = @StartSampleTime, - @MinutesBack = @BlitzCacheMinutesBack, - @Debug = @Debug; + EXEC sp_BlitzCache + @OutputDatabaseName = @UnquotedOutputDatabaseName, + @OutputSchemaName = @UnquotedOutputSchemaName, + @OutputTableName = @OutputTableNameBlitzCache, + @CheckDateOverride = @StartSampleTime, + @SortOrder = 'all', + @SkipAnalysis = 1, + @MinutesBack = @BlitzCacheMinutesBack, + @Debug = @Debug; /* Delete history older than @OutputTableRetentionDays */ SET @StringToExecute = N' IF EXISTS(SELECT * FROM ' @@ -20470,6 +21109,7 @@ ALTER PROCEDURE dbo.sp_BlitzIndex @SkipStatistics BIT = 1, @GetAllDatabases BIT = 0, @BringThePain BIT = 0, + @IgnoreDatabases NVARCHAR(MAX) = NULL, /* Comma-delimited list of databases you want to skip */ @ThresholdMB INT = 250 /* Number of megabytes that an object must be before we include it in basic results */, @OutputType VARCHAR(20) = 'TABLE' , @OutputServerName NVARCHAR(256) = NULL , @@ -20485,7 +21125,7 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -20565,12 +21205,14 @@ DECLARE @collation NVARCHAR(256); DECLARE @NumDatabases INT; DECLARE @LineFeed NVARCHAR(5); DECLARE @DaysUptimeInsertValue NVARCHAR(256); +DECLARE @DatabaseToIgnore NVARCHAR(MAX); SET @LineFeed = CHAR(13) + CHAR(10); SELECT @SQLServerProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)); SELECT @SQLServerEdition =CAST(SERVERPROPERTY('EngineEdition') AS INT); /* We default to online index creates where EngineEdition=3*/ SET @FilterMB=250; SELECT @ScriptVersionName = 'sp_BlitzIndex(TM) v' + @Version + ' - ' + DATENAME(MM, @VersionDate) + ' ' + RIGHT('0'+DATENAME(DD, @VersionDate),2) + ', ' + DATENAME(YY, @VersionDate); +SET @IgnoreDatabases = LTRIM(RTRIM(@IgnoreDatabases)); RAISERROR(N'Starting run. %s', 0,1, @ScriptVersionName) WITH NOWAIT; @@ -20649,6 +21291,9 @@ IF OBJECT_ID('tempdb..#CheckConstraints') IS NOT NULL IF OBJECT_ID('tempdb..#FilteredIndexes') IS NOT NULL DROP TABLE #FilteredIndexes; +IF OBJECT_ID('tempdb..#Ignore_Databases') IS NOT NULL + DROP TABLE #Ignore_Databases + RAISERROR (N'Create temp tables.',0,1) WITH NOWAIT; CREATE TABLE #BlitzIndexResults ( @@ -21131,6 +21776,12 @@ IF OBJECT_ID('tempdb..#FilteredIndexes') IS NOT NULL column_name NVARCHAR(128) NULL ); + CREATE TABLE #Ignore_Databases + ( + DatabaseName NVARCHAR(128), + Reason NVARCHAR(100) + ); + /* Sanitize our inputs */ SELECT @OutputServerName = QUOTENAME(@OutputServerName), @@ -21179,6 +21830,37 @@ IF @GetAllDatabases = 1 END; END; + IF @IgnoreDatabases IS NOT NULL + AND LEN(@IgnoreDatabases) > 0 + BEGIN + RAISERROR(N'Setting up filter to ignore databases', 0, 1) WITH NOWAIT; + SET @DatabaseToIgnore = ''; + + WHILE LEN(@IgnoreDatabases) > 0 + BEGIN + IF PATINDEX('%,%', @IgnoreDatabases) > 0 + BEGIN + SET @DatabaseToIgnore = SUBSTRING(@IgnoreDatabases, 0, PATINDEX('%,%',@IgnoreDatabases)) ; + + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseToIgnore, 'Specified in the @IgnoreDatabases parameter' + OPTION (RECOMPILE) ; + + SET @IgnoreDatabases = SUBSTRING(@IgnoreDatabases, LEN(@DatabaseToIgnore + ',') + 1, LEN(@IgnoreDatabases)) ; + END; + ELSE + BEGIN + SET @DatabaseToIgnore = @IgnoreDatabases ; + SET @IgnoreDatabases = NULL ; + + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseToIgnore, 'Specified in the @IgnoreDatabases parameter' + OPTION (RECOMPILE) ; + END; + END; + + END + END; ELSE BEGIN @@ -21264,16 +21946,72 @@ BEGIN CATCH RETURN; END CATCH; + +RAISERROR (N'Checking partition counts to exclude databases with over 100 partitions',0,1) WITH NOWAIT; +IF @BringThePain = 0 AND @SkipPartitions = 0 AND @TableName IS NULL + BEGIN + DECLARE partition_cursor CURSOR FOR + SELECT dl.DatabaseName + FROM #DatabaseList dl + LEFT OUTER JOIN #Ignore_Databases i ON dl.DatabaseName = i.DatabaseName + WHERE COALESCE(dl.secondary_role_allow_connections_desc, 'OK') <> 'NO' + AND i.DatabaseName IS NULL + + OPEN partition_cursor + FETCH NEXT FROM partition_cursor INTO @DatabaseName + + WHILE @@FETCH_STATUS = 0 + BEGIN + /* Count the total number of partitions */ + SET @dsql = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + SELECT @RowcountOUT = SUM(1) FROM ' + QUOTENAME(@DatabaseName) + '.sys.partitions WHERE partition_number > 1 OPTION ( RECOMPILE );'; + EXEC sp_executesql @dsql, N'@RowcountOUT BIGINT OUTPUT', @RowcountOUT = @Rowcount OUTPUT; + IF @Rowcount > 100 + BEGIN + RAISERROR (N'Skipping database %s because > 100 partitions were found. To check this database, you must set @BringThePain = 1.',0,1,@DatabaseName) WITH NOWAIT; + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseName, 'Over 100 partitions found - use @BringThePain = 1 to analyze' + END; + FETCH NEXT FROM partition_cursor INTO @DatabaseName + END; + CLOSE partition_cursor + DEALLOCATE partition_cursor + + END; + +INSERT #BlitzIndexResults ( Priority, check_id, findings_group, finding, URL, details, index_definition, + index_usage_summary, index_size_summary ) +SELECT 1, 0 , + 'Database Skipped', + i.DatabaseName, + 'http://FirstResponderKit.org', + i.Reason, '', '', '' +FROM #Ignore_Databases i; + + +/* 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 OR @DaysUptime IS NULL + SET @DaysUptime = .01; + +SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPERTY('ServerName')))) + ' Days Uptime: ' + RTRIM(@DaysUptime); + + /* Permission granted or unnecessary? Ok, let's go! */ +RAISERROR (N'Starting loop through databases',0,1) WITH NOWAIT; DECLARE c1 CURSOR LOCAL FAST_FORWARD FOR -SELECT DatabaseName -FROM #DatabaseList -WHERE COALESCE(secondary_role_allow_connections_desc, 'OK') -<> 'NO' -ORDER BY DatabaseName; +SELECT dl.DatabaseName +FROM #DatabaseList dl +LEFT OUTER JOIN #Ignore_Databases i ON dl.DatabaseName = i.DatabaseName +WHERE COALESCE(dl.secondary_role_allow_connections_desc, 'OK') <> 'NO' + AND i.DatabaseName IS NULL +ORDER BY dl.DatabaseName; OPEN c1; FETCH NEXT FROM c1 INTO @DatabaseName; @@ -21291,16 +22029,6 @@ FROM sys.databases AND user_access_desc='MULTI_USER' AND state_desc = 'ONLINE'; -/* 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 OR @DaysUptime IS NULL - SET @DaysUptime = .01; - -SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPERTY('ServerName')))) + ' Days Uptime: ' + RTRIM(@DaysUptime); - ---------------------------------------- --STEP 1: OBSERVE THE PATIENT --This step puts index information into temp tables. @@ -21308,7 +22036,7 @@ SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPE BEGIN TRY BEGIN - --Validate SQL Server Verson + --Validate SQL Server Version IF (SELECT LEFT(@SQLServerProductVersion, CHARINDEX('.',@SQLServerProductVersion,0)-1 @@ -25390,7 +26118,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '2.4', @VersionDate = '20190320'; +SELECT @Version = '2.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) @@ -25546,7 +26274,13 @@ You need to use an Azure storage account, and the path has to look like this: ht DECLARE @d VARCHAR(40), @StringToExecute NVARCHAR(4000); CREATE TABLE #t (id INT NOT NULL); - UPDATE STATISTICS #t WITH ROWCOUNT = 100000000, PAGECOUNT = 100000000; + + /* WITH ROWCOUNT doesn't work on Amazon RDS - see: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2037 */ + 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-' + AND db_id('rdsadmin') IS NULL + UPDATE STATISTICS #t WITH ROWCOUNT = 100000000, PAGECOUNT = 100000000; /*Grab the initial set of XML to parse*/ SET @d = CONVERT(VARCHAR(40), GETDATE(), 109); @@ -26478,14 +27212,14 @@ You need to use an Azure storage account, and the path has to look like this: ht DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en, ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn, NULL AS is_victim, - cao.wait_type AS owner_mode, + cao.wait_type COLLATE DATABASE_DEFAULT AS owner_mode, cao.waiter_type AS owner_waiter_type, cao.owner_activity AS owner_activity, cao.waiter_activity AS owner_waiter_activity, cao.merging AS owner_merging, cao.spilling AS owner_spilling, cao.waiting_to_close AS owner_waiting_to_close, - caw.wait_type AS waiter_mode, + caw.wait_type COLLATE DATABASE_DEFAULT AS waiter_mode, caw.waiter_type AS waiter_waiter_type, caw.owner_activity AS waiter_owner_activity, caw.waiter_activity AS waiter_waiter_activity, @@ -26623,7 +27357,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '7.4', @VersionDate = '20190320'; + SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN diff --git a/Install-Core-Blitz-With-Query-Store.sql b/Install-Core-Blitz-With-Query-Store.sql index fb5aec4e1..88308e7cd 100755 --- a/Install-Core-Blitz-With-Query-Store.sql +++ b/Install-Core-Blitz-With-Query-Store.sql @@ -36,7 +36,7 @@ AS SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '7.4', @VersionDate = '20190320'; + SELECT @Version = '7.6', @VersionDate = '20190702'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -78,7 +78,7 @@ AS @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 + @OutputType ''TABLE''=table | ''COUNT''=row with number found | ''MARKDOWN''=bulleted list | ''SCHEMA''=version and field list | ''XML'' =table output as XML | ''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. @@ -116,8 +116,8 @@ AS 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' */ + END;/* IF @OutputType = 'SCHEMA' */ + ELSE BEGIN DECLARE @StringToExecute NVARCHAR(4000) @@ -150,7 +150,38 @@ AS ,@TraceFileIssue bit -- Flag for Windows OS to help with Linux support ,@IsWindowsOperatingSystem BIT - ,@DaysUptime NUMERIC(23,2); + ,@DaysUptime NUMERIC(23,2) + /* For First Responder Kit consistency check:*/ + ,@spBlitzFullName VARCHAR(1024) + ,@BlitzIsOutdatedComparedToOthers BIT + ,@tsql NVARCHAR(MAX) + ,@VersionCheckModeExistsTSQL NVARCHAR(MAX) + ,@BlitzProcDbName VARCHAR(256) + ,@ExecRet INT + ,@InnerExecRet INT + ,@TmpCnt INT + ,@PreviousComponentName VARCHAR(256) + ,@PreviousComponentFullPath VARCHAR(1024) + ,@CurrentStatementId INT + ,@CurrentComponentSchema VARCHAR(256) + ,@CurrentComponentName VARCHAR(256) + ,@CurrentComponentType VARCHAR(256) + ,@CurrentComponentVersionDate DATETIME2 + ,@CurrentComponentFullName VARCHAR(1024) + ,@CurrentComponentMandatory BIT + ,@MaximumVersionDate DATETIME + ,@StatementCheckName VARCHAR(256) + ,@StatementOutputsCounter BIT + ,@OutputCounterExpectedValue INT + ,@StatementOutputsExecRet BIT + ,@StatementOutputsDateTime BIT + ,@CurrentComponentMandatoryCheckOK BIT + ,@CurrentComponentVersionCheckModeOK BIT + ,@canExitLoop BIT + ,@frkIsConsistent BIT + + /* End of declarations for First Responder Kit consistency check:*/ + ; SET @crlf = NCHAR(13) + NCHAR(10); SET @ResultText = 'sp_Blitz Results: ' + @crlf; @@ -201,6 +232,47 @@ AS Finding NVARCHAR(128) ); + /* First Responder Kit consistency (temporary tables) */ + + IF(OBJECT_ID('tempdb..#FRKObjects') IS NOT NULL) + BEGIN + EXEC sp_executesql N'DROP TABLE #FRKObjects;'; + END; + + -- this one represents FRK objects + CREATE TABLE #FRKObjects ( + DatabaseName VARCHAR(256) NOT NULL, + ObjectSchemaName VARCHAR(256) NULL, + ObjectName VARCHAR(256) NOT NULL, + ObjectType VARCHAR(256) NOT NULL, + MandatoryComponent BIT NOT NULL + ); + + + IF(OBJECT_ID('tempdb..#StatementsToRun4FRKVersionCheck') IS NOT NULL) + BEGIN + EXEC sp_executesql N'DROP TABLE #StatementsToRun4FRKVersionCheck;'; + END; + + + -- This one will contain the statements to be executed + -- order: 1- Mandatory, 2- VersionCheckMode, 3- VersionCheck + + CREATE TABLE #StatementsToRun4FRKVersionCheck ( + StatementId INT IDENTITY(1,1), + CheckName VARCHAR(256), + SubjectName VARCHAR(256), + SubjectFullPath VARCHAR(1024), + StatementText NVARCHAR(MAX), + StatementOutputsCounter BIT, + OutputCounterExpectedValue INT, + StatementOutputsExecRet BIT, + StatementOutputsDateTime BIT + ); + + /* End of First Responder Kit consistency (temporary tables) */ + + /* You can build your own table with a list of checks to skip. For example, you might have some databases that you don't care about, or some checks you don't @@ -2280,7 +2352,7 @@ AS 200 AS Priority , 'Monitoring' AS FindingsGroup , 'Alerts Disabled' AS Finding , - 'https://www.BrentOzar.com/go/alerts/' AS URL , + 'https://BrentOzar.com/go/alert' AS URL , ( 'The following Alert is disabled, please review and enable if desired: ' + name ) AS Details FROM msdb.dbo.sysalerts @@ -4257,6 +4329,513 @@ IF @ProductVersionMajor >= 10 END; END; + +/*This checks that First Responder Kit is consistent. +It assumes that all the objects of the kit resides in the same database, the one in which this SP is stored +It also is ready to check for installation in another schema. +*/ +IF( + NOT EXISTS ( + SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 226 + ) +) +BEGIN + + IF @Debug IN (1, 2) RAISERROR('Running check with id %d',0,1,2000); + + SET @spBlitzFullName = QUOTENAME(DB_NAME()) + '.' +QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)) + '.' + QUOTENAME(OBJECT_NAME(@@PROCID)); + SET @BlitzIsOutdatedComparedToOthers = 0; + SET @tsql = NULL; + SET @VersionCheckModeExistsTSQL = NULL; + SET @BlitzProcDbName = DB_NAME(); + SET @ExecRet = NULL; + SET @InnerExecRet = NULL; + SET @TmpCnt = NULL; + + SET @PreviousComponentName = NULL; + SET @PreviousComponentFullPath = NULL; + SET @CurrentStatementId = NULL; + SET @CurrentComponentSchema = NULL; + SET @CurrentComponentName = NULL; + SET @CurrentComponentType = NULL; + SET @CurrentComponentVersionDate = NULL; + SET @CurrentComponentFullName = NULL; + SET @CurrentComponentMandatory = NULL; + SET @MaximumVersionDate = NULL; + + SET @StatementCheckName = NULL; + SET @StatementOutputsCounter = NULL; + SET @OutputCounterExpectedValue = NULL; + SET @StatementOutputsExecRet = NULL; + SET @StatementOutputsDateTime = NULL; + + SET @CurrentComponentMandatoryCheckOK = NULL; + SET @CurrentComponentVersionCheckModeOK = NULL; + + SET @canExitLoop = 0; + SET @frkIsConsistent = 0; + + + SET @tsql = 'USE ' + QUOTENAME(@BlitzProcDbName) + ';' + @crlf + + 'WITH FRKComponents (' + @crlf + + ' ObjectName,' + @crlf + + ' ObjectType,' + @crlf + + ' MandatoryComponent' + @crlf + + ')' + @crlf + + 'AS (' + @crlf + + ' SELECT ''sp_AllNightLog'',''P'' ,0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''sp_AllNightLog_Setup'', ''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_Blitz'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzBackups'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzCache'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzFirst'',''P'',0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''sp_BlitzIndex'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzLock'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzQueryStore'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzWho'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_DatabaseRestore'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_foreachdb'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_ineachdb'',''P'',0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''SqlServerVersions'',''U'',0' + @crlf + + ')' + @crlf + + 'INSERT INTO #FRKObjects (' + @crlf + + ' DatabaseName,ObjectSchemaName,ObjectName, ObjectType,MandatoryComponent' + @crlf + + ')' + @crlf + + 'SELECT DB_NAME(),SCHEMA_NAME(o.schema_id), c.ObjectName,c.ObjectType,c.MandatoryComponent' + @crlf + + 'FROM ' + @crlf + + ' FRKComponents c' + @crlf + + 'LEFT JOIN ' + @crlf + + ' sys.objects o' + @crlf + + 'ON c.ObjectName = o.[name]' + @crlf + + 'AND c.ObjectType = o.[type]' + @crlf + + --'WHERE o.schema_id IS NOT NULL' + @crlf + + ';' + ; + + EXEC @ExecRet = sp_executesql @tsql ; + + -- TODO: add check for statement success + + -- TODO: based on SP requirements and presence (SchemaName is not null) ==> update MandatoryComponent column + + -- Filling #StatementsToRun4FRKVersionCheck + INSERT INTO #StatementsToRun4FRKVersionCheck ( + CheckName,StatementText,SubjectName,SubjectFullPath, StatementOutputsCounter,OutputCounterExpectedValue,StatementOutputsExecRet,StatementOutputsDateTime + ) + SELECT + 'Mandatory', + 'SELECT @cnt = COUNT(*) FROM #FRKObjects WHERE ObjectSchemaName IS NULL AND ObjectName = ''' + ObjectName + ''' AND MandatoryComponent = 1;', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 1, + 0, + 0, + 0 + FROM #FRKObjects + UNION ALL + SELECT + 'VersionCheckMode', + 'SELECT @cnt = COUNT(*) FROM ' + + QUOTENAME(DatabaseName) + '.sys.all_parameters ' + + 'where object_id = OBJECT_ID(''' + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName) + ''') AND [name] = ''@VersionCheckMode'';', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 1, + 1, + 0, + 0 + FROM #FRKObjects + WHERE ObjectType = 'P' + AND ObjectSchemaName IS NOT NULL + UNION ALL + SELECT + 'VersionCheck', + 'EXEC @ExecRet = ' + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName) + ' @VersionCheckMode = 1 , @VersionDate = @ObjDate OUTPUT;', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 0, + 0, + 1, + 1 + FROM #FRKObjects + WHERE ObjectType = 'P' + AND ObjectSchemaName IS NOT NULL + ; + IF(@Debug in (1,2)) + BEGIN + SELECT * + FROM #StatementsToRun4FRKVersionCheck ORDER BY SubjectName,SubjectFullPath,StatementId -- in case of schema change ; + END; + + + -- loop on queries... + WHILE(@canExitLoop = 0) + BEGIN + SET @CurrentStatementId = NULL; + + SELECT TOP 1 + @StatementCheckName = CheckName, + @CurrentStatementId = StatementId , + @CurrentComponentName = SubjectName, + @CurrentComponentFullName = SubjectFullPath, + @tsql = StatementText, + @StatementOutputsCounter = StatementOutputsCounter, + @OutputCounterExpectedValue = OutputCounterExpectedValue , + @StatementOutputsExecRet = StatementOutputsExecRet, + @StatementOutputsDateTime = StatementOutputsDateTime + FROM #StatementsToRun4FRKVersionCheck + ORDER BY SubjectName, SubjectFullPath,StatementId /* in case of schema change */ + ; + + -- loop exit condition + IF(@CurrentStatementId IS NULL) + BEGIN + BREAK; + END; + + IF @Debug IN (1, 2) RAISERROR(' Statement: %s',0,1,@tsql); + + -- we start a new component + IF(@PreviousComponentName IS NULL OR + (@PreviousComponentName IS NOT NULL AND @PreviousComponentName <> @CurrentComponentName) OR + (@PreviousComponentName IS NOT NULL AND @PreviousComponentName = @CurrentComponentName AND @PreviousComponentFullPath <> @CurrentComponentFullName) + ) + BEGIN + -- reset variables + SET @CurrentComponentMandatoryCheckOK = 0; + SET @CurrentComponentVersionCheckModeOK = 0; + SET @PreviousComponentName = @CurrentComponentName; + SET @PreviousComponentFullPath = @CurrentComponentFullName ; + END; + + IF(@StatementCheckName NOT IN ('Mandatory','VersionCheckMode','VersionCheck')) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (code generator changed)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Your version check failed because a change has been made to the version check code generator.' + @crlf + + 'Error: No handler for check with name "' + ISNULL(@StatementCheckName,'') + '"' AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@StatementCheckName = 'Mandatory') + BEGIN + -- outputs counter + EXEC @ExecRet = sp_executesql @tsql, N'@cnt INT OUTPUT',@cnt = @TmpCnt OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Your version check failed due to dynamic query failure.' + @crlf + + 'Error: following query failed at execution (check if component [' + ISNULL(@CurrentComponentName,@CurrentComponentName) + '] is mandatory and missing)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@TmpCnt <> @OutputCounterExpectedValue) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 227 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Missing: ' + @CurrentComponentName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated version of the First Responder Kit to install it.' AS Details + ; + + -- as it's missing, no value for SubjectFullPath + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectName = @CurrentComponentName ; + CONTINUE; + END; + + SET @CurrentComponentMandatoryCheckOK = 1; + END; + + IF(@StatementCheckName = 'VersionCheckMode') + BEGIN + IF(@CurrentComponentMandatoryCheckOK = 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (unexpectedly modified checks ordering)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because "Mandatory" check has not been completed before for current component' + @crlf + + 'Error: version check mode happenned before "Mandatory" check for component called "' + @CurrentComponentFullName + '"' + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + -- outputs counter + EXEC @ExecRet = sp_executesql @tsql, N'@cnt INT OUTPUT',@cnt = @TmpCnt OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because a change has been made to the code generator.' + @crlf + + 'Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] can run in VersionCheckMode)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@TmpCnt <> @OutputCounterExpectedValue) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 228 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Outdated: ' + @CurrentComponentFullName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Component ' + @CurrentComponentFullName + ' is not at the minimum version required to run this procedure' + @crlf + + 'VersionCheckMode has been introduced in component version date after "20190320". This means its version is lower than or equal to that date.' AS Details; + ; + + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + SET @CurrentComponentVersionCheckModeOK = 1; + END; + + IF(@StatementCheckName = 'VersionCheck') + BEGIN + IF(@CurrentComponentMandatoryCheckOK = 0 OR @CurrentComponentVersionCheckModeOK = 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (unexpectedly modified checks ordering)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because "VersionCheckMode" check has not been completed before for component called "' + @CurrentComponentFullName + '"' + @crlf + + 'Error: VersionCheck happenned before "VersionCheckMode" check for component called "' + @CurrentComponentFullName + '"' + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + EXEC @ExecRet = sp_executesql @tsql , N'@ExecRet INT OUTPUT, @ObjDate DATETIME OUTPUT', @ExecRet = @InnerExecRet OUTPUT, @ObjDate = @CurrentComponentVersionDate OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. The version check failed because a change has been made to the code generator.' + @crlf + + 'Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] is at the expected version)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + + IF(@InnerExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (Failed dynamic SP call to ' + @CurrentComponentFullName + ')' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] is at the expected version)' + @crlf + + 'Return code: ' + CONVERT(VARCHAR(10),@InnerExecRet) + @crlf + + 'T-SQL Query: ' + @crlf + + @tsql AS Details + ; + + -- advance to next component + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + IF(@CurrentComponentVersionDate < @VersionDate) + BEGIN + + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 228 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Outdated: ' + @CurrentComponentFullName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download and install the latest First Responder Kit - you''re running some older code, and it doesn''t get better with age.' AS Details + ; + + RAISERROR('Component %s is outdated',10,1,@CurrentComponentFullName); + -- advance to next component + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + ELSE IF(@CurrentComponentVersionDate > @VersionDate AND @BlitzIsOutdatedComparedToOthers = 0) + BEGIN + SET @BlitzIsOutdatedComparedToOthers = 1; + RAISERROR('Procedure %s is outdated',10,1,@spBlitzFullName); + IF(@MaximumVersionDate IS NULL OR @MaximumVersionDate < @CurrentComponentVersionDate) + BEGIN + SET @MaximumVersionDate = @CurrentComponentVersionDate; + END; + END; + /* Kept for debug purpose: + ELSE + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 2000 AS CheckID , + 250 AS Priority , + 'Informational' AS FindingsGroup , + 'First Responder kit component ' + @CurrentComponentFullName + ' is at the expected version' AS Finding , + 'https://www.BrentOzar.com/blitz/' AS URL , + 'Version date is: ' + CONVERT(VARCHAR(32),@CurrentComponentVersionDate,121) AS Details + ; + END; + */ + END; + + -- could be performed differently to minimize computation + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE StatementId = @CurrentStatementId ; + END; +END; + /*This counts memory dumps and gives min and max date of in view*/ IF @ProductVersionMajor >= 10 @@ -5072,9 +5651,9 @@ IF @ProductVersionMajor >= 10 DB_NAME(s.database_id) + '' has '' + CONVERT(NVARCHAR(20), COUNT_BIG(*)) - + '' open implicit transactions '' - + '' with an oldest begin time of '' - + CONVERT(NVARCHAR(30), MIN(tat.transaction_begin_time)) AS details + + '' open implicit transactions with an oldest begin time of '' + + CONVERT(NVARCHAR(30), MIN(tat.transaction_begin_time)) + + '' Run sp_BlitzWho and check the is_implicit_transaction column to see the culprits.'' AS details FROM sys.dm_tran_active_transactions AS tat LEFT JOIN sys.dm_tran_session_transactions AS tst ON tst.transaction_id = tat.transaction_id @@ -5131,6 +5710,32 @@ IF @ProductVersionMajor >= 10 END; + IF NOT EXISTS ( SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 229 ) + AND CAST(SERVERPROPERTY('Edition') AS NVARCHAR(4000)) LIKE '%Evaluation%' + BEGIN + + IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 216) WITH NOWAIT; + + INSERT INTO #BlitzResults + ( CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT 229 AS CheckID, + 1 AS Priority, + 'Reliability' AS FindingsGroup, + 'Evaluation Edition' AS Finding, + 'https://www.BrentOzar.com/go/workgroup' AS URL, + 'This server will stop working on: ' + CAST(CONVERT(DATETIME, DATEADD(DD, 180, create_date), 102) AS VARCHAR(100)) AS details + FROM sys.server_principals + WHERE sid = 0x010100000000000512000000; + + END; IF @CheckUserDatabaseObjects = 1 @@ -6115,6 +6720,37 @@ IF @ProductVersionMajor >= 10 HAVING COUNT(1) > 0;'; END; --of Check 218. + /* Check 225 - Reliability - Resumable Index Operation Paused */ + IF NOT EXISTS ( + SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL + AND CheckID = 225 + ) + AND EXISTS (SELECT * FROM sys.all_objects WHERE name = 'index_resumable_operations') + BEGIN + IF @Debug IN (1,2) + BEGIN + RAISERROR ('Running CheckId [%d].',0,1,218) WITH NOWAIT; + END + + EXECUTE sp_MSforeachdb 'USE [?]; + SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + INSERT INTO #BlitzResults (CheckID, DatabaseName, Priority, FindingsGroup, Finding, URL, Details) + SELECT 225 AS CheckID + ,''?'' AS DatabaseName + ,200 AS Priority + ,''Reliability'' AS FindingsGroup + ,''Resumable Index Operation Paused'' AS Finding + ,''https://BrentOzar.com/go/resumable'' AS URL + ,iro.state_desc + N'' since '' + CONVERT(NVARCHAR(50), last_pause_time, 120) + '', '' + + CAST(iro.percent_complete AS NVARCHAR(20)) + ''% complete: '' + + CAST(iro.sql_text AS NVARCHAR(1000)) AS Details + FROM sys.index_resumable_operations iro + JOIN sys.objects o ON iro.[object_id] = o.[object_id] + WHERE iro.state <> 0;'; + END; --of Check 225. + --/* Check 220 - Statistics Without Histograms */ --IF NOT EXISTS ( -- SELECT 1 @@ -6673,7 +7309,7 @@ IF @ProductVersionMajor >= 10 (@@SERVERNAME IS NOT NULL AND /* not a named instance */ - CHARINDEX('\',CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128))) = 0 + CHARINDEX(CHAR(92),CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128))) = 0 AND /* not clustered, when computername may be different than the servername */ SERVERPROPERTY('IsClustered') = 0 @@ -8237,6 +8873,25 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1 LEFT OUTER JOIN Results rNext ON r.rownum = rNext.rownum - 1 ORDER BY r.rownum FOR XML PATH(N''); END; + ELSE IF @OutputType = 'XML' + BEGIN + /* --TOURSTOP05-- */ + SELECT [Priority] , + [FindingsGroup] , + [Finding] , + [DatabaseName] , + [URL] , + [Details] , + [QueryPlanFiltered] , + CheckID + FROM #BlitzResults + ORDER BY Priority , + FindingsGroup , + Finding , + DatabaseName , + Details + FOR XML PATH('Result'), ROOT('sp_Blitz_Output'); + END; ELSE IF @OutputType <> 'NONE' BEGIN /* --TOURSTOP05-- */ @@ -8317,7 +8972,7 @@ GO /* --Sample execution call with the most common parameters: -EXEC [dbo].[sp_Blitz] +EXEC [dbo].[sp_Blitz] @CheckUserDatabaseObjects = 1 , @CheckProcedureCache = 0 , @OutputType = 'TABLE' , @@ -8350,7 +9005,7 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '3.4', @VersionDate = '20190320'; + SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -10005,7 +10660,7 @@ CREATE TABLE ##BlitzCacheProcs ( unparameterized_query BIT, near_parallel BIT, plan_warnings BIT, - plan_multiple_plans BIT, + plan_multiple_plans INT, long_running BIT, downlevel_estimator BIT, implicit_conversions BIT, @@ -10122,7 +10777,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) @@ -10762,7 +11417,7 @@ BEGIN unparameterized_query BIT, near_parallel BIT, plan_warnings BIT, - plan_multiple_plans BIT, + plan_multiple_plans INT, long_running BIT, downlevel_estimator BIT, implicit_conversions BIT, @@ -10913,10 +11568,6 @@ IF @SortOrder NOT IN ('cpu', 'avg cpu', 'reads', 'avg reads', 'writes', 'avg wri SET @SortOrder = 'cpu'; END; -SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName), - @OutputSchemaName = QUOTENAME(@OutputSchemaName), - @OutputTableName = QUOTENAME(@OutputTableName); - SET @QueryFilter = LOWER(@QueryFilter); IF LEFT(@QueryFilter, 3) NOT IN ('all', 'sta', 'pro', 'fun') @@ -10931,6 +11582,25 @@ IF @SkipAnalysis = 1 SET @HideSummary = 1; END; +DECLARE @AllSortSql NVARCHAR(MAX) = N''; +DECLARE @VersionShowsMemoryGrants BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') + SET @VersionShowsMemoryGrants = 1; +ELSE + SET @VersionShowsMemoryGrants = 0; + +DECLARE @VersionShowsSpills BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') + SET @VersionShowsSpills = 1; +ELSE + SET @VersionShowsSpills = 0; + +DECLARE @VersionShowsAirQuoteActualPlans BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') + SET @VersionShowsAirQuoteActualPlans = 1; +ELSE + SET @VersionShowsAirQuoteActualPlans = 0; + IF @Reanalyze = 1 AND OBJECT_ID('tempdb..##BlitzCacheResults') IS NULL BEGIN RAISERROR(N'##BlitzCacheResults does not exist, can''t reanalyze', 0, 1) WITH NOWAIT; @@ -10955,6 +11625,9 @@ IF @Reanalyze = 1 GOTO Results; END; + + + IF @SortOrder IN ('all', 'all avg') BEGIN RAISERROR(N'Checking all sort orders, please be patient', 0, 1) WITH NOWAIT; @@ -11584,22 +12257,15 @@ SELECT @v = common_version , FROM #checkversion OPTION (RECOMPILE); -IF (@SortOrder IN ('memory grant', 'avg memory grant')) -AND ((@v < 11) -OR (@v = 11 AND @build < 6020) -OR (@v = 12 AND @build < 5000) -OR (@v = 13 AND @build < 1601)) +IF (@SortOrder IN ('memory grant', 'avg memory grant')) AND @VersionShowsMemoryGrants = 0 BEGIN RAISERROR('Your version of SQL does not support sorting by memory grant or average memory grant. Please use another sort order.', 16, 1); RETURN; END; -IF (@SortOrder IN ('spills', 'avg spills')) -AND (@v < 13 - OR @v = 13 AND @build < 5026 - OR @v = 14 AND @build < 3015) +IF (@SortOrder IN ('spills', 'avg spills') AND @VersionShowsSpills = 0) BEGIN - RAISERROR('Your version of SQL does not support sorting by spills or average spills. Please use another sort order.', 16, 1); + RAISERROR('Your version of SQL does not support sorting by spills. Please use another sort order.', 16, 1); RETURN; END; @@ -11634,8 +12300,19 @@ FROM (SELECT TOP (@Top) x.*, xpa.*, CROSS APPLY (SELECT * FROM sys.dm_exec_plan_attributes(x.plan_handle) AS ixpa WHERE ixpa.attribute = ''dbid'') AS xpa ' + @nl ; + +IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @body += N' CROSS APPLY sys.dm_exec_query_plan_stats(x.plan_handle) AS deqps ' + @nl ; + END + SET @body += N' WHERE 1 = 1 ' + @nl ; +IF EXISTS (SELECT * FROM sys.all_objects o INNER JOIN sys.all_columns c ON o.object_id = c.object_id WHERE o.name = 'dm_hadr_database_replica_states' AND c.name = 'is_primary_replica') + BEGIN + RAISERROR(N'Ignoring readable secondaries databases by default', 0, 1) WITH NOWAIT; + SET @body += N' AND CAST(xpa.value AS INT) NOT IN (select database_id from sys.dm_hadr_database_replica_states where is_primary_replica = 0 AND DATABASEPROPERTYEX(DB_NAME(database_id), ''Updateability'') = ''READ_ONLY'')' + @nl ; + END IF @IgnoreSystemDBs = 1 BEGIN @@ -11750,6 +12427,11 @@ SET @body += N') AS qs CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS st CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp ' + @nl ; +IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @body += N' CROSS APPLY sys.dm_exec_query_plan_stats(qs.plan_handle) AS deqps ' + @nl ; + END + SET @body_where += N' AND pa.attribute = ' + QUOTENAME('dbid', @q ) + @nl ; @@ -11818,7 +12500,7 @@ SELECT TOP (@Top) NULL AS PercentMemoryGrantUsed, NULL AS AvgMaxMemoryGrant,'; - IF @v >=15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026) + IF @VersionShowsSpills = 1 BEGIN RAISERROR(N'Getting spill information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @plans_triggers_select_list += N' @@ -11837,10 +12519,20 @@ SELECT TOP (@Top) NULL AS AvgSpills, ' ; END; - SET @plans_triggers_select_list += - N'st.text AS QueryText , - query_plan AS QueryPlan, - t.t_TotalWorker, + SET @plans_triggers_select_list += + N'st.text AS QueryText ,'; + + IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @plans_triggers_select_list += N' COALESCE(deqps.query_plan, qp.query_plan) AS QueryPlan, ' + @nl ; + END; + ELSE + BEGIN + SET @plans_triggers_select_list += N' qp.query_plan AS QueryPlan, ' + @nl ; + END; + + SET @plans_triggers_select_list += + N't.t_TotalWorker, t.t_TotalElapsed, t.t_TotalReads, t.t_TotalExecs, @@ -11927,8 +12619,7 @@ BEGIN NULL AS LastReturnedRows, ' ; END; - IF (@v = 11 AND @build >= 6020) OR (@v = 12 AND @build >= 5000) OR (@v = 13 AND @build >= 1601) OR (@v >= 14) - + IF @VersionShowsMemoryGrants = 1 BEGIN RAISERROR(N'Getting memory grant information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @sql += N' @@ -11951,7 +12642,7 @@ BEGIN NULL AS AvgMaxMemoryGrant, ' ; END; - IF @v >=15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026) + IF @VersionShowsSpills = 1 BEGIN RAISERROR(N'Getting spill information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @sql += N' @@ -11974,8 +12665,19 @@ BEGIN SUBSTRING(st.text, ( qs.statement_start_offset / 2 ) + 1, ( ( CASE qs.statement_end_offset WHEN -1 THEN DATALENGTH(st.text) ELSE qs.statement_end_offset - END - qs.statement_start_offset ) / 2 ) + 1) AS QueryText , - query_plan AS QueryPlan, + END - qs.statement_start_offset ) / 2 ) + 1) AS QueryText , ' + @nl ; + + + IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @sql += N' COALESCE(deqps.query_plan, qp.query_plan) AS QueryPlan, ' + @nl ; + END + ELSE + BEGIN + SET @sql += N' query_plan AS QueryPlan, ' + @nl ; + END + + SET @sql += N' t.t_TotalWorker, t.t_TotalElapsed, t.t_TotalReads, @@ -12135,6 +12837,9 @@ FROM (SELECT SqlHandle, WHERE x.rn = 1 OPTION (RECOMPILE); +/* + This block was used to delete duplicate queries, but has been removed. + For more info: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2026 WITH d AS ( SELECT SPID, ROW_NUMBER() OVER (PARTITION BY SqlHandle, QueryHash ORDER BY #sortable# DESC) AS rn @@ -12144,7 +12849,8 @@ WHERE SPID = @@SPID DELETE d WHERE d.rn > 1 AND SPID = @@SPID -OPTION (RECOMPILE); +OPTION (RECOMPILE); +*/ '; SELECT @sort = CASE @SortOrder WHEN N'cpu' THEN N'TotalCPU' @@ -12249,11 +12955,11 @@ OPTION (RECOMPILE) ; * metric. */ RAISERROR('Computing CPU, duration, read, and write metrics', 0, 1) WITH NOWAIT; -DECLARE @total_duration MONEY, - @total_cpu MONEY, - @total_reads MONEY, - @total_writes MONEY, - @total_execution_count MONEY; +DECLARE @total_duration BIGINT, + @total_cpu BIGINT, + @total_reads BIGINT, + @total_writes BIGINT, + @total_execution_count BIGINT; SELECT @total_cpu = SUM(TotalCPU), @total_duration = SUM(TotalDuration), @@ -12436,7 +13142,7 @@ RAISERROR(N'Gathering high level plan information', 0, 1) WITH NOWAIT; UPDATE ##BlitzCacheProcs SET NumberOfDistinctPlans = distinct_plan_count, NumberOfPlans = number_of_plans , - plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN 1 END + plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN number_of_plans END FROM ( SELECT COUNT(DISTINCT QueryHash) AS distinct_plan_count, COUNT(QueryHash) AS number_of_plans, @@ -13246,7 +13952,7 @@ WITH XMLNAMESPACES('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS UPDATE ##BlitzCacheProcs SET NumberOfDistinctPlans = distinct_plan_count, NumberOfPlans = number_of_plans, - plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN 1 END + plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN number_of_plans END FROM ( SELECT COUNT(DISTINCT QueryHash) AS distinct_plan_count, COUNT(QueryHash) AS number_of_plans, @@ -14177,7 +14883,7 @@ SET Warnings = SUBSTRING( CASE WHEN downlevel_estimator = 1 THEN ', Downlevel CE' ELSE '' END + CASE WHEN implicit_conversions = 1 THEN ', Implicit Conversions' ELSE '' END + CASE WHEN tvf_join = 1 THEN ', Function Join' ELSE '' END + - CASE WHEN plan_multiple_plans = 1 THEN ', Multiple Plans' ELSE '' END + + CASE WHEN plan_multiple_plans > 0 THEN ', Multiple Plans' + COALESCE(' (' + CAST(plan_multiple_plans AS VARCHAR(10)) + ')', '') ELSE '' END + CASE WHEN is_trivial = 1 THEN ', Trivial Plans' ELSE '' END + CASE WHEN is_forced_serial = 1 THEN ', Forced Serialization' ELSE '' END + CASE WHEN is_key_lookup_expensive = 1 THEN ', Expensive Key Lookup' ELSE '' END + @@ -14255,7 +14961,7 @@ SELECT DISTINCT CASE WHEN downlevel_estimator = 1 THEN ', Downlevel CE' ELSE '' END + CASE WHEN implicit_conversions = 1 THEN ', Implicit Conversions' ELSE '' END + CASE WHEN tvf_join = 1 THEN ', Function Join' ELSE '' END + - CASE WHEN plan_multiple_plans = 1 THEN ', Multiple Plans' ELSE '' END + + CASE WHEN plan_multiple_plans > 0 THEN ', Multiple Plans' + COALESCE(' (' + CAST(plan_multiple_plans AS VARCHAR(10)) + ')', '') ELSE '' END + CASE WHEN is_trivial = 1 THEN ', Trivial Plans' ELSE '' END + CASE WHEN is_forced_serial = 1 THEN ', Forced Serialization' ELSE '' END + CASE WHEN is_key_lookup_expensive = 1 THEN ', Expensive Key Lookup' ELSE '' END + @@ -14346,205 +15052,14 @@ OPTION (RECOMPILE); Results: -IF @OutputDatabaseName IS NOT NULL - AND @OutputSchemaName IS NOT NULL - AND @OutputTableName IS NOT NULL +IF @ExportToExcel = 1 BEGIN - RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT; + RAISERROR('Displaying results with Excel formatting (no plans).', 0, 1) WITH NOWAIT; - /* send results to a table */ - DECLARE @insert_sql NVARCHAR(MAX) = N'' ; - - SET @insert_sql = 'USE ' - + @OutputDatabaseName - + '; IF EXISTS(SELECT * FROM ' - + @OutputDatabaseName - + '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' - + @OutputSchemaName - + ''') AND NOT EXISTS (SELECT * FROM ' - + @OutputDatabaseName - + '.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = ''' - + @OutputSchemaName + ''' AND QUOTENAME(TABLE_NAME) = ''' - + @OutputTableName + ''') CREATE TABLE ' - + @OutputSchemaName + '.' - + @OutputTableName - + N'(ID bigint NOT NULL IDENTITY(1,1), - ServerName NVARCHAR(258), - CheckDate DATETIMEOFFSET, - Version NVARCHAR(258), - QueryType NVARCHAR(258), - Warnings varchar(max), - DatabaseName sysname, - SerialDesiredMemory float, - SerialRequiredMemory float, - AverageCPU bigint, - TotalCPU bigint, - PercentCPUByType money, - CPUWeight money, - AverageDuration bigint, - TotalDuration bigint, - DurationWeight money, - PercentDurationByType money, - AverageReads bigint, - TotalReads bigint, - ReadWeight money, - PercentReadsByType money, - AverageWrites bigint, - TotalWrites bigint, - WriteWeight money, - PercentWritesByType money, - ExecutionCount bigint, - ExecutionWeight money, - PercentExecutionsByType money,' + N' - ExecutionsPerMinute money, - PlanCreationTime datetime, - PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()), - LastExecutionTime datetime, - PlanHandle varbinary(64), - [Remove Plan Handle From Cache] AS - CASE WHEN [PlanHandle] IS NOT NULL - THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');'' - ELSE ''N/A'' END, - SqlHandle varbinary(64), - [Remove SQL Handle From Cache] AS - CASE WHEN [SqlHandle] IS NOT NULL - THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');'' - ELSE ''N/A'' END, - [SQL Handle More Info] AS - CASE WHEN [SqlHandle] IS NOT NULL - THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; '' - ELSE ''N/A'' END, - QueryHash binary(8), - [Query Hash More Info] AS - CASE WHEN [QueryHash] IS NOT NULL - THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; '' - ELSE ''N/A'' END, - QueryPlanHash binary(8), - StatementStartOffset int, - StatementEndOffset int, - MinReturnedRows bigint, - MaxReturnedRows bigint, - AverageReturnedRows money, - TotalReturnedRows bigint, - QueryText nvarchar(max), - QueryPlan xml, - NumberOfPlans int, - NumberOfDistinctPlans int, - MinGrantKB BIGINT, - MaxGrantKB BIGINT, - MinUsedGrantKB BIGINT, - MaxUsedGrantKB BIGINT, - PercentMemoryGrantUsed MONEY, - AvgMaxMemoryGrant MONEY, - MinSpills BIGINT, - MaxSpills BIGINT, - TotalSpills BIGINT, - AvgSpills MONEY, - QueryPlanCost FLOAT, - CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))'; - - IF @Debug = 1 - BEGIN - PRINT SUBSTRING(@insert_sql, 0, 4000); - PRINT SUBSTRING(@insert_sql, 4000, 8000); - PRINT SUBSTRING(@insert_sql, 8000, 12000); - PRINT SUBSTRING(@insert_sql, 12000, 16000); - PRINT SUBSTRING(@insert_sql, 16000, 20000); - PRINT SUBSTRING(@insert_sql, 20000, 24000); - PRINT SUBSTRING(@insert_sql, 24000, 28000); - PRINT SUBSTRING(@insert_sql, 28000, 32000); - PRINT SUBSTRING(@insert_sql, 32000, 36000); - PRINT SUBSTRING(@insert_sql, 36000, 40000); - END; - - EXEC sp_executesql @insert_sql ; - - IF @CheckDateOverride IS NULL - BEGIN - SET @CheckDateOverride = SYSDATETIMEOFFSET(); - END; - - - SET @insert_sql = N' IF EXISTS(SELECT * FROM ' - + @OutputDatabaseName - + N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' - + @OutputSchemaName + N''') ' - + N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;' - + 'INSERT ' - + @OutputDatabaseName + '.' - + @OutputSchemaName + '.' - + @OutputTableName - + N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' - + N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' - + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' - + N'SELECT TOP (@Top) ' - + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', @CheckDateOverride, ' - + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', ' - + N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' - + N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' - + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' - + N' FROM ##BlitzCacheProcs ' - + N' WHERE 1=1 '; - - IF @MinimumExecutionCount IS NOT NULL - BEGIN - SET @insert_sql += N' AND ExecutionCount >= @MinimumExecutionCount '; - END; - - IF @MinutesBack IS NOT NULL - BEGIN - SET @insert_sql += N' AND LastExecutionTime >= DATEADD(MINUTE, @min_back, GETDATE() ) '; - END; - - SET @insert_sql += N' AND SPID = @@SPID '; - - SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU ' - WHEN N'reads' THEN N' TotalReads ' - WHEN N'writes' THEN N' TotalWrites ' - WHEN N'duration' THEN N' TotalDuration ' - WHEN N'executions' THEN N' ExecutionCount ' - WHEN N'compiles' THEN N' PlanCreationTime ' - WHEN N'memory grant' THEN N' MaxGrantKB' - WHEN N'spills' THEN N' MaxSpills' - WHEN N'avg cpu' THEN N' AverageCPU' - WHEN N'avg reads' THEN N' AverageReads' - WHEN N'avg writes' THEN N' AverageWrites' - WHEN N'avg duration' THEN N' AverageDuration' - WHEN N'avg executions' THEN N' ExecutionsPerMinute' - WHEN N'avg memory grant' THEN N' AvgMaxMemoryGrant' - WHEN 'avg spills' THEN N' AvgSpills' - END + N' DESC '; - - SET @insert_sql += N' OPTION (RECOMPILE) ; '; - - IF @Debug = 1 - BEGIN - PRINT SUBSTRING(@insert_sql, 0, 4000); - PRINT SUBSTRING(@insert_sql, 4000, 8000); - PRINT SUBSTRING(@insert_sql, 8000, 12000); - PRINT SUBSTRING(@insert_sql, 12000, 16000); - PRINT SUBSTRING(@insert_sql, 16000, 20000); - PRINT SUBSTRING(@insert_sql, 20000, 24000); - PRINT SUBSTRING(@insert_sql, 24000, 28000); - PRINT SUBSTRING(@insert_sql, 28000, 32000); - PRINT SUBSTRING(@insert_sql, 32000, 36000); - PRINT SUBSTRING(@insert_sql, 36000, 40000); - END; - - EXEC sp_executesql @insert_sql, N'@Top INT, @min_duration INT, @min_back INT, @CheckDateOverride DATETIMEOFFSET, @MinimumExecutionCount INT', @Top, @DurationFilter_i, @MinutesBack, @CheckDateOverride, @MinimumExecutionCount; - - RETURN; -END; -ELSE IF @ExportToExcel = 1 -BEGIN - RAISERROR('Displaying results with Excel formatting (no plans).', 0, 1) WITH NOWAIT; - - /* excel output */ - UPDATE ##BlitzCacheProcs - SET QueryText = SUBSTRING(REPLACE(REPLACE(REPLACE(LTRIM(RTRIM(QueryText)),' ','<>'),'><',''),'<>',' '), 1, 32000) - OPTION(RECOMPILE); + /* excel output */ + UPDATE ##BlitzCacheProcs + SET QueryText = SUBSTRING(REPLACE(REPLACE(REPLACE(LTRIM(RTRIM(QueryText)),' ','<>'),'><',''),'<>',' '), 1, 32000) + OPTION(RECOMPILE); SET @sql = N' SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; @@ -14668,31 +15183,31 @@ BEGIN missing_indexes AS [Missing Indexes], implicit_conversion_info AS [Implicit Conversion Info], cached_execution_parameters AS [Cached Execution Parameters], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS MONEY), 1), N''.00'', N'''') AS [# Executions], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS MONEY), 1), N''.00'', N'''') AS [Executions / Minute], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS MONEY), 1), N''.00'', N'''') AS [Execution Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalCPU) AS MONEY), 1), N''.00'', N'''') AS [Total CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageCPU) AS MONEY), 1), N''.00'', N'''') AS [Avg CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPU) AS MONEY), 1), N''.00'', N'''') AS [CPU Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalDuration) AS MONEY), 1), N''.00'', N'''') AS [Total Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageDuration) AS MONEY), 1), N''.00'', N'''') AS [Avg Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDuration) AS MONEY), 1), N''.00'', N'''') AS [Duration Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReads) AS MONEY), 1), N''.00'', N'''') AS [Total Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReads) AS MONEY), 1), N''.00'', N'''') AS [Avg Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReads) AS MONEY), 1), N''.00'', N'''') AS [Read Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalWrites) AS MONEY), 1), N''.00'', N'''') AS [Total Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageWrites) AS MONEY), 1), N''.00'', N'''') AS [Avg Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWrites) AS MONEY), 1), N''.00'', N'''') AS [Write Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Average Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS MONEY), 1), N''.00'', N'''') AS [Average Max Memory Grant], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinSpills) AS MONEY), 1), N''.00'', N'''') AS [Min Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxSpills) AS MONEY), 1), N''.00'', N'''') AS [Max Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalSpills) AS MONEY), 1), N''.00'', N'''') AS [Total Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1), N''.00'', N'''') AS [Avg Spills], + CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS BIGINT), 1) AS [# Executions], + CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS BIGINT), 1) AS [Executions / Minute], + CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS BIGINT), 1) AS [Execution Weight], + CONVERT(NVARCHAR(30), CAST((TotalCPU) AS BIGINT), 1) AS [Total CPU (ms)], + CONVERT(NVARCHAR(30), CAST((AverageCPU) AS BIGINT), 1) AS [Avg CPU (ms)], + CONVERT(NVARCHAR(30), CAST((PercentCPU) AS BIGINT), 1) AS [CPU Weight], + CONVERT(NVARCHAR(30), CAST((TotalDuration) AS BIGINT), 1) AS [Total Duration (ms)], + CONVERT(NVARCHAR(30), CAST((AverageDuration) AS BIGINT), 1) AS [Avg Duration (ms)], + CONVERT(NVARCHAR(30), CAST((PercentDuration) AS BIGINT), 1) AS [Duration Weight], + CONVERT(NVARCHAR(30), CAST((TotalReads) AS BIGINT), 1) AS [Total Reads], + CONVERT(NVARCHAR(30), CAST((AverageReads) AS BIGINT), 1) AS [Avg Reads], + CONVERT(NVARCHAR(30), CAST((PercentReads) AS BIGINT), 1) AS [Read Weight], + CONVERT(NVARCHAR(30), CAST((TotalWrites) AS BIGINT), 1) AS [Total Writes], + CONVERT(NVARCHAR(30), CAST((AverageWrites) AS BIGINT), 1) AS [Avg Writes], + CONVERT(NVARCHAR(30), CAST((PercentWrites) AS BIGINT), 1) AS [Write Weight], + CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS BIGINT), 1) AS [Average Rows], + CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS BIGINT), 1) AS [Minimum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS BIGINT), 1) AS [Maximum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS BIGINT), 1) AS [Minimum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS BIGINT), 1) AS [Maximum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS BIGINT), 1) AS [Average Max Memory Grant], + CONVERT(NVARCHAR(30), CAST((MinSpills) AS BIGINT), 1) AS [Min Spills], + CONVERT(NVARCHAR(30), CAST((MaxSpills) AS BIGINT), 1) AS [Max Spills], + CONVERT(NVARCHAR(30), CAST((TotalSpills) AS BIGINT), 1) AS [Total Spills], + CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1) AS [Avg Spills], PlanCreationTime AS [Created At], LastExecutionTime AS [Last Execution], PlanHandle AS [Plan Handle], @@ -14735,7 +15250,7 @@ BEGIN CASE WHEN downlevel_estimator = 1 THEN '', 13'' ELSE '''' END + CASE WHEN implicit_conversions = 1 THEN '', 14'' ELSE '''' END + CASE WHEN tvf_join = 1 THEN '', 17'' ELSE '''' END + - CASE WHEN plan_multiple_plans = 1 THEN '', 21'' ELSE '''' END + + CASE WHEN plan_multiple_plans > 0 THEN '', 21'' ELSE '''' END + CASE WHEN unmatched_index_count > 0 THEN '', 22'' ELSE '''' END + CASE WHEN is_trivial = 1 THEN '', 24'' ELSE '''' END + CASE WHEN is_forced_serial = 1 THEN '', 25'' ELSE '''' END + @@ -14782,49 +15297,49 @@ BEGIN END; SET @columns += N' - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS MONEY), 1), N''.00'', N'''') AS [# Executions], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS MONEY), 1), N''.00'', N'''') AS [Executions / Minute], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS MONEY), 1), N''.00'', N'''') AS [Execution Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((SerialDesiredMemory) AS MONEY), 1), N''.00'', N'''') AS [Serial Desired Memory], - REPLACE(CONVERT(NVARCHAR(30), CAST((SerialRequiredMemory) AS MONEY), 1), N''.00'', N'''') AS [Serial Required Memory], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalCPU) AS MONEY), 1), N''.00'', N'''') AS [Total CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageCPU) AS MONEY), 1), N''.00'', N'''') AS [Avg CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPU) AS MONEY), 1), N''.00'', N'''') AS [CPU Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalDuration) AS MONEY), 1), N''.00'', N'''') AS [Total Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageDuration) AS MONEY), 1), N''.00'', N'''') AS [Avg Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDuration) AS MONEY), 1), N''.00'', N'''') AS [Duration Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReads) AS MONEY), 1), N''.00'', N'''') AS [Total Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReads) AS MONEY), 1), N''.00'', N'''') AS [Average Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReads) AS MONEY), 1), N''.00'', N'''') AS [Read Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalWrites) AS MONEY), 1), N''.00'', N'''') AS [Total Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageWrites) AS MONEY), 1), N''.00'', N'''') AS [Average Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWrites) AS MONEY), 1), N''.00'', N'''') AS [Write Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutionsByType) AS MONEY), 1), N''.00'', N'''') AS [% Executions (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPUByType) AS MONEY), 1), N''.00'', N'''') AS [% CPU (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDurationByType) AS MONEY), 1), N''.00'', N'''') AS [% Duration (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReadsByType) AS MONEY), 1), N''.00'', N'''') AS [% Reads (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWritesByType) AS MONEY), 1), N''.00'', N'''') AS [% Writes (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Total Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Avg Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Min Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Max Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS MONEY), 1), N''.00'', N'''') AS [Average Max Memory Grant], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinSpills) AS MONEY), 1), N''.00'', N'''') AS [Min Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxSpills) AS MONEY), 1), N''.00'', N'''') AS [Max Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalSpills) AS MONEY), 1), N''.00'', N'''') AS [Total Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1), N''.00'', N'''') AS [Avg Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((NumberOfPlans) AS MONEY), 1), N''.00'', N'''') AS [# Plans], - REPLACE(CONVERT(NVARCHAR(30), CAST((NumberOfDistinctPlans) AS MONEY), 1), N''.00'', N'''') AS [# Distinct Plans], + CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS BIGINT), 1) AS [# Executions], + CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS BIGINT), 1) AS [Executions / Minute], + CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS BIGINT), 1) AS [Execution Weight], + CONVERT(NVARCHAR(30), CAST((SerialDesiredMemory) AS BIGINT), 1) AS [Serial Desired Memory], + CONVERT(NVARCHAR(30), CAST((SerialRequiredMemory) AS BIGINT), 1) AS [Serial Required Memory], + CONVERT(NVARCHAR(30), CAST((TotalCPU) AS BIGINT), 1) AS [Total CPU (ms)], + CONVERT(NVARCHAR(30), CAST((AverageCPU) AS BIGINT), 1) AS [Avg CPU (ms)], + CONVERT(NVARCHAR(30), CAST((PercentCPU) AS BIGINT), 1) AS [CPU Weight], + CONVERT(NVARCHAR(30), CAST((TotalDuration) AS BIGINT), 1) AS [Total Duration (ms)], + CONVERT(NVARCHAR(30), CAST((AverageDuration) AS BIGINT), 1) AS [Avg Duration (ms)], + CONVERT(NVARCHAR(30), CAST((PercentDuration) AS BIGINT), 1) AS [Duration Weight], + CONVERT(NVARCHAR(30), CAST((TotalReads) AS BIGINT), 1) AS [Total Reads], + CONVERT(NVARCHAR(30), CAST((AverageReads) AS BIGINT), 1) AS [Average Reads], + CONVERT(NVARCHAR(30), CAST((PercentReads) AS BIGINT), 1) AS [Read Weight], + CONVERT(NVARCHAR(30), CAST((TotalWrites) AS BIGINT), 1) AS [Total Writes], + CONVERT(NVARCHAR(30), CAST((AverageWrites) AS BIGINT), 1) AS [Average Writes], + CONVERT(NVARCHAR(30), CAST((PercentWrites) AS BIGINT), 1) AS [Write Weight], + CONVERT(NVARCHAR(30), CAST((PercentExecutionsByType) AS BIGINT), 1) AS [% Executions (Type)], + CONVERT(NVARCHAR(30), CAST((PercentCPUByType) AS BIGINT), 1) AS [% CPU (Type)], + CONVERT(NVARCHAR(30), CAST((PercentDurationByType) AS BIGINT), 1) AS [% Duration (Type)], + CONVERT(NVARCHAR(30), CAST((PercentReadsByType) AS BIGINT), 1) AS [% Reads (Type)], + CONVERT(NVARCHAR(30), CAST((PercentWritesByType) AS BIGINT), 1) AS [% Writes (Type)], + CONVERT(NVARCHAR(30), CAST((TotalReturnedRows) AS BIGINT), 1) AS [Total Rows], + CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS BIGINT), 1) AS [Avg Rows], + CONVERT(NVARCHAR(30), CAST((MinReturnedRows) AS BIGINT), 1) AS [Min Rows], + CONVERT(NVARCHAR(30), CAST((MaxReturnedRows) AS BIGINT), 1) AS [Max Rows], + CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS BIGINT), 1) AS [Minimum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS BIGINT), 1) AS [Maximum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS BIGINT), 1) AS [Minimum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS BIGINT), 1) AS [Maximum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS BIGINT), 1) AS [Average Max Memory Grant], + CONVERT(NVARCHAR(30), CAST((MinSpills) AS BIGINT), 1) AS [Min Spills], + CONVERT(NVARCHAR(30), CAST((MaxSpills) AS BIGINT), 1) AS [Max Spills], + CONVERT(NVARCHAR(30), CAST((TotalSpills) AS BIGINT), 1) AS [Total Spills], + CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1) AS [Avg Spills], + CONVERT(NVARCHAR(30), CAST((NumberOfPlans) AS BIGINT), 1) AS [# Plans], + CONVERT(NVARCHAR(30), CAST((NumberOfDistinctPlans) AS BIGINT), 1) AS [# Distinct Plans], PlanCreationTime AS [Created At], LastExecutionTime AS [Last Execution], - REPLACE(CONVERT(NVARCHAR(30), CAST((CachedPlanSize) AS MONEY), 1), N''.00'', N'''') AS [Cached Plan Size (KB)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileTime) AS MONEY), 1), N''.00'', N'''') AS [Compile Time (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileCPU) AS MONEY), 1), N''.00'', N'''') AS [Compile CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileMemory) AS MONEY), 1), N''.00'', N'''') AS [Compile memory (KB)], + CONVERT(NVARCHAR(30), CAST((CachedPlanSize) AS BIGINT), 1) AS [Cached Plan Size (KB)], + CONVERT(NVARCHAR(30), CAST((CompileTime) AS BIGINT), 1) AS [Compile Time (ms)], + CONVERT(NVARCHAR(30), CAST((CompileCPU) AS BIGINT), 1) AS [Compile CPU (ms)], + CONVERT(NVARCHAR(30), CAST((CompileMemory) AS BIGINT), 1) AS [Compile memory (KB)], COALESCE(SetOptions, '''') AS [SET Options], PlanHandle AS [Plan Handle], SqlHandle AS [SQL Handle], @@ -15181,7 +15696,7 @@ BEGIN IF EXISTS (SELECT 1/0 FROM ##BlitzCacheProcs - WHERE plan_multiple_plans = 1 + WHERE plan_multiple_plans > 0 AND SPID = @@SPID) INSERT INTO ##BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL, Details) VALUES (@@SPID, @@ -15952,7 +16467,10 @@ IF @Debug = 1 END; - + IF @OutputDatabaseName IS NOT NULL + AND @OutputSchemaName IS NOT NULL + AND @OutputTableName IS NOT NULL + GOTO OutputResultsToTable; RETURN; --Avoid going into the AllSort GOTO /*Begin code to sort by all*/ @@ -16047,29 +16565,6 @@ IF OBJECT_ID('tempdb.. #bou_allsort') IS NULL ); END; -DECLARE @AllSortSql NVARCHAR(MAX) = N''; -DECLARE @MemGrant BIT; -SELECT @MemGrant = CASE WHEN ( - ( @v < 11 ) - OR ( - @v = 11 - AND @build < 6020 - ) - OR ( - @v = 12 - AND @build < 5000 - ) - OR ( - @v = 13 - AND @build < 1601 - ) - ) THEN 0 - ELSE 1 - END; - -DECLARE @Spills BIT; -SELECT @Spills = CASE WHEN (@v >= 15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026)) THEN 1 ELSE 0 END; - IF LOWER(@SortOrder) = 'all' BEGIN @@ -16082,7 +16577,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''cpu'', @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''cpu'', @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''cpu'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16093,7 +16588,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''reads'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16104,7 +16599,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''writes'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16115,7 +16610,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''duration'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16126,13 +16621,13 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''executions'' WHERE Pattern IS NULL OPTION(RECOMPILE); '; - IF @MemGrant = 0 + IF @VersionShowsMemoryGrants = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -16151,7 +16646,7 @@ SET @AllSortSql += N' END; - IF @MemGrant = 1 + IF @VersionShowsMemoryGrants = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -16160,7 +16655,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -16180,7 +16675,7 @@ SET @AllSortSql += N' END; - IF @Spills = 0 + IF @VersionShowsSpills = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -16199,7 +16694,7 @@ SET @AllSortSql += N' END; - IF @Spills = 1 + IF @VersionShowsSpills = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -16208,7 +16703,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -16250,7 +16745,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg cpu'', @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg cpu'', @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg cpu'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16261,7 +16756,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg reads'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16272,7 +16767,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg writes'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16283,7 +16778,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg duration'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -16294,13 +16789,13 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg executions'' WHERE Pattern IS NULL OPTION(RECOMPILE); '; - IF @MemGrant = 0 + IF @VersionShowsMemoryGrants = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -16319,7 +16814,7 @@ SET @AllSortSql += N' END; - IF @MemGrant = 1 + IF @VersionShowsMemoryGrants = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -16328,7 +16823,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -16348,7 +16843,7 @@ SET @AllSortSql += N' END; - IF @Spills = 0 + IF @VersionShowsSpills = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -16367,7 +16862,7 @@ SET @AllSortSql += N' END; - IF @Spills = 1 + IF @VersionShowsSpills = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -16376,7 +16871,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -16419,11 +16914,209 @@ END; PRINT SUBSTRING(@AllSortSql, 36000, 40000); END; - EXEC sys.sp_executesql @stmt = @AllSortSql, @params = N'@i_DatabaseName NVARCHAR(128), @i_Top INT', @i_DatabaseName = @DatabaseName, @i_Top = @Top; + EXEC sys.sp_executesql @stmt = @AllSortSql, @params = N'@i_DatabaseName NVARCHAR(128), @i_Top INT, @i_SkipAnalysis BIT, @i_OutputDatabaseName NVARCHAR(258), @i_OutputSchemaName NVARCHAR(258), @i_OutputTableName NVARCHAR(258)', + @i_DatabaseName = @DatabaseName, @i_Top = @Top, @i_SkipAnalysis = @SkipAnalysis, @i_OutputDatabaseName = @OutputDatabaseName, @i_OutputSchemaName = @OutputSchemaName, @i_OutputTableName = @OutputTableName; /*End of AllSort section*/ +/*Begin code to sort by all*/ +OutputResultsToTable: + +IF @OutputDatabaseName IS NOT NULL + AND @OutputSchemaName IS NOT NULL + AND @OutputTableName IS NOT NULL +BEGIN + RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT; + + SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName), + @OutputSchemaName = QUOTENAME(@OutputSchemaName), + @OutputTableName = QUOTENAME(@OutputTableName); + + /* send results to a table */ + DECLARE @insert_sql NVARCHAR(MAX) = N'' ; + + SET @insert_sql = 'USE ' + + @OutputDatabaseName + + '; IF EXISTS(SELECT * FROM ' + + @OutputDatabaseName + + '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' + + @OutputSchemaName + + ''') AND NOT EXISTS (SELECT * FROM ' + + @OutputDatabaseName + + '.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = ''' + + @OutputSchemaName + ''' AND QUOTENAME(TABLE_NAME) = ''' + + @OutputTableName + ''') CREATE TABLE ' + + @OutputSchemaName + '.' + + @OutputTableName + + N'(ID bigint NOT NULL IDENTITY(1,1), + ServerName NVARCHAR(258), + CheckDate DATETIMEOFFSET, + Version NVARCHAR(258), + QueryType NVARCHAR(258), + Warnings varchar(max), + DatabaseName sysname, + SerialDesiredMemory float, + SerialRequiredMemory float, + AverageCPU bigint, + TotalCPU bigint, + PercentCPUByType money, + CPUWeight money, + AverageDuration bigint, + TotalDuration bigint, + DurationWeight money, + PercentDurationByType money, + AverageReads bigint, + TotalReads bigint, + ReadWeight money, + PercentReadsByType money, + AverageWrites bigint, + TotalWrites bigint, + WriteWeight money, + PercentWritesByType money, + ExecutionCount bigint, + ExecutionWeight money, + PercentExecutionsByType money,' + N' + ExecutionsPerMinute money, + PlanCreationTime datetime, + PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()), + LastExecutionTime datetime, + PlanHandle varbinary(64), + [Remove Plan Handle From Cache] AS + CASE WHEN [PlanHandle] IS NOT NULL + THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');'' + ELSE ''N/A'' END, + SqlHandle varbinary(64), + [Remove SQL Handle From Cache] AS + CASE WHEN [SqlHandle] IS NOT NULL + THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');'' + ELSE ''N/A'' END, + [SQL Handle More Info] AS + CASE WHEN [SqlHandle] IS NOT NULL + THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; '' + ELSE ''N/A'' END, + QueryHash binary(8), + [Query Hash More Info] AS + CASE WHEN [QueryHash] IS NOT NULL + THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; '' + ELSE ''N/A'' END, + QueryPlanHash binary(8), + StatementStartOffset int, + StatementEndOffset int, + MinReturnedRows bigint, + MaxReturnedRows bigint, + AverageReturnedRows money, + TotalReturnedRows bigint, + QueryText nvarchar(max), + QueryPlan xml, + NumberOfPlans int, + NumberOfDistinctPlans int, + MinGrantKB BIGINT, + MaxGrantKB BIGINT, + MinUsedGrantKB BIGINT, + MaxUsedGrantKB BIGINT, + PercentMemoryGrantUsed MONEY, + AvgMaxMemoryGrant MONEY, + MinSpills BIGINT, + MaxSpills BIGINT, + TotalSpills BIGINT, + AvgSpills MONEY, + QueryPlanCost FLOAT, + CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))'; + + IF @Debug = 1 + BEGIN + PRINT SUBSTRING(@insert_sql, 0, 4000); + PRINT SUBSTRING(@insert_sql, 4000, 8000); + PRINT SUBSTRING(@insert_sql, 8000, 12000); + PRINT SUBSTRING(@insert_sql, 12000, 16000); + PRINT SUBSTRING(@insert_sql, 16000, 20000); + PRINT SUBSTRING(@insert_sql, 20000, 24000); + PRINT SUBSTRING(@insert_sql, 24000, 28000); + PRINT SUBSTRING(@insert_sql, 28000, 32000); + PRINT SUBSTRING(@insert_sql, 32000, 36000); + PRINT SUBSTRING(@insert_sql, 36000, 40000); + END; + + EXEC sp_executesql @insert_sql ; + + IF @CheckDateOverride IS NULL + BEGIN + SET @CheckDateOverride = SYSDATETIMEOFFSET(); + END; + + + SET @insert_sql = N' IF EXISTS(SELECT * FROM ' + + @OutputDatabaseName + + N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' + + @OutputSchemaName + N''') ' + + N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;' + + 'INSERT ' + + @OutputDatabaseName + '.' + + @OutputSchemaName + '.' + + @OutputTableName + + N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + + N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' + + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + N'SELECT TOP (@Top) ' + + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', @CheckDateOverride, ' + + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', ' + + N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + + N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' + + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + N' FROM ##BlitzCacheProcs ' + + N' WHERE 1=1 '; + + IF @MinimumExecutionCount IS NOT NULL + BEGIN + SET @insert_sql += N' AND ExecutionCount >= @MinimumExecutionCount '; + END; + + IF @MinutesBack IS NOT NULL + BEGIN + SET @insert_sql += N' AND LastExecutionTime >= DATEADD(MINUTE, @min_back, GETDATE() ) '; + END; + + SET @insert_sql += N' AND SPID = @@SPID '; + + SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU ' + WHEN N'reads' THEN N' TotalReads ' + WHEN N'writes' THEN N' TotalWrites ' + WHEN N'duration' THEN N' TotalDuration ' + WHEN N'executions' THEN N' ExecutionCount ' + WHEN N'compiles' THEN N' PlanCreationTime ' + WHEN N'memory grant' THEN N' MaxGrantKB' + WHEN N'spills' THEN N' MaxSpills' + WHEN N'avg cpu' THEN N' AverageCPU' + WHEN N'avg reads' THEN N' AverageReads' + WHEN N'avg writes' THEN N' AverageWrites' + WHEN N'avg duration' THEN N' AverageDuration' + WHEN N'avg executions' THEN N' ExecutionsPerMinute' + WHEN N'avg memory grant' THEN N' AvgMaxMemoryGrant' + WHEN 'avg spills' THEN N' AvgSpills' + END + N' DESC '; + + SET @insert_sql += N' OPTION (RECOMPILE) ; '; + + IF @Debug = 1 + BEGIN + PRINT SUBSTRING(@insert_sql, 0, 4000); + PRINT SUBSTRING(@insert_sql, 4000, 8000); + PRINT SUBSTRING(@insert_sql, 8000, 12000); + PRINT SUBSTRING(@insert_sql, 12000, 16000); + PRINT SUBSTRING(@insert_sql, 16000, 20000); + PRINT SUBSTRING(@insert_sql, 20000, 24000); + PRINT SUBSTRING(@insert_sql, 24000, 28000); + PRINT SUBSTRING(@insert_sql, 28000, 32000); + PRINT SUBSTRING(@insert_sql, 32000, 36000); + PRINT SUBSTRING(@insert_sql, 36000, 40000); + END; + + EXEC sp_executesql @insert_sql, N'@Top INT, @min_duration INT, @min_back INT, @CheckDateOverride DATETIMEOFFSET, @MinimumExecutionCount INT', @Top, @DurationFilter_i, @MinutesBack, @CheckDateOverride, @MinimumExecutionCount; +END; /* End of writing results to table */ + END; /*Final End*/ GO @@ -16471,7 +17164,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -16557,7 +17250,6 @@ DECLARE @StringToExecute NVARCHAR(MAX), @ObjectFullName NVARCHAR(2000), @BlitzWho NVARCHAR(MAX) = N'EXEC dbo.sp_BlitzWho @ShowSleepingSPIDs = ' + CONVERT(NVARCHAR(1), @ShowSleepingSPIDs) + N';', @BlitzCacheMinutesBack INT, - @BlitzCacheSortOrder VARCHAR(50), @UnquotedOutputServerName NVARCHAR(256) = @OutputServerName , @UnquotedOutputDatabaseName NVARCHAR(256) = @OutputDatabaseName , @UnquotedOutputSchemaName NVARCHAR(256) = @OutputSchemaName ; @@ -17714,8 +18406,9 @@ BEGIN 'Maintenance Tasks Running' AS FindingGroup, 'Backup Running' AS Finding, 'http://www.BrentOzar.com/askbrent/backups/' AS URL, - 'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) is ' + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' - + CASE WHEN COALESCE(s.nt_user_name, s.login_name) IS NOT NULL THEN (' Login: ' + COALESCE(s.nt_user_name, s.login_name) + ' ') ELSE '' END AS Details, + 'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) ' + @LineFeed + + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' + @LineFeed + + CASE WHEN COALESCE(s.nt_user_name, s.login_name) IS NOT NULL THEN (' Login: ' + COALESCE(s.nt_user_name, s.login_name) + ' ') ELSE '' END AS Details, 'KILL ' + CAST(r.session_id AS NVARCHAR(100)) + ';' AS HowToStopIt, pl.query_plan AS QueryPlan, r.start_time AS StartTime, @@ -17853,9 +18546,9 @@ BEGIN ''Long-Running Query Blocking Others'' AS Finding, ''http://www.BrentOzar.com/go/blocking'' AS URL, ''Query in '' + COALESCE(DB_NAME(COALESCE((SELECT TOP 1 dbid FROM sys.dm_exec_sql_text(r.sql_handle)), - (SELECT TOP 1 t.dbid FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) t WHERE spBlocker.spid = tBlocked.blocking_session_id))), ''(Unknown)'') + '' has a last request start time of '' + CAST(s.last_request_start_time AS NVARCHAR(100)) + ''. Query follows:'' ' + (SELECT TOP 1 t.dbid FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) t WHERE spBlocker.spid = tBlocked.blocking_session_id))), ''(Unknown)'') + '' has a last request start time of '' + CAST(s.last_request_start_time AS NVARCHAR(100)) + ''. Query follows: ' + @LineFeed + @LineFeed + - '+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(r.sql_handle)), + '''+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(r.sql_handle)), (SELECT TOP 1 [text] FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) WHERE spBlocker.spid = tBlocked.blocking_session_id), '''') AS NVARCHAR(2000)) AS Details, ''KILL '' + CAST(tBlocked.blocking_session_id AS NVARCHAR(100)) + '';'' AS HowToStopIt, (SELECT TOP 1 query_plan FROM sys.dm_exec_query_plan(r.plan_handle)) AS QueryPlan, @@ -17873,7 +18566,9 @@ BEGIN INNER JOIN sys.dm_exec_sessions s ON tBlocked.blocking_session_id = s.session_id LEFT OUTER JOIN sys.dm_exec_requests r ON s.session_id = r.session_id INNER JOIN sys.dm_exec_connections c ON s.session_id = c.session_id - WHERE tBlocked.wait_type LIKE ''LCK%'' AND tBlocked.wait_duration_ms > 30000;'; + WHERE tBlocked.wait_type LIKE ''LCK%'' AND tBlocked.wait_duration_ms > 30000 + /* And the blocking session ID is not blocked by anyone else: */ + AND NOT EXISTS(SELECT * FROM sys.dm_os_waiting_tasks tBlocking WHERE s.session_id = tBlocking.session_id AND tBlocking.session_id <> tBlocking.blocking_session_id AND tBlocking.blocking_session_id IS NOT NULL);'; EXECUTE sp_executesql @StringToExecute; END; @@ -17941,17 +18636,18 @@ BEGIN SET @StringToExecute = N'INSERT INTO #BlitzFirstResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, QueryText, OpenTransactionCount) SELECT 37 AS CheckId, 50 AS Priority, - ''Implicit Transactions'' AS FindingsGroup, - ''Queries were found running using implicit transactions'', + ''Query Problems'' AS FindingsGroup, + ''Implicit Transactions'', ''https://www.brentozar.com/go/ImplicitTransactions/'' AS URL, - ''Database: '' + DB_NAME(s.database_id) + '' '' + - ''Host: '' + s.[host_name] + '' '' + - ''Program: '' + s.[program_name] + '' '' + + ''Database: '' + DB_NAME(s.database_id) + '' '' + CHAR(13) + CHAR(10) + + ''Host: '' + s.[host_name] + '' '' + CHAR(13) + CHAR(10) + + ''Program: '' + s.[program_name] + '' '' + CHAR(13) + CHAR(10) + CONVERT(NVARCHAR(10), s.open_transaction_count) + '' open transactions since: '' + CONVERT(NVARCHAR(30), tat.transaction_begin_time) + ''. '' AS Details, - ''Check client configuration options'' AS HowToStopit, + ''Run sp_BlitzWho and check the is_implicit_transaction column to spot the culprits. +If one of them is a lead blocker, consider killing that query.'' AS HowToStopit, tat.transaction_begin_time, s.login_name, s.nt_user_name, @@ -19169,55 +19865,6 @@ BEGIN RAISERROR('Calling sp_BlitzCache',10,1) WITH NOWAIT; - /* Set the sp_BlitzCache sort order based on their top wait type */ - - /* First, check for poison waits - CheckID 30 */ - IF EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 30) - BEGIN - SELECT TOP 1 @BlitzCacheSortOrder = CASE - WHEN Finding = 'Poison Wait Detected: RESOURCE_SEMAPHORE' AND @memGrantSortSupported = 1 THEN 'memory grant' - WHEN Finding = 'Poison Wait Detected: RESOURCE_SEMAPHORE_QUERY_COMPILE' AND @memGrantSortSupported = 1 THEN 'memory grant' - WHEN Finding = 'Poison Wait Detected: THREADPOOL' THEN 'executions' - WHEN Finding = 'Poison Wait Detected: LOG_RATE_GOVERNOR' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_CATCHUP_THROTTLE' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_COMMIT_ACK' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_ROLLBACK_ACK' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_SLOW_SECONDARY_THROTTLE' THEN 'writes' - ELSE NULL - END - FROM #BlitzFirstResults - WHERE CheckID = 30 - ORDER BY DetailsInt DESC; - END; - - /* Too much free memory - which probably indicates queries finished w/huge grants - CheckID 34 */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 34) AND @memGrantSortSupported = 1 - SET @BlitzCacheSortOrder = 'memory grant'; - - /* Next, Compilations/Sec High - CheckID 15 and 16 */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID IN (15,16)) - SET @BlitzCacheSortOrder = 'recent compilations'; - - /* Still not set? Use the top wait type. */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 6) - BEGIN - SELECT TOP 1 @BlitzCacheSortOrder = CASE - WHEN Finding = 'ASYNC_NETWORK_IO' THEN 'duration' - WHEN Finding = 'CXPACKET' THEN 'reads' - WHEN Finding = 'LATCH_EX' THEN 'reads' - WHEN Finding LIKE 'LCK%' THEN 'duration' - WHEN Finding LIKE 'PAGEIOLATCH%' THEN 'reads' - WHEN Finding = 'SOS_SCHEDULER_YIELD' THEN 'cpu' - WHEN Finding = 'WRITELOG' THEN 'writes' - ELSE NULL - END - FROM #BlitzFirstResults - WHERE CheckID = 6 - ORDER BY DetailsInt DESC; - END; - /* Still null? Just use the default. */ - - /* If they have an newer version of sp_BlitzCache that supports @MinutesBack and @CheckDateOverride */ IF EXISTS (SELECT * FROM sys.objects o @@ -19241,23 +19888,15 @@ BEGIN IF @BlitzCacheMinutesBack IS NULL OR @BlitzCacheMinutesBack < 1 OR @BlitzCacheMinutesBack > 60 SET @BlitzCacheMinutesBack = 15; - IF @BlitzCacheSortOrder IS NOT NULL - EXEC sp_BlitzCache - @OutputDatabaseName = @UnquotedOutputDatabaseName, - @OutputSchemaName = @UnquotedOutputSchemaName, - @OutputTableName = @OutputTableNameBlitzCache, - @CheckDateOverride = @StartSampleTime, - @SortOrder = @BlitzCacheSortOrder, - @MinutesBack = @BlitzCacheMinutesBack, - @Debug = @Debug; - ELSE - EXEC sp_BlitzCache - @OutputDatabaseName = @UnquotedOutputDatabaseName, - @OutputSchemaName = @UnquotedOutputSchemaName, - @OutputTableName = @OutputTableNameBlitzCache, - @CheckDateOverride = @StartSampleTime, - @MinutesBack = @BlitzCacheMinutesBack, - @Debug = @Debug; + EXEC sp_BlitzCache + @OutputDatabaseName = @UnquotedOutputDatabaseName, + @OutputSchemaName = @UnquotedOutputSchemaName, + @OutputTableName = @OutputTableNameBlitzCache, + @CheckDateOverride = @StartSampleTime, + @SortOrder = 'all', + @SkipAnalysis = 1, + @MinutesBack = @BlitzCacheMinutesBack, + @Debug = @Debug; /* Delete history older than @OutputTableRetentionDays */ SET @StringToExecute = N' IF EXISTS(SELECT * FROM ' @@ -20470,6 +21109,7 @@ ALTER PROCEDURE dbo.sp_BlitzIndex @SkipStatistics BIT = 1, @GetAllDatabases BIT = 0, @BringThePain BIT = 0, + @IgnoreDatabases NVARCHAR(MAX) = NULL, /* Comma-delimited list of databases you want to skip */ @ThresholdMB INT = 250 /* Number of megabytes that an object must be before we include it in basic results */, @OutputType VARCHAR(20) = 'TABLE' , @OutputServerName NVARCHAR(256) = NULL , @@ -20485,7 +21125,7 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -20565,12 +21205,14 @@ DECLARE @collation NVARCHAR(256); DECLARE @NumDatabases INT; DECLARE @LineFeed NVARCHAR(5); DECLARE @DaysUptimeInsertValue NVARCHAR(256); +DECLARE @DatabaseToIgnore NVARCHAR(MAX); SET @LineFeed = CHAR(13) + CHAR(10); SELECT @SQLServerProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)); SELECT @SQLServerEdition =CAST(SERVERPROPERTY('EngineEdition') AS INT); /* We default to online index creates where EngineEdition=3*/ SET @FilterMB=250; SELECT @ScriptVersionName = 'sp_BlitzIndex(TM) v' + @Version + ' - ' + DATENAME(MM, @VersionDate) + ' ' + RIGHT('0'+DATENAME(DD, @VersionDate),2) + ', ' + DATENAME(YY, @VersionDate); +SET @IgnoreDatabases = LTRIM(RTRIM(@IgnoreDatabases)); RAISERROR(N'Starting run. %s', 0,1, @ScriptVersionName) WITH NOWAIT; @@ -20649,6 +21291,9 @@ IF OBJECT_ID('tempdb..#CheckConstraints') IS NOT NULL IF OBJECT_ID('tempdb..#FilteredIndexes') IS NOT NULL DROP TABLE #FilteredIndexes; +IF OBJECT_ID('tempdb..#Ignore_Databases') IS NOT NULL + DROP TABLE #Ignore_Databases + RAISERROR (N'Create temp tables.',0,1) WITH NOWAIT; CREATE TABLE #BlitzIndexResults ( @@ -21131,6 +21776,12 @@ IF OBJECT_ID('tempdb..#FilteredIndexes') IS NOT NULL column_name NVARCHAR(128) NULL ); + CREATE TABLE #Ignore_Databases + ( + DatabaseName NVARCHAR(128), + Reason NVARCHAR(100) + ); + /* Sanitize our inputs */ SELECT @OutputServerName = QUOTENAME(@OutputServerName), @@ -21179,6 +21830,37 @@ IF @GetAllDatabases = 1 END; END; + IF @IgnoreDatabases IS NOT NULL + AND LEN(@IgnoreDatabases) > 0 + BEGIN + RAISERROR(N'Setting up filter to ignore databases', 0, 1) WITH NOWAIT; + SET @DatabaseToIgnore = ''; + + WHILE LEN(@IgnoreDatabases) > 0 + BEGIN + IF PATINDEX('%,%', @IgnoreDatabases) > 0 + BEGIN + SET @DatabaseToIgnore = SUBSTRING(@IgnoreDatabases, 0, PATINDEX('%,%',@IgnoreDatabases)) ; + + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseToIgnore, 'Specified in the @IgnoreDatabases parameter' + OPTION (RECOMPILE) ; + + SET @IgnoreDatabases = SUBSTRING(@IgnoreDatabases, LEN(@DatabaseToIgnore + ',') + 1, LEN(@IgnoreDatabases)) ; + END; + ELSE + BEGIN + SET @DatabaseToIgnore = @IgnoreDatabases ; + SET @IgnoreDatabases = NULL ; + + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseToIgnore, 'Specified in the @IgnoreDatabases parameter' + OPTION (RECOMPILE) ; + END; + END; + + END + END; ELSE BEGIN @@ -21264,16 +21946,72 @@ BEGIN CATCH RETURN; END CATCH; + +RAISERROR (N'Checking partition counts to exclude databases with over 100 partitions',0,1) WITH NOWAIT; +IF @BringThePain = 0 AND @SkipPartitions = 0 AND @TableName IS NULL + BEGIN + DECLARE partition_cursor CURSOR FOR + SELECT dl.DatabaseName + FROM #DatabaseList dl + LEFT OUTER JOIN #Ignore_Databases i ON dl.DatabaseName = i.DatabaseName + WHERE COALESCE(dl.secondary_role_allow_connections_desc, 'OK') <> 'NO' + AND i.DatabaseName IS NULL + + OPEN partition_cursor + FETCH NEXT FROM partition_cursor INTO @DatabaseName + + WHILE @@FETCH_STATUS = 0 + BEGIN + /* Count the total number of partitions */ + SET @dsql = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + SELECT @RowcountOUT = SUM(1) FROM ' + QUOTENAME(@DatabaseName) + '.sys.partitions WHERE partition_number > 1 OPTION ( RECOMPILE );'; + EXEC sp_executesql @dsql, N'@RowcountOUT BIGINT OUTPUT', @RowcountOUT = @Rowcount OUTPUT; + IF @Rowcount > 100 + BEGIN + RAISERROR (N'Skipping database %s because > 100 partitions were found. To check this database, you must set @BringThePain = 1.',0,1,@DatabaseName) WITH NOWAIT; + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseName, 'Over 100 partitions found - use @BringThePain = 1 to analyze' + END; + FETCH NEXT FROM partition_cursor INTO @DatabaseName + END; + CLOSE partition_cursor + DEALLOCATE partition_cursor + + END; + +INSERT #BlitzIndexResults ( Priority, check_id, findings_group, finding, URL, details, index_definition, + index_usage_summary, index_size_summary ) +SELECT 1, 0 , + 'Database Skipped', + i.DatabaseName, + 'http://FirstResponderKit.org', + i.Reason, '', '', '' +FROM #Ignore_Databases i; + + +/* 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 OR @DaysUptime IS NULL + SET @DaysUptime = .01; + +SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPERTY('ServerName')))) + ' Days Uptime: ' + RTRIM(@DaysUptime); + + /* Permission granted or unnecessary? Ok, let's go! */ +RAISERROR (N'Starting loop through databases',0,1) WITH NOWAIT; DECLARE c1 CURSOR LOCAL FAST_FORWARD FOR -SELECT DatabaseName -FROM #DatabaseList -WHERE COALESCE(secondary_role_allow_connections_desc, 'OK') -<> 'NO' -ORDER BY DatabaseName; +SELECT dl.DatabaseName +FROM #DatabaseList dl +LEFT OUTER JOIN #Ignore_Databases i ON dl.DatabaseName = i.DatabaseName +WHERE COALESCE(dl.secondary_role_allow_connections_desc, 'OK') <> 'NO' + AND i.DatabaseName IS NULL +ORDER BY dl.DatabaseName; OPEN c1; FETCH NEXT FROM c1 INTO @DatabaseName; @@ -21291,16 +22029,6 @@ FROM sys.databases AND user_access_desc='MULTI_USER' AND state_desc = 'ONLINE'; -/* 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 OR @DaysUptime IS NULL - SET @DaysUptime = .01; - -SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPERTY('ServerName')))) + ' Days Uptime: ' + RTRIM(@DaysUptime); - ---------------------------------------- --STEP 1: OBSERVE THE PATIENT --This step puts index information into temp tables. @@ -21308,7 +22036,7 @@ SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPE BEGIN TRY BEGIN - --Validate SQL Server Verson + --Validate SQL Server Version IF (SELECT LEFT(@SQLServerProductVersion, CHARINDEX('.',@SQLServerProductVersion,0)-1 @@ -25390,7 +26118,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '2.4', @VersionDate = '20190320'; +SELECT @Version = '2.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) @@ -25546,7 +26274,13 @@ You need to use an Azure storage account, and the path has to look like this: ht DECLARE @d VARCHAR(40), @StringToExecute NVARCHAR(4000); CREATE TABLE #t (id INT NOT NULL); - UPDATE STATISTICS #t WITH ROWCOUNT = 100000000, PAGECOUNT = 100000000; + + /* WITH ROWCOUNT doesn't work on Amazon RDS - see: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2037 */ + 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-' + AND db_id('rdsadmin') IS NULL + UPDATE STATISTICS #t WITH ROWCOUNT = 100000000, PAGECOUNT = 100000000; /*Grab the initial set of XML to parse*/ SET @d = CONVERT(VARCHAR(40), GETDATE(), 109); @@ -26478,14 +27212,14 @@ You need to use an Azure storage account, and the path has to look like this: ht DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en, ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn, NULL AS is_victim, - cao.wait_type AS owner_mode, + cao.wait_type COLLATE DATABASE_DEFAULT AS owner_mode, cao.waiter_type AS owner_waiter_type, cao.owner_activity AS owner_activity, cao.waiter_activity AS owner_waiter_activity, cao.merging AS owner_merging, cao.spilling AS owner_spilling, cao.waiting_to_close AS owner_waiting_to_close, - caw.wait_type AS waiter_mode, + caw.wait_type COLLATE DATABASE_DEFAULT AS waiter_mode, caw.waiter_type AS waiter_waiter_type, caw.owner_activity AS waiter_owner_activity, caw.waiter_activity AS waiter_waiter_activity, @@ -26652,7 +27386,7 @@ BEGIN /*First BEGIN*/ SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '3.4', @VersionDate = '20190320'; +SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN RETURN; @@ -29745,9 +30479,9 @@ WITH XMLNAMESPACES('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS UPDATE b SET b.is_fast_forward_cursor = 1 FROM #working_warnings b -JOIN #statements AS qs -ON b.sql_handle = qs.sql_handle -CROSS APPLY qs.statement.nodes('/p:StmtCursor') AS n1(fn) +JOIN #statements AS s +ON b.sql_handle = s.sql_handle +CROSS APPLY s.statement.nodes('/p:StmtCursor') AS n1(fn) WHERE n1.fn.exist('//p:CursorPlan/@CursorActualType[.="FastForward"]') = 1 AND s.is_cursor = 1 OPTION (RECOMPILE); @@ -32377,7 +33111,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '7.4', @VersionDate = '20190320'; + SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN diff --git a/SqlServerVersions.sql b/SqlServerVersions.sql index 66fbc79ac..436d5f37e 100644 --- a/SqlServerVersions.sql +++ b/SqlServerVersions.sql @@ -30,6 +30,8 @@ DELETE dbo.SqlServerVersions; INSERT INTO dbo.SqlServerVersions (MajorVersionNumber, MinorVersionNumber, Branch, [Url], ReleaseDate, MainstreamSupportEndDate, ExtendedSupportEndDate, MajorVersionName, MinorVersionName) VALUES + (14, 3162, 'RTM CU15', 'https://support.microsoft.com/en-us/help/4498951', '2019-05-24', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 15'), + (14, 3076, 'RTM CU14', 'https://support.microsoft.com/en-us/help/4484710', '2019-03-25', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 14'), (14, 3048, 'RTM CU13', 'https://support.microsoft.com/en-us/help/4466404', '2018-12-18', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 13'), (14, 3045, 'RTM CU12', 'https://support.microsoft.com/en-us/help/4464082', '2018-10-24', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 12'), (14, 3038, 'RTM CU11', 'https://support.microsoft.com/en-us/help/4462262', '2018-09-20', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 11'), @@ -44,6 +46,7 @@ VALUES (14, 3008, 'RTM CU2', 'https://support.microsoft.com/en-us/help/4052574', '2017-11-28', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 2'), (14, 3006, 'RTM CU1', 'https://support.microsoft.com/en-us/help/4038634', '2017-10-24', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 1'), (14, 1000, 'RTM ', '', '2017-10-02', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM '), + (13, 5337, 'SP2 CU7', 'https://support.microsoft.com/en-us/help/4495256', '2019-05-23', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 7'), (13, 5292, 'SP2 CU6', 'https://support.microsoft.com/en-us/help/4488536', '2019-03-19', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 6'), (13, 5264, 'SP2 CU5', 'https://support.microsoft.com/en-us/help/4475776', '2019-01-23', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 5'), (13, 5233, 'SP2 CU4', 'https://support.microsoft.com/en-us/help/4464106', '2018-11-13', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 4'), @@ -52,9 +55,10 @@ VALUES (13, 5153, 'SP2 CU2', 'https://support.microsoft.com/en-us/help/4340355', '2018-07-16', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 2'), (13, 5149, 'SP2 CU1', 'https://support.microsoft.com/en-us/help/4135048', '2018-05-30', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 1'), (13, 5026, 'SP2 ', 'https://support.microsoft.com/en-us/help/4052908', '2018-04-24', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 '), - (13, 4560, 'SP2 CU14', 'https://support.microsoft.com/en-us/help/4488535', '2019-03-19', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 14'), - (13, 4550, 'SP2 CU13', 'https://support.microsoft.com/en-us/help/4475775', '2019-01-23', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 13'), - (13, 4541, 'SP2 CU12', 'https://support.microsoft.com/en-us/help/4464343', '2018-11-13', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 2 Cumulative Update 12'), + (13, 4574, 'SP1 CU15', 'https://support.microsoft.com/en-us/help/4495257', '2019-05-16', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 1 Cumulative Update 15'), + (13, 4560, 'SP1 CU14', 'https://support.microsoft.com/en-us/help/4488535', '2019-03-19', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 1 Cumulative Update 14'), + (13, 4550, 'SP1 CU13', 'https://support.microsoft.com/en-us/help/4475775', '2019-01-23', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 1 Cumulative Update 13'), + (13, 4541, 'SP1 CU12', 'https://support.microsoft.com/en-us/help/4464343', '2018-11-13', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 1 Cumulative Update 12'), (13, 4528, 'SP1 CU11', 'https://support.microsoft.com/en-us/help/4459676', '2018-09-17', '2019-07-09', '2019-07-09', 'SQL Server 2016', 'Service Pack 1 Cumulative Update 11'), (13, 4514, 'SP1 CU10', 'https://support.microsoft.com/en-us/help/4341569', '2018-07-16', '2019-07-09', '2019-07-09', 'SQL Server 2016', 'Service Pack 1 Cumulative Update 10'), (13, 4502, 'SP1 CU9', 'https://support.microsoft.com/en-us/help/4100997', '2018-05-30', '2019-07-09', '2019-07-09', 'SQL Server 2016', 'Service Pack 1 Cumulative Update 9'), @@ -78,9 +82,11 @@ VALUES (13, 2164, 'RTM CU2', 'https://support.microsoft.com/en-us/help/3182270 ', '2016-09-22', '2018-01-09', '2018-01-09', 'SQL Server 2016', 'RTM Cumulative Update 2'), (13, 2149, 'RTM CU1', 'https://support.microsoft.com/en-us/help/3164674 ', '2016-07-25', '2018-01-09', '2018-01-09', 'SQL Server 2016', 'RTM Cumulative Update 1'), (13, 1601, 'RTM ', '', '2016-06-01', '2019-01-09', '2019-01-09', 'SQL Server 2016', 'RTM '), + (12, 6259, 'SP3 CU3', 'https://support.microsoft.com/en-us/help/4491539', '2019-04-16', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 3'), (12, 6214, 'SP3 CU2', 'https://support.microsoft.com/en-us/help/4482960', '2019-02-19', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 2'), (12, 6205, 'SP3 CU1', 'https://support.microsoft.com/en-us/help/4470220', '2018-12-12', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 1'), (12, 6024, 'SP3 ', 'https://support.microsoft.com/en-us/help/4022619', '2018-10-30', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 '), + (12, 5632, 'SP2 CU17', 'https://support.microsoft.com/en-us/help/4491540', '2019-04-16', '2020-01-14', '2020-01-14', 'SQL Server 2014', 'Service Pack 2 Cumulative Update 17'), (12, 5626, 'SP2 CU16', 'https://support.microsoft.com/en-us/help/4482967', '2019-02-19', '2020-01-14', '2020-01-14', 'SQL Server 2014', 'Service Pack 2 Cumulative Update 16'), (12, 5605, 'SP2 CU15', 'https://support.microsoft.com/en-us/help/4469137', '2018-12-12', '2020-01-14', '2020-01-14', 'SQL Server 2014', 'Service Pack 2 Cumulative Update 15'), (12, 5600, 'SP2 CU14', 'https://support.microsoft.com/en-us/help/4459860', '2018-10-15', '2020-01-14', '2020-01-14', 'SQL Server 2014', 'Service Pack 2 Cumulative Update 14'), diff --git a/sp_AllNightLog.sql b/sp_AllNightLog.sql index 712857b41..7b8bb1b7b 100644 --- a/sp_AllNightLog.sql +++ b/sp_AllNightLog.sql @@ -30,7 +30,7 @@ SET NOCOUNT ON; BEGIN; -SELECT @Version = '3.4', @VersionDate = '20190320'; +SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN diff --git a/sp_AllNightLog_Setup.sql b/sp_AllNightLog_Setup.sql index ac282c6ee..19e5f9259 100644 --- a/sp_AllNightLog_Setup.sql +++ b/sp_AllNightLog_Setup.sql @@ -36,7 +36,7 @@ SET NOCOUNT ON; BEGIN; -SELECT @Version = '3.4', @VersionDate = '20190320'; +SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN diff --git a/sp_Blitz.sql b/sp_Blitz.sql index a96f39442..ccb0bc0fc 100755 --- a/sp_Blitz.sql +++ b/sp_Blitz.sql @@ -36,7 +36,7 @@ AS SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '7.4', @VersionDate = '20190320'; + SELECT @Version = '7.6', @VersionDate = '20190702'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -78,7 +78,7 @@ AS @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 + @OutputType ''TABLE''=table | ''COUNT''=row with number found | ''MARKDOWN''=bulleted list | ''SCHEMA''=version and field list | ''XML'' =table output as XML | ''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. @@ -116,8 +116,8 @@ AS 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' */ + END;/* IF @OutputType = 'SCHEMA' */ + ELSE BEGIN DECLARE @StringToExecute NVARCHAR(4000) @@ -150,7 +150,38 @@ AS ,@TraceFileIssue bit -- Flag for Windows OS to help with Linux support ,@IsWindowsOperatingSystem BIT - ,@DaysUptime NUMERIC(23,2); + ,@DaysUptime NUMERIC(23,2) + /* For First Responder Kit consistency check:*/ + ,@spBlitzFullName VARCHAR(1024) + ,@BlitzIsOutdatedComparedToOthers BIT + ,@tsql NVARCHAR(MAX) + ,@VersionCheckModeExistsTSQL NVARCHAR(MAX) + ,@BlitzProcDbName VARCHAR(256) + ,@ExecRet INT + ,@InnerExecRet INT + ,@TmpCnt INT + ,@PreviousComponentName VARCHAR(256) + ,@PreviousComponentFullPath VARCHAR(1024) + ,@CurrentStatementId INT + ,@CurrentComponentSchema VARCHAR(256) + ,@CurrentComponentName VARCHAR(256) + ,@CurrentComponentType VARCHAR(256) + ,@CurrentComponentVersionDate DATETIME2 + ,@CurrentComponentFullName VARCHAR(1024) + ,@CurrentComponentMandatory BIT + ,@MaximumVersionDate DATETIME + ,@StatementCheckName VARCHAR(256) + ,@StatementOutputsCounter BIT + ,@OutputCounterExpectedValue INT + ,@StatementOutputsExecRet BIT + ,@StatementOutputsDateTime BIT + ,@CurrentComponentMandatoryCheckOK BIT + ,@CurrentComponentVersionCheckModeOK BIT + ,@canExitLoop BIT + ,@frkIsConsistent BIT + + /* End of declarations for First Responder Kit consistency check:*/ + ; SET @crlf = NCHAR(13) + NCHAR(10); SET @ResultText = 'sp_Blitz Results: ' + @crlf; @@ -201,6 +232,47 @@ AS Finding NVARCHAR(128) ); + /* First Responder Kit consistency (temporary tables) */ + + IF(OBJECT_ID('tempdb..#FRKObjects') IS NOT NULL) + BEGIN + EXEC sp_executesql N'DROP TABLE #FRKObjects;'; + END; + + -- this one represents FRK objects + CREATE TABLE #FRKObjects ( + DatabaseName VARCHAR(256) NOT NULL, + ObjectSchemaName VARCHAR(256) NULL, + ObjectName VARCHAR(256) NOT NULL, + ObjectType VARCHAR(256) NOT NULL, + MandatoryComponent BIT NOT NULL + ); + + + IF(OBJECT_ID('tempdb..#StatementsToRun4FRKVersionCheck') IS NOT NULL) + BEGIN + EXEC sp_executesql N'DROP TABLE #StatementsToRun4FRKVersionCheck;'; + END; + + + -- This one will contain the statements to be executed + -- order: 1- Mandatory, 2- VersionCheckMode, 3- VersionCheck + + CREATE TABLE #StatementsToRun4FRKVersionCheck ( + StatementId INT IDENTITY(1,1), + CheckName VARCHAR(256), + SubjectName VARCHAR(256), + SubjectFullPath VARCHAR(1024), + StatementText NVARCHAR(MAX), + StatementOutputsCounter BIT, + OutputCounterExpectedValue INT, + StatementOutputsExecRet BIT, + StatementOutputsDateTime BIT + ); + + /* End of First Responder Kit consistency (temporary tables) */ + + /* You can build your own table with a list of checks to skip. For example, you might have some databases that you don't care about, or some checks you don't @@ -2280,7 +2352,7 @@ AS 200 AS Priority , 'Monitoring' AS FindingsGroup , 'Alerts Disabled' AS Finding , - 'https://www.BrentOzar.com/go/alerts/' AS URL , + 'https://BrentOzar.com/go/alert' AS URL , ( 'The following Alert is disabled, please review and enable if desired: ' + name ) AS Details FROM msdb.dbo.sysalerts @@ -4257,6 +4329,513 @@ IF @ProductVersionMajor >= 10 END; END; + +/*This checks that First Responder Kit is consistent. +It assumes that all the objects of the kit resides in the same database, the one in which this SP is stored +It also is ready to check for installation in another schema. +*/ +IF( + NOT EXISTS ( + SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 226 + ) +) +BEGIN + + IF @Debug IN (1, 2) RAISERROR('Running check with id %d',0,1,2000); + + SET @spBlitzFullName = QUOTENAME(DB_NAME()) + '.' +QUOTENAME(OBJECT_SCHEMA_NAME(@@PROCID)) + '.' + QUOTENAME(OBJECT_NAME(@@PROCID)); + SET @BlitzIsOutdatedComparedToOthers = 0; + SET @tsql = NULL; + SET @VersionCheckModeExistsTSQL = NULL; + SET @BlitzProcDbName = DB_NAME(); + SET @ExecRet = NULL; + SET @InnerExecRet = NULL; + SET @TmpCnt = NULL; + + SET @PreviousComponentName = NULL; + SET @PreviousComponentFullPath = NULL; + SET @CurrentStatementId = NULL; + SET @CurrentComponentSchema = NULL; + SET @CurrentComponentName = NULL; + SET @CurrentComponentType = NULL; + SET @CurrentComponentVersionDate = NULL; + SET @CurrentComponentFullName = NULL; + SET @CurrentComponentMandatory = NULL; + SET @MaximumVersionDate = NULL; + + SET @StatementCheckName = NULL; + SET @StatementOutputsCounter = NULL; + SET @OutputCounterExpectedValue = NULL; + SET @StatementOutputsExecRet = NULL; + SET @StatementOutputsDateTime = NULL; + + SET @CurrentComponentMandatoryCheckOK = NULL; + SET @CurrentComponentVersionCheckModeOK = NULL; + + SET @canExitLoop = 0; + SET @frkIsConsistent = 0; + + + SET @tsql = 'USE ' + QUOTENAME(@BlitzProcDbName) + ';' + @crlf + + 'WITH FRKComponents (' + @crlf + + ' ObjectName,' + @crlf + + ' ObjectType,' + @crlf + + ' MandatoryComponent' + @crlf + + ')' + @crlf + + 'AS (' + @crlf + + ' SELECT ''sp_AllNightLog'',''P'' ,0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''sp_AllNightLog_Setup'', ''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_Blitz'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzBackups'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzCache'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzFirst'',''P'',0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''sp_BlitzIndex'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzLock'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzQueryStore'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_BlitzWho'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_DatabaseRestore'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_foreachdb'',''P'',0' + @crlf + + ' UNION ALL ' + @crlf + + ' SELECT ''sp_ineachdb'',''P'',0' + @crlf + + ' UNION ALL' + @crlf + + ' SELECT ''SqlServerVersions'',''U'',0' + @crlf + + ')' + @crlf + + 'INSERT INTO #FRKObjects (' + @crlf + + ' DatabaseName,ObjectSchemaName,ObjectName, ObjectType,MandatoryComponent' + @crlf + + ')' + @crlf + + 'SELECT DB_NAME(),SCHEMA_NAME(o.schema_id), c.ObjectName,c.ObjectType,c.MandatoryComponent' + @crlf + + 'FROM ' + @crlf + + ' FRKComponents c' + @crlf + + 'LEFT JOIN ' + @crlf + + ' sys.objects o' + @crlf + + 'ON c.ObjectName = o.[name]' + @crlf + + 'AND c.ObjectType = o.[type]' + @crlf + + --'WHERE o.schema_id IS NOT NULL' + @crlf + + ';' + ; + + EXEC @ExecRet = sp_executesql @tsql ; + + -- TODO: add check for statement success + + -- TODO: based on SP requirements and presence (SchemaName is not null) ==> update MandatoryComponent column + + -- Filling #StatementsToRun4FRKVersionCheck + INSERT INTO #StatementsToRun4FRKVersionCheck ( + CheckName,StatementText,SubjectName,SubjectFullPath, StatementOutputsCounter,OutputCounterExpectedValue,StatementOutputsExecRet,StatementOutputsDateTime + ) + SELECT + 'Mandatory', + 'SELECT @cnt = COUNT(*) FROM #FRKObjects WHERE ObjectSchemaName IS NULL AND ObjectName = ''' + ObjectName + ''' AND MandatoryComponent = 1;', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 1, + 0, + 0, + 0 + FROM #FRKObjects + UNION ALL + SELECT + 'VersionCheckMode', + 'SELECT @cnt = COUNT(*) FROM ' + + QUOTENAME(DatabaseName) + '.sys.all_parameters ' + + 'where object_id = OBJECT_ID(''' + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName) + ''') AND [name] = ''@VersionCheckMode'';', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 1, + 1, + 0, + 0 + FROM #FRKObjects + WHERE ObjectType = 'P' + AND ObjectSchemaName IS NOT NULL + UNION ALL + SELECT + 'VersionCheck', + 'EXEC @ExecRet = ' + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName) + ' @VersionCheckMode = 1 , @VersionDate = @ObjDate OUTPUT;', + ObjectName, + QUOTENAME(DatabaseName) + '.' + QUOTENAME(ObjectSchemaName) + '.' + QUOTENAME(ObjectName), + 0, + 0, + 1, + 1 + FROM #FRKObjects + WHERE ObjectType = 'P' + AND ObjectSchemaName IS NOT NULL + ; + IF(@Debug in (1,2)) + BEGIN + SELECT * + FROM #StatementsToRun4FRKVersionCheck ORDER BY SubjectName,SubjectFullPath,StatementId -- in case of schema change ; + END; + + + -- loop on queries... + WHILE(@canExitLoop = 0) + BEGIN + SET @CurrentStatementId = NULL; + + SELECT TOP 1 + @StatementCheckName = CheckName, + @CurrentStatementId = StatementId , + @CurrentComponentName = SubjectName, + @CurrentComponentFullName = SubjectFullPath, + @tsql = StatementText, + @StatementOutputsCounter = StatementOutputsCounter, + @OutputCounterExpectedValue = OutputCounterExpectedValue , + @StatementOutputsExecRet = StatementOutputsExecRet, + @StatementOutputsDateTime = StatementOutputsDateTime + FROM #StatementsToRun4FRKVersionCheck + ORDER BY SubjectName, SubjectFullPath,StatementId /* in case of schema change */ + ; + + -- loop exit condition + IF(@CurrentStatementId IS NULL) + BEGIN + BREAK; + END; + + IF @Debug IN (1, 2) RAISERROR(' Statement: %s',0,1,@tsql); + + -- we start a new component + IF(@PreviousComponentName IS NULL OR + (@PreviousComponentName IS NOT NULL AND @PreviousComponentName <> @CurrentComponentName) OR + (@PreviousComponentName IS NOT NULL AND @PreviousComponentName = @CurrentComponentName AND @PreviousComponentFullPath <> @CurrentComponentFullName) + ) + BEGIN + -- reset variables + SET @CurrentComponentMandatoryCheckOK = 0; + SET @CurrentComponentVersionCheckModeOK = 0; + SET @PreviousComponentName = @CurrentComponentName; + SET @PreviousComponentFullPath = @CurrentComponentFullName ; + END; + + IF(@StatementCheckName NOT IN ('Mandatory','VersionCheckMode','VersionCheck')) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (code generator changed)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Your version check failed because a change has been made to the version check code generator.' + @crlf + + 'Error: No handler for check with name "' + ISNULL(@StatementCheckName,'') + '"' AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@StatementCheckName = 'Mandatory') + BEGIN + -- outputs counter + EXEC @ExecRet = sp_executesql @tsql, N'@cnt INT OUTPUT',@cnt = @TmpCnt OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Your version check failed due to dynamic query failure.' + @crlf + + 'Error: following query failed at execution (check if component [' + ISNULL(@CurrentComponentName,@CurrentComponentName) + '] is mandatory and missing)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@TmpCnt <> @OutputCounterExpectedValue) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 227 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Missing: ' + @CurrentComponentName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated version of the First Responder Kit to install it.' AS Details + ; + + -- as it's missing, no value for SubjectFullPath + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectName = @CurrentComponentName ; + CONTINUE; + END; + + SET @CurrentComponentMandatoryCheckOK = 1; + END; + + IF(@StatementCheckName = 'VersionCheckMode') + BEGIN + IF(@CurrentComponentMandatoryCheckOK = 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (unexpectedly modified checks ordering)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because "Mandatory" check has not been completed before for current component' + @crlf + + 'Error: version check mode happenned before "Mandatory" check for component called "' + @CurrentComponentFullName + '"' + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + -- outputs counter + EXEC @ExecRet = sp_executesql @tsql, N'@cnt INT OUTPUT',@cnt = @TmpCnt OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because a change has been made to the code generator.' + @crlf + + 'Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] can run in VersionCheckMode)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + IF(@TmpCnt <> @OutputCounterExpectedValue) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 228 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Outdated: ' + @CurrentComponentFullName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Component ' + @CurrentComponentFullName + ' is not at the minimum version required to run this procedure' + @crlf + + 'VersionCheckMode has been introduced in component version date after "20190320". This means its version is lower than or equal to that date.' AS Details; + ; + + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + SET @CurrentComponentVersionCheckModeOK = 1; + END; + + IF(@StatementCheckName = 'VersionCheck') + BEGIN + IF(@CurrentComponentMandatoryCheckOK = 0 OR @CurrentComponentVersionCheckModeOK = 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (unexpectedly modified checks ordering)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Version check failed because "VersionCheckMode" check has not been completed before for component called "' + @CurrentComponentFullName + '"' + @crlf + + 'Error: VersionCheck happenned before "VersionCheckMode" check for component called "' + @CurrentComponentFullName + '"' + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + EXEC @ExecRet = sp_executesql @tsql , N'@ExecRet INT OUTPUT, @ObjDate DATETIME OUTPUT', @ExecRet = @InnerExecRet OUTPUT, @ObjDate = @CurrentComponentVersionDate OUTPUT; + + IF(@ExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (dynamic query failure)' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. The version check failed because a change has been made to the code generator.' + @crlf + + 'Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] is at the expected version)' + @crlf + + @tsql AS Details + ; + + -- we will stop the test because it's possible to get the same message for other components + SET @canExitLoop = 1; + CONTINUE; + END; + + + IF(@InnerExecRet <> 0) + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 226 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Version Check Failed (Failed dynamic SP call to ' + @CurrentComponentFullName + ')' AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download an updated First Responder Kit. Error: following query failed at execution (check if component [' + @CurrentComponentFullName + '] is at the expected version)' + @crlf + + 'Return code: ' + CONVERT(VARCHAR(10),@InnerExecRet) + @crlf + + 'T-SQL Query: ' + @crlf + + @tsql AS Details + ; + + -- advance to next component + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + IF(@CurrentComponentVersionDate < @VersionDate) + BEGIN + + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 228 AS CheckID , + 253 AS Priority , + 'First Responder Kit' AS FindingsGroup , + 'Component Outdated: ' + @CurrentComponentFullName AS Finding , + 'http://FirstResponderKit.org' AS URL , + 'Download and install the latest First Responder Kit - you''re running some older code, and it doesn''t get better with age.' AS Details + ; + + RAISERROR('Component %s is outdated',10,1,@CurrentComponentFullName); + -- advance to next component + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE SubjectFullPath = @CurrentComponentFullName ; + CONTINUE; + END; + + ELSE IF(@CurrentComponentVersionDate > @VersionDate AND @BlitzIsOutdatedComparedToOthers = 0) + BEGIN + SET @BlitzIsOutdatedComparedToOthers = 1; + RAISERROR('Procedure %s is outdated',10,1,@spBlitzFullName); + IF(@MaximumVersionDate IS NULL OR @MaximumVersionDate < @CurrentComponentVersionDate) + BEGIN + SET @MaximumVersionDate = @CurrentComponentVersionDate; + END; + END; + /* Kept for debug purpose: + ELSE + BEGIN + INSERT INTO #BlitzResults( + CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT + 2000 AS CheckID , + 250 AS Priority , + 'Informational' AS FindingsGroup , + 'First Responder kit component ' + @CurrentComponentFullName + ' is at the expected version' AS Finding , + 'https://www.BrentOzar.com/blitz/' AS URL , + 'Version date is: ' + CONVERT(VARCHAR(32),@CurrentComponentVersionDate,121) AS Details + ; + END; + */ + END; + + -- could be performed differently to minimize computation + DELETE FROM #StatementsToRun4FRKVersionCheck WHERE StatementId = @CurrentStatementId ; + END; +END; + /*This counts memory dumps and gives min and max date of in view*/ IF @ProductVersionMajor >= 10 @@ -5072,9 +5651,9 @@ IF @ProductVersionMajor >= 10 DB_NAME(s.database_id) + '' has '' + CONVERT(NVARCHAR(20), COUNT_BIG(*)) - + '' open implicit transactions '' - + '' with an oldest begin time of '' - + CONVERT(NVARCHAR(30), MIN(tat.transaction_begin_time)) AS details + + '' open implicit transactions with an oldest begin time of '' + + CONVERT(NVARCHAR(30), MIN(tat.transaction_begin_time)) + + '' Run sp_BlitzWho and check the is_implicit_transaction column to see the culprits.'' AS details FROM sys.dm_tran_active_transactions AS tat LEFT JOIN sys.dm_tran_session_transactions AS tst ON tst.transaction_id = tat.transaction_id @@ -5131,6 +5710,32 @@ IF @ProductVersionMajor >= 10 END; + IF NOT EXISTS ( SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 229 ) + AND CAST(SERVERPROPERTY('Edition') AS NVARCHAR(4000)) LIKE '%Evaluation%' + BEGIN + + IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 216) WITH NOWAIT; + + INSERT INTO #BlitzResults + ( CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT 229 AS CheckID, + 1 AS Priority, + 'Reliability' AS FindingsGroup, + 'Evaluation Edition' AS Finding, + 'https://www.BrentOzar.com/go/workgroup' AS URL, + 'This server will stop working on: ' + CAST(CONVERT(DATETIME, DATEADD(DD, 180, create_date), 102) AS VARCHAR(100)) AS details + FROM sys.server_principals + WHERE sid = 0x010100000000000512000000; + + END; IF @CheckUserDatabaseObjects = 1 @@ -6115,6 +6720,37 @@ IF @ProductVersionMajor >= 10 HAVING COUNT(1) > 0;'; END; --of Check 218. + /* Check 225 - Reliability - Resumable Index Operation Paused */ + IF NOT EXISTS ( + SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL + AND CheckID = 225 + ) + AND EXISTS (SELECT * FROM sys.all_objects WHERE name = 'index_resumable_operations') + BEGIN + IF @Debug IN (1,2) + BEGIN + RAISERROR ('Running CheckId [%d].',0,1,218) WITH NOWAIT; + END + + EXECUTE sp_MSforeachdb 'USE [?]; + SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + INSERT INTO #BlitzResults (CheckID, DatabaseName, Priority, FindingsGroup, Finding, URL, Details) + SELECT 225 AS CheckID + ,''?'' AS DatabaseName + ,200 AS Priority + ,''Reliability'' AS FindingsGroup + ,''Resumable Index Operation Paused'' AS Finding + ,''https://BrentOzar.com/go/resumable'' AS URL + ,iro.state_desc + N'' since '' + CONVERT(NVARCHAR(50), last_pause_time, 120) + '', '' + + CAST(iro.percent_complete AS NVARCHAR(20)) + ''% complete: '' + + CAST(iro.sql_text AS NVARCHAR(1000)) AS Details + FROM sys.index_resumable_operations iro + JOIN sys.objects o ON iro.[object_id] = o.[object_id] + WHERE iro.state <> 0;'; + END; --of Check 225. + --/* Check 220 - Statistics Without Histograms */ --IF NOT EXISTS ( -- SELECT 1 @@ -6673,7 +7309,7 @@ IF @ProductVersionMajor >= 10 (@@SERVERNAME IS NOT NULL AND /* not a named instance */ - CHARINDEX('\',CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128))) = 0 + CHARINDEX(CHAR(92),CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128))) = 0 AND /* not clustered, when computername may be different than the servername */ SERVERPROPERTY('IsClustered') = 0 @@ -8237,6 +8873,25 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1 LEFT OUTER JOIN Results rNext ON r.rownum = rNext.rownum - 1 ORDER BY r.rownum FOR XML PATH(N''); END; + ELSE IF @OutputType = 'XML' + BEGIN + /* --TOURSTOP05-- */ + SELECT [Priority] , + [FindingsGroup] , + [Finding] , + [DatabaseName] , + [URL] , + [Details] , + [QueryPlanFiltered] , + CheckID + FROM #BlitzResults + ORDER BY Priority , + FindingsGroup , + Finding , + DatabaseName , + Details + FOR XML PATH('Result'), ROOT('sp_Blitz_Output'); + END; ELSE IF @OutputType <> 'NONE' BEGIN /* --TOURSTOP05-- */ @@ -8317,7 +8972,7 @@ GO /* --Sample execution call with the most common parameters: -EXEC [dbo].[sp_Blitz] +EXEC [dbo].[sp_Blitz] @CheckUserDatabaseObjects = 1 , @CheckProcedureCache = 0 , @OutputType = 'TABLE' , diff --git a/sp_BlitzBackups.sql b/sp_BlitzBackups.sql index cfc71a680..6807d5839 100755 --- a/sp_BlitzBackups.sql +++ b/sp_BlitzBackups.sql @@ -23,7 +23,7 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '3.4', @VersionDate = '20190320'; + SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN diff --git a/sp_BlitzCache.sql b/sp_BlitzCache.sql index 3fda277a5..14c35832c 100644 --- a/sp_BlitzCache.sql +++ b/sp_BlitzCache.sql @@ -154,7 +154,7 @@ CREATE TABLE ##BlitzCacheProcs ( unparameterized_query BIT, near_parallel BIT, plan_warnings BIT, - plan_multiple_plans BIT, + plan_multiple_plans INT, long_running BIT, downlevel_estimator BIT, implicit_conversions BIT, @@ -271,7 +271,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) @@ -911,7 +911,7 @@ BEGIN unparameterized_query BIT, near_parallel BIT, plan_warnings BIT, - plan_multiple_plans BIT, + plan_multiple_plans INT, long_running BIT, downlevel_estimator BIT, implicit_conversions BIT, @@ -1062,10 +1062,6 @@ IF @SortOrder NOT IN ('cpu', 'avg cpu', 'reads', 'avg reads', 'writes', 'avg wri SET @SortOrder = 'cpu'; END; -SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName), - @OutputSchemaName = QUOTENAME(@OutputSchemaName), - @OutputTableName = QUOTENAME(@OutputTableName); - SET @QueryFilter = LOWER(@QueryFilter); IF LEFT(@QueryFilter, 3) NOT IN ('all', 'sta', 'pro', 'fun') @@ -1080,6 +1076,25 @@ IF @SkipAnalysis = 1 SET @HideSummary = 1; END; +DECLARE @AllSortSql NVARCHAR(MAX) = N''; +DECLARE @VersionShowsMemoryGrants BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') + SET @VersionShowsMemoryGrants = 1; +ELSE + SET @VersionShowsMemoryGrants = 0; + +DECLARE @VersionShowsSpills BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') + SET @VersionShowsSpills = 1; +ELSE + SET @VersionShowsSpills = 0; + +DECLARE @VersionShowsAirQuoteActualPlans BIT; +IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') + SET @VersionShowsAirQuoteActualPlans = 1; +ELSE + SET @VersionShowsAirQuoteActualPlans = 0; + IF @Reanalyze = 1 AND OBJECT_ID('tempdb..##BlitzCacheResults') IS NULL BEGIN RAISERROR(N'##BlitzCacheResults does not exist, can''t reanalyze', 0, 1) WITH NOWAIT; @@ -1104,6 +1119,9 @@ IF @Reanalyze = 1 GOTO Results; END; + + + IF @SortOrder IN ('all', 'all avg') BEGIN RAISERROR(N'Checking all sort orders, please be patient', 0, 1) WITH NOWAIT; @@ -1733,22 +1751,15 @@ SELECT @v = common_version , FROM #checkversion OPTION (RECOMPILE); -IF (@SortOrder IN ('memory grant', 'avg memory grant')) -AND ((@v < 11) -OR (@v = 11 AND @build < 6020) -OR (@v = 12 AND @build < 5000) -OR (@v = 13 AND @build < 1601)) +IF (@SortOrder IN ('memory grant', 'avg memory grant')) AND @VersionShowsMemoryGrants = 0 BEGIN RAISERROR('Your version of SQL does not support sorting by memory grant or average memory grant. Please use another sort order.', 16, 1); RETURN; END; -IF (@SortOrder IN ('spills', 'avg spills')) -AND (@v < 13 - OR @v = 13 AND @build < 5026 - OR @v = 14 AND @build < 3015) +IF (@SortOrder IN ('spills', 'avg spills') AND @VersionShowsSpills = 0) BEGIN - RAISERROR('Your version of SQL does not support sorting by spills or average spills. Please use another sort order.', 16, 1); + RAISERROR('Your version of SQL does not support sorting by spills. Please use another sort order.', 16, 1); RETURN; END; @@ -1783,8 +1794,19 @@ FROM (SELECT TOP (@Top) x.*, xpa.*, CROSS APPLY (SELECT * FROM sys.dm_exec_plan_attributes(x.plan_handle) AS ixpa WHERE ixpa.attribute = ''dbid'') AS xpa ' + @nl ; + +IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @body += N' CROSS APPLY sys.dm_exec_query_plan_stats(x.plan_handle) AS deqps ' + @nl ; + END + SET @body += N' WHERE 1 = 1 ' + @nl ; +IF EXISTS (SELECT * FROM sys.all_objects o INNER JOIN sys.all_columns c ON o.object_id = c.object_id WHERE o.name = 'dm_hadr_database_replica_states' AND c.name = 'is_primary_replica') + BEGIN + RAISERROR(N'Ignoring readable secondaries databases by default', 0, 1) WITH NOWAIT; + SET @body += N' AND CAST(xpa.value AS INT) NOT IN (select database_id from sys.dm_hadr_database_replica_states where is_primary_replica = 0 AND DATABASEPROPERTYEX(DB_NAME(database_id), ''Updateability'') = ''READ_ONLY'')' + @nl ; + END IF @IgnoreSystemDBs = 1 BEGIN @@ -1899,6 +1921,11 @@ SET @body += N') AS qs CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS st CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp ' + @nl ; +IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @body += N' CROSS APPLY sys.dm_exec_query_plan_stats(qs.plan_handle) AS deqps ' + @nl ; + END + SET @body_where += N' AND pa.attribute = ' + QUOTENAME('dbid', @q ) + @nl ; @@ -1967,7 +1994,7 @@ SELECT TOP (@Top) NULL AS PercentMemoryGrantUsed, NULL AS AvgMaxMemoryGrant,'; - IF @v >=15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026) + IF @VersionShowsSpills = 1 BEGIN RAISERROR(N'Getting spill information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @plans_triggers_select_list += N' @@ -1986,10 +2013,20 @@ SELECT TOP (@Top) NULL AS AvgSpills, ' ; END; - SET @plans_triggers_select_list += - N'st.text AS QueryText , - query_plan AS QueryPlan, - t.t_TotalWorker, + SET @plans_triggers_select_list += + N'st.text AS QueryText ,'; + + IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @plans_triggers_select_list += N' COALESCE(deqps.query_plan, qp.query_plan) AS QueryPlan, ' + @nl ; + END; + ELSE + BEGIN + SET @plans_triggers_select_list += N' qp.query_plan AS QueryPlan, ' + @nl ; + END; + + SET @plans_triggers_select_list += + N't.t_TotalWorker, t.t_TotalElapsed, t.t_TotalReads, t.t_TotalExecs, @@ -2076,8 +2113,7 @@ BEGIN NULL AS LastReturnedRows, ' ; END; - IF (@v = 11 AND @build >= 6020) OR (@v = 12 AND @build >= 5000) OR (@v = 13 AND @build >= 1601) OR (@v >= 14) - + IF @VersionShowsMemoryGrants = 1 BEGIN RAISERROR(N'Getting memory grant information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @sql += N' @@ -2100,7 +2136,7 @@ BEGIN NULL AS AvgMaxMemoryGrant, ' ; END; - IF @v >=15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026) + IF @VersionShowsSpills = 1 BEGIN RAISERROR(N'Getting spill information for newer versions of SQL', 0, 1) WITH NOWAIT; SET @sql += N' @@ -2123,8 +2159,19 @@ BEGIN SUBSTRING(st.text, ( qs.statement_start_offset / 2 ) + 1, ( ( CASE qs.statement_end_offset WHEN -1 THEN DATALENGTH(st.text) ELSE qs.statement_end_offset - END - qs.statement_start_offset ) / 2 ) + 1) AS QueryText , - query_plan AS QueryPlan, + END - qs.statement_start_offset ) / 2 ) + 1) AS QueryText , ' + @nl ; + + + IF @VersionShowsAirQuoteActualPlans = 1 + BEGIN + SET @sql += N' COALESCE(deqps.query_plan, qp.query_plan) AS QueryPlan, ' + @nl ; + END + ELSE + BEGIN + SET @sql += N' query_plan AS QueryPlan, ' + @nl ; + END + + SET @sql += N' t.t_TotalWorker, t.t_TotalElapsed, t.t_TotalReads, @@ -2284,6 +2331,9 @@ FROM (SELECT SqlHandle, WHERE x.rn = 1 OPTION (RECOMPILE); +/* + This block was used to delete duplicate queries, but has been removed. + For more info: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2026 WITH d AS ( SELECT SPID, ROW_NUMBER() OVER (PARTITION BY SqlHandle, QueryHash ORDER BY #sortable# DESC) AS rn @@ -2293,7 +2343,8 @@ WHERE SPID = @@SPID DELETE d WHERE d.rn > 1 AND SPID = @@SPID -OPTION (RECOMPILE); +OPTION (RECOMPILE); +*/ '; SELECT @sort = CASE @SortOrder WHEN N'cpu' THEN N'TotalCPU' @@ -2398,11 +2449,11 @@ OPTION (RECOMPILE) ; * metric. */ RAISERROR('Computing CPU, duration, read, and write metrics', 0, 1) WITH NOWAIT; -DECLARE @total_duration MONEY, - @total_cpu MONEY, - @total_reads MONEY, - @total_writes MONEY, - @total_execution_count MONEY; +DECLARE @total_duration BIGINT, + @total_cpu BIGINT, + @total_reads BIGINT, + @total_writes BIGINT, + @total_execution_count BIGINT; SELECT @total_cpu = SUM(TotalCPU), @total_duration = SUM(TotalDuration), @@ -2585,7 +2636,7 @@ RAISERROR(N'Gathering high level plan information', 0, 1) WITH NOWAIT; UPDATE ##BlitzCacheProcs SET NumberOfDistinctPlans = distinct_plan_count, NumberOfPlans = number_of_plans , - plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN 1 END + plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN number_of_plans END FROM ( SELECT COUNT(DISTINCT QueryHash) AS distinct_plan_count, COUNT(QueryHash) AS number_of_plans, @@ -3395,7 +3446,7 @@ WITH XMLNAMESPACES('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS UPDATE ##BlitzCacheProcs SET NumberOfDistinctPlans = distinct_plan_count, NumberOfPlans = number_of_plans, - plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN 1 END + plan_multiple_plans = CASE WHEN distinct_plan_count < number_of_plans THEN number_of_plans END FROM ( SELECT COUNT(DISTINCT QueryHash) AS distinct_plan_count, COUNT(QueryHash) AS number_of_plans, @@ -4326,7 +4377,7 @@ SET Warnings = SUBSTRING( CASE WHEN downlevel_estimator = 1 THEN ', Downlevel CE' ELSE '' END + CASE WHEN implicit_conversions = 1 THEN ', Implicit Conversions' ELSE '' END + CASE WHEN tvf_join = 1 THEN ', Function Join' ELSE '' END + - CASE WHEN plan_multiple_plans = 1 THEN ', Multiple Plans' ELSE '' END + + CASE WHEN plan_multiple_plans > 0 THEN ', Multiple Plans' + COALESCE(' (' + CAST(plan_multiple_plans AS VARCHAR(10)) + ')', '') ELSE '' END + CASE WHEN is_trivial = 1 THEN ', Trivial Plans' ELSE '' END + CASE WHEN is_forced_serial = 1 THEN ', Forced Serialization' ELSE '' END + CASE WHEN is_key_lookup_expensive = 1 THEN ', Expensive Key Lookup' ELSE '' END + @@ -4404,7 +4455,7 @@ SELECT DISTINCT CASE WHEN downlevel_estimator = 1 THEN ', Downlevel CE' ELSE '' END + CASE WHEN implicit_conversions = 1 THEN ', Implicit Conversions' ELSE '' END + CASE WHEN tvf_join = 1 THEN ', Function Join' ELSE '' END + - CASE WHEN plan_multiple_plans = 1 THEN ', Multiple Plans' ELSE '' END + + CASE WHEN plan_multiple_plans > 0 THEN ', Multiple Plans' + COALESCE(' (' + CAST(plan_multiple_plans AS VARCHAR(10)) + ')', '') ELSE '' END + CASE WHEN is_trivial = 1 THEN ', Trivial Plans' ELSE '' END + CASE WHEN is_forced_serial = 1 THEN ', Forced Serialization' ELSE '' END + CASE WHEN is_key_lookup_expensive = 1 THEN ', Expensive Key Lookup' ELSE '' END + @@ -4495,198 +4546,7 @@ OPTION (RECOMPILE); Results: -IF @OutputDatabaseName IS NOT NULL - AND @OutputSchemaName IS NOT NULL - AND @OutputTableName IS NOT NULL -BEGIN - RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT; - - /* send results to a table */ - DECLARE @insert_sql NVARCHAR(MAX) = N'' ; - - SET @insert_sql = 'USE ' - + @OutputDatabaseName - + '; IF EXISTS(SELECT * FROM ' - + @OutputDatabaseName - + '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' - + @OutputSchemaName - + ''') AND NOT EXISTS (SELECT * FROM ' - + @OutputDatabaseName - + '.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = ''' - + @OutputSchemaName + ''' AND QUOTENAME(TABLE_NAME) = ''' - + @OutputTableName + ''') CREATE TABLE ' - + @OutputSchemaName + '.' - + @OutputTableName - + N'(ID bigint NOT NULL IDENTITY(1,1), - ServerName NVARCHAR(258), - CheckDate DATETIMEOFFSET, - Version NVARCHAR(258), - QueryType NVARCHAR(258), - Warnings varchar(max), - DatabaseName sysname, - SerialDesiredMemory float, - SerialRequiredMemory float, - AverageCPU bigint, - TotalCPU bigint, - PercentCPUByType money, - CPUWeight money, - AverageDuration bigint, - TotalDuration bigint, - DurationWeight money, - PercentDurationByType money, - AverageReads bigint, - TotalReads bigint, - ReadWeight money, - PercentReadsByType money, - AverageWrites bigint, - TotalWrites bigint, - WriteWeight money, - PercentWritesByType money, - ExecutionCount bigint, - ExecutionWeight money, - PercentExecutionsByType money,' + N' - ExecutionsPerMinute money, - PlanCreationTime datetime, - PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()), - LastExecutionTime datetime, - PlanHandle varbinary(64), - [Remove Plan Handle From Cache] AS - CASE WHEN [PlanHandle] IS NOT NULL - THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');'' - ELSE ''N/A'' END, - SqlHandle varbinary(64), - [Remove SQL Handle From Cache] AS - CASE WHEN [SqlHandle] IS NOT NULL - THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');'' - ELSE ''N/A'' END, - [SQL Handle More Info] AS - CASE WHEN [SqlHandle] IS NOT NULL - THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; '' - ELSE ''N/A'' END, - QueryHash binary(8), - [Query Hash More Info] AS - CASE WHEN [QueryHash] IS NOT NULL - THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; '' - ELSE ''N/A'' END, - QueryPlanHash binary(8), - StatementStartOffset int, - StatementEndOffset int, - MinReturnedRows bigint, - MaxReturnedRows bigint, - AverageReturnedRows money, - TotalReturnedRows bigint, - QueryText nvarchar(max), - QueryPlan xml, - NumberOfPlans int, - NumberOfDistinctPlans int, - MinGrantKB BIGINT, - MaxGrantKB BIGINT, - MinUsedGrantKB BIGINT, - MaxUsedGrantKB BIGINT, - PercentMemoryGrantUsed MONEY, - AvgMaxMemoryGrant MONEY, - MinSpills BIGINT, - MaxSpills BIGINT, - TotalSpills BIGINT, - AvgSpills MONEY, - QueryPlanCost FLOAT, - CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))'; - - IF @Debug = 1 - BEGIN - PRINT SUBSTRING(@insert_sql, 0, 4000); - PRINT SUBSTRING(@insert_sql, 4000, 8000); - PRINT SUBSTRING(@insert_sql, 8000, 12000); - PRINT SUBSTRING(@insert_sql, 12000, 16000); - PRINT SUBSTRING(@insert_sql, 16000, 20000); - PRINT SUBSTRING(@insert_sql, 20000, 24000); - PRINT SUBSTRING(@insert_sql, 24000, 28000); - PRINT SUBSTRING(@insert_sql, 28000, 32000); - PRINT SUBSTRING(@insert_sql, 32000, 36000); - PRINT SUBSTRING(@insert_sql, 36000, 40000); - END; - - EXEC sp_executesql @insert_sql ; - - IF @CheckDateOverride IS NULL - BEGIN - SET @CheckDateOverride = SYSDATETIMEOFFSET(); - END; - - - SET @insert_sql = N' IF EXISTS(SELECT * FROM ' - + @OutputDatabaseName - + N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' - + @OutputSchemaName + N''') ' - + N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;' - + 'INSERT ' - + @OutputDatabaseName + '.' - + @OutputSchemaName + '.' - + @OutputTableName - + N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' - + N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' - + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' - + N'SELECT TOP (@Top) ' - + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', @CheckDateOverride, ' - + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', ' - + N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' - + N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' - + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' - + N' FROM ##BlitzCacheProcs ' - + N' WHERE 1=1 '; - - IF @MinimumExecutionCount IS NOT NULL - BEGIN - SET @insert_sql += N' AND ExecutionCount >= @MinimumExecutionCount '; - END; - - IF @MinutesBack IS NOT NULL - BEGIN - SET @insert_sql += N' AND LastExecutionTime >= DATEADD(MINUTE, @min_back, GETDATE() ) '; - END; - - SET @insert_sql += N' AND SPID = @@SPID '; - - SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU ' - WHEN N'reads' THEN N' TotalReads ' - WHEN N'writes' THEN N' TotalWrites ' - WHEN N'duration' THEN N' TotalDuration ' - WHEN N'executions' THEN N' ExecutionCount ' - WHEN N'compiles' THEN N' PlanCreationTime ' - WHEN N'memory grant' THEN N' MaxGrantKB' - WHEN N'spills' THEN N' MaxSpills' - WHEN N'avg cpu' THEN N' AverageCPU' - WHEN N'avg reads' THEN N' AverageReads' - WHEN N'avg writes' THEN N' AverageWrites' - WHEN N'avg duration' THEN N' AverageDuration' - WHEN N'avg executions' THEN N' ExecutionsPerMinute' - WHEN N'avg memory grant' THEN N' AvgMaxMemoryGrant' - WHEN 'avg spills' THEN N' AvgSpills' - END + N' DESC '; - - SET @insert_sql += N' OPTION (RECOMPILE) ; '; - - IF @Debug = 1 - BEGIN - PRINT SUBSTRING(@insert_sql, 0, 4000); - PRINT SUBSTRING(@insert_sql, 4000, 8000); - PRINT SUBSTRING(@insert_sql, 8000, 12000); - PRINT SUBSTRING(@insert_sql, 12000, 16000); - PRINT SUBSTRING(@insert_sql, 16000, 20000); - PRINT SUBSTRING(@insert_sql, 20000, 24000); - PRINT SUBSTRING(@insert_sql, 24000, 28000); - PRINT SUBSTRING(@insert_sql, 28000, 32000); - PRINT SUBSTRING(@insert_sql, 32000, 36000); - PRINT SUBSTRING(@insert_sql, 36000, 40000); - END; - - EXEC sp_executesql @insert_sql, N'@Top INT, @min_duration INT, @min_back INT, @CheckDateOverride DATETIMEOFFSET, @MinimumExecutionCount INT', @Top, @DurationFilter_i, @MinutesBack, @CheckDateOverride, @MinimumExecutionCount; - - RETURN; -END; -ELSE IF @ExportToExcel = 1 +IF @ExportToExcel = 1 BEGIN RAISERROR('Displaying results with Excel formatting (no plans).', 0, 1) WITH NOWAIT; @@ -4817,31 +4677,31 @@ BEGIN missing_indexes AS [Missing Indexes], implicit_conversion_info AS [Implicit Conversion Info], cached_execution_parameters AS [Cached Execution Parameters], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS MONEY), 1), N''.00'', N'''') AS [# Executions], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS MONEY), 1), N''.00'', N'''') AS [Executions / Minute], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS MONEY), 1), N''.00'', N'''') AS [Execution Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalCPU) AS MONEY), 1), N''.00'', N'''') AS [Total CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageCPU) AS MONEY), 1), N''.00'', N'''') AS [Avg CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPU) AS MONEY), 1), N''.00'', N'''') AS [CPU Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalDuration) AS MONEY), 1), N''.00'', N'''') AS [Total Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageDuration) AS MONEY), 1), N''.00'', N'''') AS [Avg Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDuration) AS MONEY), 1), N''.00'', N'''') AS [Duration Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReads) AS MONEY), 1), N''.00'', N'''') AS [Total Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReads) AS MONEY), 1), N''.00'', N'''') AS [Avg Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReads) AS MONEY), 1), N''.00'', N'''') AS [Read Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalWrites) AS MONEY), 1), N''.00'', N'''') AS [Total Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageWrites) AS MONEY), 1), N''.00'', N'''') AS [Avg Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWrites) AS MONEY), 1), N''.00'', N'''') AS [Write Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Average Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS MONEY), 1), N''.00'', N'''') AS [Average Max Memory Grant], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinSpills) AS MONEY), 1), N''.00'', N'''') AS [Min Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxSpills) AS MONEY), 1), N''.00'', N'''') AS [Max Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalSpills) AS MONEY), 1), N''.00'', N'''') AS [Total Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1), N''.00'', N'''') AS [Avg Spills], + CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS BIGINT), 1) AS [# Executions], + CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS BIGINT), 1) AS [Executions / Minute], + CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS BIGINT), 1) AS [Execution Weight], + CONVERT(NVARCHAR(30), CAST((TotalCPU) AS BIGINT), 1) AS [Total CPU (ms)], + CONVERT(NVARCHAR(30), CAST((AverageCPU) AS BIGINT), 1) AS [Avg CPU (ms)], + CONVERT(NVARCHAR(30), CAST((PercentCPU) AS BIGINT), 1) AS [CPU Weight], + CONVERT(NVARCHAR(30), CAST((TotalDuration) AS BIGINT), 1) AS [Total Duration (ms)], + CONVERT(NVARCHAR(30), CAST((AverageDuration) AS BIGINT), 1) AS [Avg Duration (ms)], + CONVERT(NVARCHAR(30), CAST((PercentDuration) AS BIGINT), 1) AS [Duration Weight], + CONVERT(NVARCHAR(30), CAST((TotalReads) AS BIGINT), 1) AS [Total Reads], + CONVERT(NVARCHAR(30), CAST((AverageReads) AS BIGINT), 1) AS [Avg Reads], + CONVERT(NVARCHAR(30), CAST((PercentReads) AS BIGINT), 1) AS [Read Weight], + CONVERT(NVARCHAR(30), CAST((TotalWrites) AS BIGINT), 1) AS [Total Writes], + CONVERT(NVARCHAR(30), CAST((AverageWrites) AS BIGINT), 1) AS [Avg Writes], + CONVERT(NVARCHAR(30), CAST((PercentWrites) AS BIGINT), 1) AS [Write Weight], + CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS BIGINT), 1) AS [Average Rows], + CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS BIGINT), 1) AS [Minimum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS BIGINT), 1) AS [Maximum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS BIGINT), 1) AS [Minimum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS BIGINT), 1) AS [Maximum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS BIGINT), 1) AS [Average Max Memory Grant], + CONVERT(NVARCHAR(30), CAST((MinSpills) AS BIGINT), 1) AS [Min Spills], + CONVERT(NVARCHAR(30), CAST((MaxSpills) AS BIGINT), 1) AS [Max Spills], + CONVERT(NVARCHAR(30), CAST((TotalSpills) AS BIGINT), 1) AS [Total Spills], + CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1) AS [Avg Spills], PlanCreationTime AS [Created At], LastExecutionTime AS [Last Execution], PlanHandle AS [Plan Handle], @@ -4884,7 +4744,7 @@ BEGIN CASE WHEN downlevel_estimator = 1 THEN '', 13'' ELSE '''' END + CASE WHEN implicit_conversions = 1 THEN '', 14'' ELSE '''' END + CASE WHEN tvf_join = 1 THEN '', 17'' ELSE '''' END + - CASE WHEN plan_multiple_plans = 1 THEN '', 21'' ELSE '''' END + + CASE WHEN plan_multiple_plans > 0 THEN '', 21'' ELSE '''' END + CASE WHEN unmatched_index_count > 0 THEN '', 22'' ELSE '''' END + CASE WHEN is_trivial = 1 THEN '', 24'' ELSE '''' END + CASE WHEN is_forced_serial = 1 THEN '', 25'' ELSE '''' END + @@ -4931,49 +4791,49 @@ BEGIN END; SET @columns += N' - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS MONEY), 1), N''.00'', N'''') AS [# Executions], - REPLACE(CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS MONEY), 1), N''.00'', N'''') AS [Executions / Minute], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS MONEY), 1), N''.00'', N'''') AS [Execution Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((SerialDesiredMemory) AS MONEY), 1), N''.00'', N'''') AS [Serial Desired Memory], - REPLACE(CONVERT(NVARCHAR(30), CAST((SerialRequiredMemory) AS MONEY), 1), N''.00'', N'''') AS [Serial Required Memory], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalCPU) AS MONEY), 1), N''.00'', N'''') AS [Total CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageCPU) AS MONEY), 1), N''.00'', N'''') AS [Avg CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPU) AS MONEY), 1), N''.00'', N'''') AS [CPU Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalDuration) AS MONEY), 1), N''.00'', N'''') AS [Total Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageDuration) AS MONEY), 1), N''.00'', N'''') AS [Avg Duration (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDuration) AS MONEY), 1), N''.00'', N'''') AS [Duration Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReads) AS MONEY), 1), N''.00'', N'''') AS [Total Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReads) AS MONEY), 1), N''.00'', N'''') AS [Average Reads], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReads) AS MONEY), 1), N''.00'', N'''') AS [Read Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalWrites) AS MONEY), 1), N''.00'', N'''') AS [Total Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageWrites) AS MONEY), 1), N''.00'', N'''') AS [Average Writes], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWrites) AS MONEY), 1), N''.00'', N'''') AS [Write Weight], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentExecutionsByType) AS MONEY), 1), N''.00'', N'''') AS [% Executions (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentCPUByType) AS MONEY), 1), N''.00'', N'''') AS [% CPU (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentDurationByType) AS MONEY), 1), N''.00'', N'''') AS [% Duration (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentReadsByType) AS MONEY), 1), N''.00'', N'''') AS [% Reads (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((PercentWritesByType) AS MONEY), 1), N''.00'', N'''') AS [% Writes (Type)], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Total Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Avg Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Min Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxReturnedRows) AS MONEY), 1), N''.00'', N'''') AS [Max Rows], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Memory Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Minimum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS MONEY), 1), N''.00'', N'''') AS [Maximum Used Grant KB], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS MONEY), 1), N''.00'', N'''') AS [Average Max Memory Grant], - REPLACE(CONVERT(NVARCHAR(30), CAST((MinSpills) AS MONEY), 1), N''.00'', N'''') AS [Min Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((MaxSpills) AS MONEY), 1), N''.00'', N'''') AS [Max Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((TotalSpills) AS MONEY), 1), N''.00'', N'''') AS [Total Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1), N''.00'', N'''') AS [Avg Spills], - REPLACE(CONVERT(NVARCHAR(30), CAST((NumberOfPlans) AS MONEY), 1), N''.00'', N'''') AS [# Plans], - REPLACE(CONVERT(NVARCHAR(30), CAST((NumberOfDistinctPlans) AS MONEY), 1), N''.00'', N'''') AS [# Distinct Plans], + CONVERT(NVARCHAR(30), CAST((ExecutionCount) AS BIGINT), 1) AS [# Executions], + CONVERT(NVARCHAR(30), CAST((ExecutionsPerMinute) AS BIGINT), 1) AS [Executions / Minute], + CONVERT(NVARCHAR(30), CAST((PercentExecutions) AS BIGINT), 1) AS [Execution Weight], + CONVERT(NVARCHAR(30), CAST((SerialDesiredMemory) AS BIGINT), 1) AS [Serial Desired Memory], + CONVERT(NVARCHAR(30), CAST((SerialRequiredMemory) AS BIGINT), 1) AS [Serial Required Memory], + CONVERT(NVARCHAR(30), CAST((TotalCPU) AS BIGINT), 1) AS [Total CPU (ms)], + CONVERT(NVARCHAR(30), CAST((AverageCPU) AS BIGINT), 1) AS [Avg CPU (ms)], + CONVERT(NVARCHAR(30), CAST((PercentCPU) AS BIGINT), 1) AS [CPU Weight], + CONVERT(NVARCHAR(30), CAST((TotalDuration) AS BIGINT), 1) AS [Total Duration (ms)], + CONVERT(NVARCHAR(30), CAST((AverageDuration) AS BIGINT), 1) AS [Avg Duration (ms)], + CONVERT(NVARCHAR(30), CAST((PercentDuration) AS BIGINT), 1) AS [Duration Weight], + CONVERT(NVARCHAR(30), CAST((TotalReads) AS BIGINT), 1) AS [Total Reads], + CONVERT(NVARCHAR(30), CAST((AverageReads) AS BIGINT), 1) AS [Average Reads], + CONVERT(NVARCHAR(30), CAST((PercentReads) AS BIGINT), 1) AS [Read Weight], + CONVERT(NVARCHAR(30), CAST((TotalWrites) AS BIGINT), 1) AS [Total Writes], + CONVERT(NVARCHAR(30), CAST((AverageWrites) AS BIGINT), 1) AS [Average Writes], + CONVERT(NVARCHAR(30), CAST((PercentWrites) AS BIGINT), 1) AS [Write Weight], + CONVERT(NVARCHAR(30), CAST((PercentExecutionsByType) AS BIGINT), 1) AS [% Executions (Type)], + CONVERT(NVARCHAR(30), CAST((PercentCPUByType) AS BIGINT), 1) AS [% CPU (Type)], + CONVERT(NVARCHAR(30), CAST((PercentDurationByType) AS BIGINT), 1) AS [% Duration (Type)], + CONVERT(NVARCHAR(30), CAST((PercentReadsByType) AS BIGINT), 1) AS [% Reads (Type)], + CONVERT(NVARCHAR(30), CAST((PercentWritesByType) AS BIGINT), 1) AS [% Writes (Type)], + CONVERT(NVARCHAR(30), CAST((TotalReturnedRows) AS BIGINT), 1) AS [Total Rows], + CONVERT(NVARCHAR(30), CAST((AverageReturnedRows) AS BIGINT), 1) AS [Avg Rows], + CONVERT(NVARCHAR(30), CAST((MinReturnedRows) AS BIGINT), 1) AS [Min Rows], + CONVERT(NVARCHAR(30), CAST((MaxReturnedRows) AS BIGINT), 1) AS [Max Rows], + CONVERT(NVARCHAR(30), CAST((MinGrantKB) AS BIGINT), 1) AS [Minimum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxGrantKB) AS BIGINT), 1) AS [Maximum Memory Grant KB], + CONVERT(NVARCHAR(30), CAST((MinUsedGrantKB) AS BIGINT), 1) AS [Minimum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((MaxUsedGrantKB) AS BIGINT), 1) AS [Maximum Used Grant KB], + CONVERT(NVARCHAR(30), CAST((AvgMaxMemoryGrant) AS BIGINT), 1) AS [Average Max Memory Grant], + CONVERT(NVARCHAR(30), CAST((MinSpills) AS BIGINT), 1) AS [Min Spills], + CONVERT(NVARCHAR(30), CAST((MaxSpills) AS BIGINT), 1) AS [Max Spills], + CONVERT(NVARCHAR(30), CAST((TotalSpills) AS BIGINT), 1) AS [Total Spills], + CONVERT(NVARCHAR(30), CAST((AvgSpills) AS MONEY), 1) AS [Avg Spills], + CONVERT(NVARCHAR(30), CAST((NumberOfPlans) AS BIGINT), 1) AS [# Plans], + CONVERT(NVARCHAR(30), CAST((NumberOfDistinctPlans) AS BIGINT), 1) AS [# Distinct Plans], PlanCreationTime AS [Created At], LastExecutionTime AS [Last Execution], - REPLACE(CONVERT(NVARCHAR(30), CAST((CachedPlanSize) AS MONEY), 1), N''.00'', N'''') AS [Cached Plan Size (KB)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileTime) AS MONEY), 1), N''.00'', N'''') AS [Compile Time (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileCPU) AS MONEY), 1), N''.00'', N'''') AS [Compile CPU (ms)], - REPLACE(CONVERT(NVARCHAR(30), CAST((CompileMemory) AS MONEY), 1), N''.00'', N'''') AS [Compile memory (KB)], + CONVERT(NVARCHAR(30), CAST((CachedPlanSize) AS BIGINT), 1) AS [Cached Plan Size (KB)], + CONVERT(NVARCHAR(30), CAST((CompileTime) AS BIGINT), 1) AS [Compile Time (ms)], + CONVERT(NVARCHAR(30), CAST((CompileCPU) AS BIGINT), 1) AS [Compile CPU (ms)], + CONVERT(NVARCHAR(30), CAST((CompileMemory) AS BIGINT), 1) AS [Compile memory (KB)], COALESCE(SetOptions, '''') AS [SET Options], PlanHandle AS [Plan Handle], SqlHandle AS [SQL Handle], @@ -5330,7 +5190,7 @@ BEGIN IF EXISTS (SELECT 1/0 FROM ##BlitzCacheProcs - WHERE plan_multiple_plans = 1 + WHERE plan_multiple_plans > 0 AND SPID = @@SPID) INSERT INTO ##BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL, Details) VALUES (@@SPID, @@ -6101,7 +5961,10 @@ IF @Debug = 1 END; - + IF @OutputDatabaseName IS NOT NULL + AND @OutputSchemaName IS NOT NULL + AND @OutputTableName IS NOT NULL + GOTO OutputResultsToTable; RETURN; --Avoid going into the AllSort GOTO /*Begin code to sort by all*/ @@ -6196,29 +6059,6 @@ IF OBJECT_ID('tempdb.. #bou_allsort') IS NULL ); END; -DECLARE @AllSortSql NVARCHAR(MAX) = N''; -DECLARE @MemGrant BIT; -SELECT @MemGrant = CASE WHEN ( - ( @v < 11 ) - OR ( - @v = 11 - AND @build < 6020 - ) - OR ( - @v = 12 - AND @build < 5000 - ) - OR ( - @v = 13 - AND @build < 1601 - ) - ) THEN 0 - ELSE 1 - END; - -DECLARE @Spills BIT; -SELECT @Spills = CASE WHEN (@v >= 15 OR (@v = 14 AND @build >= 3015) OR (@v = 13 AND @build >= 5026)) THEN 1 ELSE 0 END; - IF LOWER(@SortOrder) = 'all' BEGIN @@ -6231,7 +6071,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''cpu'', @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''cpu'', @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''cpu'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -6242,7 +6082,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''reads'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -6253,7 +6093,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''writes'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -6264,7 +6104,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''duration'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -6275,13 +6115,13 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''executions'' WHERE Pattern IS NULL OPTION(RECOMPILE); '; - IF @MemGrant = 0 + IF @VersionShowsMemoryGrants = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -6300,7 +6140,7 @@ SET @AllSortSql += N' END; - IF @MemGrant = 1 + IF @VersionShowsMemoryGrants = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -6309,7 +6149,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -6329,7 +6169,7 @@ SET @AllSortSql += N' END; - IF @Spills = 0 + IF @VersionShowsSpills = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -6348,7 +6188,7 @@ SET @AllSortSql += N' END; - IF @Spills = 1 + IF @VersionShowsSpills = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -6357,7 +6197,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -6399,7 +6239,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg cpu'', @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg cpu'', @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg cpu'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -6410,7 +6250,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg reads'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg reads'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -6421,7 +6261,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg writes'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg writes'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -6432,7 +6272,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg duration'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg duration'' WHERE Pattern IS NULL OPTION(RECOMPILE); @@ -6443,13 +6283,13 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg executions'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg executions'' WHERE Pattern IS NULL OPTION(RECOMPILE); '; - IF @MemGrant = 0 + IF @VersionShowsMemoryGrants = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -6468,7 +6308,7 @@ SET @AllSortSql += N' END; - IF @MemGrant = 1 + IF @VersionShowsMemoryGrants = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -6477,7 +6317,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg memory grant'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -6497,7 +6337,7 @@ SET @AllSortSql += N' END; - IF @Spills = 0 + IF @VersionShowsSpills = 0 BEGIN IF @ExportToExcel = 1 BEGIN @@ -6516,7 +6356,7 @@ SET @AllSortSql += N' END; - IF @Spills = 1 + IF @VersionShowsSpills = 1 BEGIN SET @AllSortSql += N' SELECT TOP 1 @ISH = STUFF((SELECT DISTINCT N'','' + CONVERT(NVARCHAR(MAX),b2.SqlHandle, 1) FROM #bou_allsort AS b2 FOR XML PATH(N''''), TYPE).value(N''.[1]'', N''NVARCHAR(MAX)''), 1, 1, N'''') OPTION(RECOMPILE); @@ -6525,7 +6365,7 @@ SET @AllSortSql += N' ReadWeight, TotalWrites, AverageWrites, WriteWeight, AverageReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, SetOptions ) - EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName WITH RECOMPILE; + EXEC sp_BlitzCache @ExpertMode = 0, @HideSummary = 1, @Top = @i_Top, @SortOrder = ''avg spills'', @IgnoreSqlHandles = @ISH, @DatabaseName = @i_DatabaseName, @SkipAnalysis = @i_SkipAnalysis, @OutputDatabaseName = @i_OutputDatabaseName, @OutputSchemaName = @i_OutputSchemaName, @OutputTableName = @i_OutputTableName WITH RECOMPILE; UPDATE #bou_allsort SET Pattern = ''avg memory grant'' WHERE Pattern IS NULL OPTION(RECOMPILE);'; IF @ExportToExcel = 1 @@ -6568,11 +6408,209 @@ END; PRINT SUBSTRING(@AllSortSql, 36000, 40000); END; - EXEC sys.sp_executesql @stmt = @AllSortSql, @params = N'@i_DatabaseName NVARCHAR(128), @i_Top INT', @i_DatabaseName = @DatabaseName, @i_Top = @Top; + EXEC sys.sp_executesql @stmt = @AllSortSql, @params = N'@i_DatabaseName NVARCHAR(128), @i_Top INT, @i_SkipAnalysis BIT, @i_OutputDatabaseName NVARCHAR(258), @i_OutputSchemaName NVARCHAR(258), @i_OutputTableName NVARCHAR(258)', + @i_DatabaseName = @DatabaseName, @i_Top = @Top, @i_SkipAnalysis = @SkipAnalysis, @i_OutputDatabaseName = @OutputDatabaseName, @i_OutputSchemaName = @OutputSchemaName, @i_OutputTableName = @OutputTableName; /*End of AllSort section*/ +/*Begin code to sort by all*/ +OutputResultsToTable: + +IF @OutputDatabaseName IS NOT NULL + AND @OutputSchemaName IS NOT NULL + AND @OutputTableName IS NOT NULL +BEGIN + RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT; + + SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName), + @OutputSchemaName = QUOTENAME(@OutputSchemaName), + @OutputTableName = QUOTENAME(@OutputTableName); + + /* send results to a table */ + DECLARE @insert_sql NVARCHAR(MAX) = N'' ; + + SET @insert_sql = 'USE ' + + @OutputDatabaseName + + '; IF EXISTS(SELECT * FROM ' + + @OutputDatabaseName + + '.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' + + @OutputSchemaName + + ''') AND NOT EXISTS (SELECT * FROM ' + + @OutputDatabaseName + + '.INFORMATION_SCHEMA.TABLES WHERE QUOTENAME(TABLE_SCHEMA) = ''' + + @OutputSchemaName + ''' AND QUOTENAME(TABLE_NAME) = ''' + + @OutputTableName + ''') CREATE TABLE ' + + @OutputSchemaName + '.' + + @OutputTableName + + N'(ID bigint NOT NULL IDENTITY(1,1), + ServerName NVARCHAR(258), + CheckDate DATETIMEOFFSET, + Version NVARCHAR(258), + QueryType NVARCHAR(258), + Warnings varchar(max), + DatabaseName sysname, + SerialDesiredMemory float, + SerialRequiredMemory float, + AverageCPU bigint, + TotalCPU bigint, + PercentCPUByType money, + CPUWeight money, + AverageDuration bigint, + TotalDuration bigint, + DurationWeight money, + PercentDurationByType money, + AverageReads bigint, + TotalReads bigint, + ReadWeight money, + PercentReadsByType money, + AverageWrites bigint, + TotalWrites bigint, + WriteWeight money, + PercentWritesByType money, + ExecutionCount bigint, + ExecutionWeight money, + PercentExecutionsByType money,' + N' + ExecutionsPerMinute money, + PlanCreationTime datetime, + PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()), + LastExecutionTime datetime, + PlanHandle varbinary(64), + [Remove Plan Handle From Cache] AS + CASE WHEN [PlanHandle] IS NOT NULL + THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');'' + ELSE ''N/A'' END, + SqlHandle varbinary(64), + [Remove SQL Handle From Cache] AS + CASE WHEN [SqlHandle] IS NOT NULL + THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');'' + ELSE ''N/A'' END, + [SQL Handle More Info] AS + CASE WHEN [SqlHandle] IS NOT NULL + THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; '' + ELSE ''N/A'' END, + QueryHash binary(8), + [Query Hash More Info] AS + CASE WHEN [QueryHash] IS NOT NULL + THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; '' + ELSE ''N/A'' END, + QueryPlanHash binary(8), + StatementStartOffset int, + StatementEndOffset int, + MinReturnedRows bigint, + MaxReturnedRows bigint, + AverageReturnedRows money, + TotalReturnedRows bigint, + QueryText nvarchar(max), + QueryPlan xml, + NumberOfPlans int, + NumberOfDistinctPlans int, + MinGrantKB BIGINT, + MaxGrantKB BIGINT, + MinUsedGrantKB BIGINT, + MaxUsedGrantKB BIGINT, + PercentMemoryGrantUsed MONEY, + AvgMaxMemoryGrant MONEY, + MinSpills BIGINT, + MaxSpills BIGINT, + TotalSpills BIGINT, + AvgSpills MONEY, + QueryPlanCost FLOAT, + CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))'; + + IF @Debug = 1 + BEGIN + PRINT SUBSTRING(@insert_sql, 0, 4000); + PRINT SUBSTRING(@insert_sql, 4000, 8000); + PRINT SUBSTRING(@insert_sql, 8000, 12000); + PRINT SUBSTRING(@insert_sql, 12000, 16000); + PRINT SUBSTRING(@insert_sql, 16000, 20000); + PRINT SUBSTRING(@insert_sql, 20000, 24000); + PRINT SUBSTRING(@insert_sql, 24000, 28000); + PRINT SUBSTRING(@insert_sql, 28000, 32000); + PRINT SUBSTRING(@insert_sql, 32000, 36000); + PRINT SUBSTRING(@insert_sql, 36000, 40000); + END; + + EXEC sp_executesql @insert_sql ; + + IF @CheckDateOverride IS NULL + BEGIN + SET @CheckDateOverride = SYSDATETIMEOFFSET(); + END; + + + SET @insert_sql = N' IF EXISTS(SELECT * FROM ' + + @OutputDatabaseName + + N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = ''' + + @OutputSchemaName + N''') ' + + N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;' + + 'INSERT ' + + @OutputDatabaseName + '.' + + @OutputSchemaName + '.' + + @OutputTableName + + N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + + N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' + + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + N'SELECT TOP (@Top) ' + + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', @CheckDateOverride, ' + + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', ' + + N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + + N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + + N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' + + N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + N' FROM ##BlitzCacheProcs ' + + N' WHERE 1=1 '; + + IF @MinimumExecutionCount IS NOT NULL + BEGIN + SET @insert_sql += N' AND ExecutionCount >= @MinimumExecutionCount '; + END; + + IF @MinutesBack IS NOT NULL + BEGIN + SET @insert_sql += N' AND LastExecutionTime >= DATEADD(MINUTE, @min_back, GETDATE() ) '; + END; + + SET @insert_sql += N' AND SPID = @@SPID '; + + SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU ' + WHEN N'reads' THEN N' TotalReads ' + WHEN N'writes' THEN N' TotalWrites ' + WHEN N'duration' THEN N' TotalDuration ' + WHEN N'executions' THEN N' ExecutionCount ' + WHEN N'compiles' THEN N' PlanCreationTime ' + WHEN N'memory grant' THEN N' MaxGrantKB' + WHEN N'spills' THEN N' MaxSpills' + WHEN N'avg cpu' THEN N' AverageCPU' + WHEN N'avg reads' THEN N' AverageReads' + WHEN N'avg writes' THEN N' AverageWrites' + WHEN N'avg duration' THEN N' AverageDuration' + WHEN N'avg executions' THEN N' ExecutionsPerMinute' + WHEN N'avg memory grant' THEN N' AvgMaxMemoryGrant' + WHEN 'avg spills' THEN N' AvgSpills' + END + N' DESC '; + + SET @insert_sql += N' OPTION (RECOMPILE) ; '; + + IF @Debug = 1 + BEGIN + PRINT SUBSTRING(@insert_sql, 0, 4000); + PRINT SUBSTRING(@insert_sql, 4000, 8000); + PRINT SUBSTRING(@insert_sql, 8000, 12000); + PRINT SUBSTRING(@insert_sql, 12000, 16000); + PRINT SUBSTRING(@insert_sql, 16000, 20000); + PRINT SUBSTRING(@insert_sql, 20000, 24000); + PRINT SUBSTRING(@insert_sql, 24000, 28000); + PRINT SUBSTRING(@insert_sql, 28000, 32000); + PRINT SUBSTRING(@insert_sql, 32000, 36000); + PRINT SUBSTRING(@insert_sql, 36000, 40000); + END; + + EXEC sp_executesql @insert_sql, N'@Top INT, @min_duration INT, @min_back INT, @CheckDateOverride DATETIMEOFFSET, @MinimumExecutionCount INT', @Top, @DurationFilter_i, @MinutesBack, @CheckDateOverride, @MinimumExecutionCount; +END; /* End of writing results to table */ + END; /*Final End*/ GO diff --git a/sp_BlitzFirst.sql b/sp_BlitzFirst.sql index 0c1a49e54..297f1539c 100644 --- a/sp_BlitzFirst.sql +++ b/sp_BlitzFirst.sql @@ -42,7 +42,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -128,7 +128,6 @@ DECLARE @StringToExecute NVARCHAR(MAX), @ObjectFullName NVARCHAR(2000), @BlitzWho NVARCHAR(MAX) = N'EXEC dbo.sp_BlitzWho @ShowSleepingSPIDs = ' + CONVERT(NVARCHAR(1), @ShowSleepingSPIDs) + N';', @BlitzCacheMinutesBack INT, - @BlitzCacheSortOrder VARCHAR(50), @UnquotedOutputServerName NVARCHAR(256) = @OutputServerName , @UnquotedOutputDatabaseName NVARCHAR(256) = @OutputDatabaseName , @UnquotedOutputSchemaName NVARCHAR(256) = @OutputSchemaName ; @@ -1285,8 +1284,9 @@ BEGIN 'Maintenance Tasks Running' AS FindingGroup, 'Backup Running' AS Finding, 'http://www.BrentOzar.com/askbrent/backups/' AS URL, - 'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) is ' + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' - + CASE WHEN COALESCE(s.nt_user_name, s.login_name) IS NOT NULL THEN (' Login: ' + COALESCE(s.nt_user_name, s.login_name) + ' ') ELSE '' END AS Details, + 'Backup of ' + DB_NAME(db.resource_database_id) + ' database (' + (SELECT CAST(CAST(SUM(size * 8.0 / 1024 / 1024) AS BIGINT) AS NVARCHAR) FROM #MasterFiles WHERE database_id = db.resource_database_id) + 'GB) ' + @LineFeed + + CAST(r.percent_complete AS NVARCHAR(100)) + '% complete, has been running since ' + CAST(r.start_time AS NVARCHAR(100)) + '. ' + @LineFeed + + CASE WHEN COALESCE(s.nt_user_name, s.login_name) IS NOT NULL THEN (' Login: ' + COALESCE(s.nt_user_name, s.login_name) + ' ') ELSE '' END AS Details, 'KILL ' + CAST(r.session_id AS NVARCHAR(100)) + ';' AS HowToStopIt, pl.query_plan AS QueryPlan, r.start_time AS StartTime, @@ -1424,9 +1424,9 @@ BEGIN ''Long-Running Query Blocking Others'' AS Finding, ''http://www.BrentOzar.com/go/blocking'' AS URL, ''Query in '' + COALESCE(DB_NAME(COALESCE((SELECT TOP 1 dbid FROM sys.dm_exec_sql_text(r.sql_handle)), - (SELECT TOP 1 t.dbid FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) t WHERE spBlocker.spid = tBlocked.blocking_session_id))), ''(Unknown)'') + '' has a last request start time of '' + CAST(s.last_request_start_time AS NVARCHAR(100)) + ''. Query follows:'' ' + (SELECT TOP 1 t.dbid FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) t WHERE spBlocker.spid = tBlocked.blocking_session_id))), ''(Unknown)'') + '' has a last request start time of '' + CAST(s.last_request_start_time AS NVARCHAR(100)) + ''. Query follows: ' + @LineFeed + @LineFeed + - '+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(r.sql_handle)), + '''+ CAST(COALESCE((SELECT TOP 1 [text] FROM sys.dm_exec_sql_text(r.sql_handle)), (SELECT TOP 1 [text] FROM master..sysprocesses spBlocker CROSS APPLY sys.dm_exec_sql_text(spBlocker.sql_handle) WHERE spBlocker.spid = tBlocked.blocking_session_id), '''') AS NVARCHAR(2000)) AS Details, ''KILL '' + CAST(tBlocked.blocking_session_id AS NVARCHAR(100)) + '';'' AS HowToStopIt, (SELECT TOP 1 query_plan FROM sys.dm_exec_query_plan(r.plan_handle)) AS QueryPlan, @@ -1444,7 +1444,9 @@ BEGIN INNER JOIN sys.dm_exec_sessions s ON tBlocked.blocking_session_id = s.session_id LEFT OUTER JOIN sys.dm_exec_requests r ON s.session_id = r.session_id INNER JOIN sys.dm_exec_connections c ON s.session_id = c.session_id - WHERE tBlocked.wait_type LIKE ''LCK%'' AND tBlocked.wait_duration_ms > 30000;'; + WHERE tBlocked.wait_type LIKE ''LCK%'' AND tBlocked.wait_duration_ms > 30000 + /* And the blocking session ID is not blocked by anyone else: */ + AND NOT EXISTS(SELECT * FROM sys.dm_os_waiting_tasks tBlocking WHERE s.session_id = tBlocking.session_id AND tBlocking.session_id <> tBlocking.blocking_session_id AND tBlocking.blocking_session_id IS NOT NULL);'; EXECUTE sp_executesql @StringToExecute; END; @@ -1512,17 +1514,18 @@ BEGIN SET @StringToExecute = N'INSERT INTO #BlitzFirstResults (CheckID, Priority, FindingsGroup, Finding, URL, Details, HowToStopIt, StartTime, LoginName, NTUserName, ProgramName, HostName, DatabaseID, DatabaseName, QueryText, OpenTransactionCount) SELECT 37 AS CheckId, 50 AS Priority, - ''Implicit Transactions'' AS FindingsGroup, - ''Queries were found running using implicit transactions'', + ''Query Problems'' AS FindingsGroup, + ''Implicit Transactions'', ''https://www.brentozar.com/go/ImplicitTransactions/'' AS URL, - ''Database: '' + DB_NAME(s.database_id) + '' '' + - ''Host: '' + s.[host_name] + '' '' + - ''Program: '' + s.[program_name] + '' '' + + ''Database: '' + DB_NAME(s.database_id) + '' '' + CHAR(13) + CHAR(10) + + ''Host: '' + s.[host_name] + '' '' + CHAR(13) + CHAR(10) + + ''Program: '' + s.[program_name] + '' '' + CHAR(13) + CHAR(10) + CONVERT(NVARCHAR(10), s.open_transaction_count) + '' open transactions since: '' + CONVERT(NVARCHAR(30), tat.transaction_begin_time) + ''. '' AS Details, - ''Check client configuration options'' AS HowToStopit, + ''Run sp_BlitzWho and check the is_implicit_transaction column to spot the culprits. +If one of them is a lead blocker, consider killing that query.'' AS HowToStopit, tat.transaction_begin_time, s.login_name, s.nt_user_name, @@ -2740,55 +2743,6 @@ BEGIN RAISERROR('Calling sp_BlitzCache',10,1) WITH NOWAIT; - /* Set the sp_BlitzCache sort order based on their top wait type */ - - /* First, check for poison waits - CheckID 30 */ - IF EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 30) - BEGIN - SELECT TOP 1 @BlitzCacheSortOrder = CASE - WHEN Finding = 'Poison Wait Detected: RESOURCE_SEMAPHORE' AND @memGrantSortSupported = 1 THEN 'memory grant' - WHEN Finding = 'Poison Wait Detected: RESOURCE_SEMAPHORE_QUERY_COMPILE' AND @memGrantSortSupported = 1 THEN 'memory grant' - WHEN Finding = 'Poison Wait Detected: THREADPOOL' THEN 'executions' - WHEN Finding = 'Poison Wait Detected: LOG_RATE_GOVERNOR' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_CATCHUP_THROTTLE' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_COMMIT_ACK' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_ROLLBACK_ACK' THEN 'writes' - WHEN Finding = 'Poison Wait Detected: SE_REPL_SLOW_SECONDARY_THROTTLE' THEN 'writes' - ELSE NULL - END - FROM #BlitzFirstResults - WHERE CheckID = 30 - ORDER BY DetailsInt DESC; - END; - - /* Too much free memory - which probably indicates queries finished w/huge grants - CheckID 34 */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 34) AND @memGrantSortSupported = 1 - SET @BlitzCacheSortOrder = 'memory grant'; - - /* Next, Compilations/Sec High - CheckID 15 and 16 */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID IN (15,16)) - SET @BlitzCacheSortOrder = 'recent compilations'; - - /* Still not set? Use the top wait type. */ - IF @BlitzCacheSortOrder IS NULL AND EXISTS (SELECT * FROM #BlitzFirstResults WHERE CheckID = 6) - BEGIN - SELECT TOP 1 @BlitzCacheSortOrder = CASE - WHEN Finding = 'ASYNC_NETWORK_IO' THEN 'duration' - WHEN Finding = 'CXPACKET' THEN 'reads' - WHEN Finding = 'LATCH_EX' THEN 'reads' - WHEN Finding LIKE 'LCK%' THEN 'duration' - WHEN Finding LIKE 'PAGEIOLATCH%' THEN 'reads' - WHEN Finding = 'SOS_SCHEDULER_YIELD' THEN 'cpu' - WHEN Finding = 'WRITELOG' THEN 'writes' - ELSE NULL - END - FROM #BlitzFirstResults - WHERE CheckID = 6 - ORDER BY DetailsInt DESC; - END; - /* Still null? Just use the default. */ - - /* If they have an newer version of sp_BlitzCache that supports @MinutesBack and @CheckDateOverride */ IF EXISTS (SELECT * FROM sys.objects o @@ -2812,23 +2766,15 @@ BEGIN IF @BlitzCacheMinutesBack IS NULL OR @BlitzCacheMinutesBack < 1 OR @BlitzCacheMinutesBack > 60 SET @BlitzCacheMinutesBack = 15; - IF @BlitzCacheSortOrder IS NOT NULL - EXEC sp_BlitzCache - @OutputDatabaseName = @UnquotedOutputDatabaseName, - @OutputSchemaName = @UnquotedOutputSchemaName, - @OutputTableName = @OutputTableNameBlitzCache, - @CheckDateOverride = @StartSampleTime, - @SortOrder = @BlitzCacheSortOrder, - @MinutesBack = @BlitzCacheMinutesBack, - @Debug = @Debug; - ELSE - EXEC sp_BlitzCache - @OutputDatabaseName = @UnquotedOutputDatabaseName, - @OutputSchemaName = @UnquotedOutputSchemaName, - @OutputTableName = @OutputTableNameBlitzCache, - @CheckDateOverride = @StartSampleTime, - @MinutesBack = @BlitzCacheMinutesBack, - @Debug = @Debug; + EXEC sp_BlitzCache + @OutputDatabaseName = @UnquotedOutputDatabaseName, + @OutputSchemaName = @UnquotedOutputSchemaName, + @OutputTableName = @OutputTableNameBlitzCache, + @CheckDateOverride = @StartSampleTime, + @SortOrder = 'all', + @SkipAnalysis = 1, + @MinutesBack = @BlitzCacheMinutesBack, + @Debug = @Debug; /* Delete history older than @OutputTableRetentionDays */ SET @StringToExecute = N' IF EXISTS(SELECT * FROM ' diff --git a/sp_BlitzInMemoryOLTP.sql b/sp_BlitzInMemoryOLTP.sql index c52dc5c1f..0fcfee3ca 100644 --- a/sp_BlitzInMemoryOLTP.sql +++ b/sp_BlitzInMemoryOLTP.sql @@ -82,7 +82,7 @@ THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLI */ AS DECLARE @ScriptVersion VARCHAR(30); -SELECT @ScriptVersion = '1.8', @VersionDate = '20180801'; +SELECT @ScriptVersion = '1.9', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN diff --git a/sp_BlitzIndex.sql b/sp_BlitzIndex.sql index 8c9b295bf..13433db06 100644 --- a/sp_BlitzIndex.sql +++ b/sp_BlitzIndex.sql @@ -24,6 +24,7 @@ ALTER PROCEDURE dbo.sp_BlitzIndex @SkipStatistics BIT = 1, @GetAllDatabases BIT = 0, @BringThePain BIT = 0, + @IgnoreDatabases NVARCHAR(MAX) = NULL, /* Comma-delimited list of databases you want to skip */ @ThresholdMB INT = 250 /* Number of megabytes that an object must be before we include it in basic results */, @OutputType VARCHAR(20) = 'TABLE' , @OutputServerName NVARCHAR(256) = NULL , @@ -39,7 +40,7 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -119,12 +120,14 @@ DECLARE @collation NVARCHAR(256); DECLARE @NumDatabases INT; DECLARE @LineFeed NVARCHAR(5); DECLARE @DaysUptimeInsertValue NVARCHAR(256); +DECLARE @DatabaseToIgnore NVARCHAR(MAX); SET @LineFeed = CHAR(13) + CHAR(10); SELECT @SQLServerProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)); SELECT @SQLServerEdition =CAST(SERVERPROPERTY('EngineEdition') AS INT); /* We default to online index creates where EngineEdition=3*/ SET @FilterMB=250; SELECT @ScriptVersionName = 'sp_BlitzIndex(TM) v' + @Version + ' - ' + DATENAME(MM, @VersionDate) + ' ' + RIGHT('0'+DATENAME(DD, @VersionDate),2) + ', ' + DATENAME(YY, @VersionDate); +SET @IgnoreDatabases = LTRIM(RTRIM(@IgnoreDatabases)); RAISERROR(N'Starting run. %s', 0,1, @ScriptVersionName) WITH NOWAIT; @@ -203,6 +206,9 @@ IF OBJECT_ID('tempdb..#CheckConstraints') IS NOT NULL IF OBJECT_ID('tempdb..#FilteredIndexes') IS NOT NULL DROP TABLE #FilteredIndexes; +IF OBJECT_ID('tempdb..#Ignore_Databases') IS NOT NULL + DROP TABLE #Ignore_Databases + RAISERROR (N'Create temp tables.',0,1) WITH NOWAIT; CREATE TABLE #BlitzIndexResults ( @@ -685,6 +691,12 @@ IF OBJECT_ID('tempdb..#FilteredIndexes') IS NOT NULL column_name NVARCHAR(128) NULL ); + CREATE TABLE #Ignore_Databases + ( + DatabaseName NVARCHAR(128), + Reason NVARCHAR(100) + ); + /* Sanitize our inputs */ SELECT @OutputServerName = QUOTENAME(@OutputServerName), @@ -733,6 +745,37 @@ IF @GetAllDatabases = 1 END; END; + IF @IgnoreDatabases IS NOT NULL + AND LEN(@IgnoreDatabases) > 0 + BEGIN + RAISERROR(N'Setting up filter to ignore databases', 0, 1) WITH NOWAIT; + SET @DatabaseToIgnore = ''; + + WHILE LEN(@IgnoreDatabases) > 0 + BEGIN + IF PATINDEX('%,%', @IgnoreDatabases) > 0 + BEGIN + SET @DatabaseToIgnore = SUBSTRING(@IgnoreDatabases, 0, PATINDEX('%,%',@IgnoreDatabases)) ; + + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseToIgnore, 'Specified in the @IgnoreDatabases parameter' + OPTION (RECOMPILE) ; + + SET @IgnoreDatabases = SUBSTRING(@IgnoreDatabases, LEN(@DatabaseToIgnore + ',') + 1, LEN(@IgnoreDatabases)) ; + END; + ELSE + BEGIN + SET @DatabaseToIgnore = @IgnoreDatabases ; + SET @IgnoreDatabases = NULL ; + + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseToIgnore, 'Specified in the @IgnoreDatabases parameter' + OPTION (RECOMPILE) ; + END; + END; + + END + END; ELSE BEGIN @@ -818,16 +861,72 @@ BEGIN CATCH RETURN; END CATCH; + +RAISERROR (N'Checking partition counts to exclude databases with over 100 partitions',0,1) WITH NOWAIT; +IF @BringThePain = 0 AND @SkipPartitions = 0 AND @TableName IS NULL + BEGIN + DECLARE partition_cursor CURSOR FOR + SELECT dl.DatabaseName + FROM #DatabaseList dl + LEFT OUTER JOIN #Ignore_Databases i ON dl.DatabaseName = i.DatabaseName + WHERE COALESCE(dl.secondary_role_allow_connections_desc, 'OK') <> 'NO' + AND i.DatabaseName IS NULL + + OPEN partition_cursor + FETCH NEXT FROM partition_cursor INTO @DatabaseName + + WHILE @@FETCH_STATUS = 0 + BEGIN + /* Count the total number of partitions */ + SET @dsql = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + SELECT @RowcountOUT = SUM(1) FROM ' + QUOTENAME(@DatabaseName) + '.sys.partitions WHERE partition_number > 1 OPTION ( RECOMPILE );'; + EXEC sp_executesql @dsql, N'@RowcountOUT BIGINT OUTPUT', @RowcountOUT = @Rowcount OUTPUT; + IF @Rowcount > 100 + BEGIN + RAISERROR (N'Skipping database %s because > 100 partitions were found. To check this database, you must set @BringThePain = 1.',0,1,@DatabaseName) WITH NOWAIT; + INSERT INTO #Ignore_Databases (DatabaseName, Reason) + SELECT @DatabaseName, 'Over 100 partitions found - use @BringThePain = 1 to analyze' + END; + FETCH NEXT FROM partition_cursor INTO @DatabaseName + END; + CLOSE partition_cursor + DEALLOCATE partition_cursor + + END; + +INSERT #BlitzIndexResults ( Priority, check_id, findings_group, finding, URL, details, index_definition, + index_usage_summary, index_size_summary ) +SELECT 1, 0 , + 'Database Skipped', + i.DatabaseName, + 'http://FirstResponderKit.org', + i.Reason, '', '', '' +FROM #Ignore_Databases i; + + +/* 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 OR @DaysUptime IS NULL + SET @DaysUptime = .01; + +SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPERTY('ServerName')))) + ' Days Uptime: ' + RTRIM(@DaysUptime); + + /* Permission granted or unnecessary? Ok, let's go! */ +RAISERROR (N'Starting loop through databases',0,1) WITH NOWAIT; DECLARE c1 CURSOR LOCAL FAST_FORWARD FOR -SELECT DatabaseName -FROM #DatabaseList -WHERE COALESCE(secondary_role_allow_connections_desc, 'OK') -<> 'NO' -ORDER BY DatabaseName; +SELECT dl.DatabaseName +FROM #DatabaseList dl +LEFT OUTER JOIN #Ignore_Databases i ON dl.DatabaseName = i.DatabaseName +WHERE COALESCE(dl.secondary_role_allow_connections_desc, 'OK') <> 'NO' + AND i.DatabaseName IS NULL +ORDER BY dl.DatabaseName; OPEN c1; FETCH NEXT FROM c1 INTO @DatabaseName; @@ -845,16 +944,6 @@ FROM sys.databases AND user_access_desc='MULTI_USER' AND state_desc = 'ONLINE'; -/* 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 OR @DaysUptime IS NULL - SET @DaysUptime = .01; - -SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPERTY('ServerName')))) + ' Days Uptime: ' + RTRIM(@DaysUptime); - ---------------------------------------- --STEP 1: OBSERVE THE PATIENT --This step puts index information into temp tables. @@ -862,7 +951,7 @@ SELECT @DaysUptimeInsertValue = 'Server: ' + (CONVERT(VARCHAR(256), (SERVERPROPE BEGIN TRY BEGIN - --Validate SQL Server Verson + --Validate SQL Server Version IF (SELECT LEFT(@SQLServerProductVersion, CHARINDEX('.',@SQLServerProductVersion,0)-1 diff --git a/sp_BlitzLock.sql b/sp_BlitzLock.sql index 0a7e81ac7..95d35a0ed 100644 --- a/sp_BlitzLock.sql +++ b/sp_BlitzLock.sql @@ -27,7 +27,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '2.4', @VersionDate = '20190320'; +SELECT @Version = '2.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) @@ -183,7 +183,13 @@ You need to use an Azure storage account, and the path has to look like this: ht DECLARE @d VARCHAR(40), @StringToExecute NVARCHAR(4000); CREATE TABLE #t (id INT NOT NULL); - UPDATE STATISTICS #t WITH ROWCOUNT = 100000000, PAGECOUNT = 100000000; + + /* WITH ROWCOUNT doesn't work on Amazon RDS - see: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/2037 */ + 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-' + AND db_id('rdsadmin') IS NULL + UPDATE STATISTICS #t WITH ROWCOUNT = 100000000, PAGECOUNT = 100000000; /*Grab the initial set of XML to parse*/ SET @d = CONVERT(VARCHAR(40), GETDATE(), 109); @@ -1115,14 +1121,14 @@ You need to use an Azure storage account, and the path has to look like this: ht DENSE_RANK() OVER ( ORDER BY dp.event_date ) AS en, ROW_NUMBER() OVER ( PARTITION BY dp.event_date ORDER BY dp.event_date ) -1 AS qn, NULL AS is_victim, - cao.wait_type AS owner_mode, + cao.wait_type COLLATE DATABASE_DEFAULT AS owner_mode, cao.waiter_type AS owner_waiter_type, cao.owner_activity AS owner_activity, cao.waiter_activity AS owner_waiter_activity, cao.merging AS owner_merging, cao.spilling AS owner_spilling, cao.waiting_to_close AS owner_waiting_to_close, - caw.wait_type AS waiter_mode, + caw.wait_type COLLATE DATABASE_DEFAULT AS waiter_mode, caw.waiter_type AS waiter_waiter_type, caw.owner_activity AS waiter_owner_activity, caw.waiter_activity AS waiter_waiter_activity, diff --git a/sp_BlitzQueryStore.sql b/sp_BlitzQueryStore.sql index b425b7d7a..eabbe7c90 100644 --- a/sp_BlitzQueryStore.sql +++ b/sp_BlitzQueryStore.sql @@ -56,7 +56,7 @@ BEGIN /*First BEGIN*/ SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '3.4', @VersionDate = '20190320'; +SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN RETURN; @@ -3149,9 +3149,9 @@ WITH XMLNAMESPACES('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS UPDATE b SET b.is_fast_forward_cursor = 1 FROM #working_warnings b -JOIN #statements AS qs -ON b.sql_handle = qs.sql_handle -CROSS APPLY qs.statement.nodes('/p:StmtCursor') AS n1(fn) +JOIN #statements AS s +ON b.sql_handle = s.sql_handle +CROSS APPLY s.statement.nodes('/p:StmtCursor') AS n1(fn) WHERE n1.fn.exist('//p:CursorPlan/@CursorActualType[.="FastForward"]') = 1 AND s.is_cursor = 1 OPTION (RECOMPILE); diff --git a/sp_BlitzWho.sql b/sp_BlitzWho.sql index bb2189ede..954ed7e61 100644 --- a/sp_BlitzWho.sql +++ b/sp_BlitzWho.sql @@ -27,7 +27,7 @@ BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '7.4', @VersionDate = '20190320'; + SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN diff --git a/sp_DatabaseRestore.sql b/sp_DatabaseRestore.sql index a6758b3b7..3ced91721 100755 --- a/sp_DatabaseRestore.sql +++ b/sp_DatabaseRestore.sql @@ -34,7 +34,7 @@ SET NOCOUNT ON; /*Versioning details*/ -SELECT @Version = '7.4', @VersionDate = '20190320'; +SELECT @Version = '7.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -386,6 +386,25 @@ SET @RestoreDatabaseName = QUOTENAME(@RestoreDatabaseName); IF NOT EXISTS (SELECT * FROM sys.configurations WHERE name = 'xp_cmdshell' AND value_in_use = 1) SET @SimpleFolderEnumeration = 1; +SET @HeadersSQL = +N'INSERT INTO #Headers WITH (TABLOCK) + (BackupName, BackupDescription, BackupType, ExpirationDate, Compressed, Position, DeviceType, UserName, ServerName + ,DatabaseName, DatabaseVersion, DatabaseCreationDate, BackupSize, FirstLSN, LastLSN, CheckpointLSN, DatabaseBackupLSN + ,BackupStartDate, BackupFinishDate, SortOrder, CodePage, UnicodeLocaleId, UnicodeComparisonStyle, CompatibilityLevel + ,SoftwareVendorId, SoftwareVersionMajor, SoftwareVersionMinor, SoftwareVersionBuild, MachineName, Flags, BindingID + ,RecoveryForkID, Collation, FamilyGUID, HasBulkLoggedData, IsSnapshot, IsReadOnly, IsSingleUser, HasBackupChecksums + ,IsDamaged, BeginsLogChain, HasIncompleteMetaData, IsForceOffline, IsCopyOnly, FirstRecoveryForkID, ForkPointLSN + ,RecoveryModel, DifferentialBaseLSN, DifferentialBaseGUID, BackupTypeDescription, BackupSetGUID, CompressedBackupSize'; + +IF @MajorVersion >= 11 + SET @HeadersSQL += NCHAR(13) + NCHAR(10) + N', Containment'; + +IF @MajorVersion >= 13 OR (@MajorVersion = 12 AND @BuildVersion >= 2342) + SET @HeadersSQL += N', KeyAlgorithm, EncryptorThumbprint, EncryptorType'; + +SET @HeadersSQL += N')' + NCHAR(13) + NCHAR(10); +SET @HeadersSQL += N'EXEC (''RESTORE HEADERONLY FROM DISK=''''{Path}'''''')'; + IF @BackupPathFull IS NOT NULL BEGIN IF @SimpleFolderEnumeration = 1 @@ -526,25 +545,6 @@ BEGIN SELECT '#SplitBackups' AS table_name, * FROM #SplitBackups END - SET @HeadersSQL = - N'INSERT INTO #Headers WITH (TABLOCK) - (BackupName, BackupDescription, BackupType, ExpirationDate, Compressed, Position, DeviceType, UserName, ServerName - ,DatabaseName, DatabaseVersion, DatabaseCreationDate, BackupSize, FirstLSN, LastLSN, CheckpointLSN, DatabaseBackupLSN - ,BackupStartDate, BackupFinishDate, SortOrder, CodePage, UnicodeLocaleId, UnicodeComparisonStyle, CompatibilityLevel - ,SoftwareVendorId, SoftwareVersionMajor, SoftwareVersionMinor, SoftwareVersionBuild, MachineName, Flags, BindingID - ,RecoveryForkID, Collation, FamilyGUID, HasBulkLoggedData, IsSnapshot, IsReadOnly, IsSingleUser, HasBackupChecksums - ,IsDamaged, BeginsLogChain, HasIncompleteMetaData, IsForceOffline, IsCopyOnly, FirstRecoveryForkID, ForkPointLSN - ,RecoveryModel, DifferentialBaseLSN, DifferentialBaseGUID, BackupTypeDescription, BackupSetGUID, CompressedBackupSize'; - - IF @MajorVersion >= 11 - SET @HeadersSQL += NCHAR(13) + NCHAR(10) + N', Containment'; - - IF @MajorVersion >= 13 OR (@MajorVersion = 12 AND @BuildVersion >= 2342) - SET @HeadersSQL += N', KeyAlgorithm, EncryptorThumbprint, EncryptorType'; - - SET @HeadersSQL += N')' + NCHAR(13) + NCHAR(10); - SET @HeadersSQL += N'EXEC (''RESTORE HEADERONLY FROM DISK=''''{Path}'''''')'; - --get the backup completed data so we can apply tlogs from that point forwards SET @sql = REPLACE(@HeadersSQL, N'{Path}', @BackupPathFull + @LastFullBackup); IF @Debug = 1 @@ -717,6 +717,16 @@ BEGIN END; END; +IF @BackupPathFull IS NULL AND @ContinueLogs = 1 +BEGIN + + SELECT @DatabaseLastLSN = CAST(f.redo_start_lsn AS NUMERIC(25, 0)) + FROM master.sys.databases d + JOIN master.sys.master_files f ON d.database_id = f.database_id + WHERE d.name = SUBSTRING(@RestoreDatabaseName, 2, LEN(@RestoreDatabaseName) - 2) AND f.file_id = 1; + +END; + IF @BackupPathDiff IS NOT NULL BEGIN DELETE FROM @FileList; diff --git a/sp_foreachdb.sql b/sp_foreachdb.sql index 50857b466..594104946 100644 --- a/sp_foreachdb.sql +++ b/sp_foreachdb.sql @@ -34,7 +34,7 @@ ALTER PROCEDURE dbo.sp_foreachdb AS BEGIN SET NOCOUNT ON; - SELECT @Version = '3.4', @VersionDate = '20190320'; + SELECT @Version = '3.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN diff --git a/sp_ineachdb.sql b/sp_ineachdb.sql index f9e28d0fd..2249ea299 100644 --- a/sp_ineachdb.sql +++ b/sp_ineachdb.sql @@ -1,8 +1,8 @@ IF OBJECT_ID('dbo.sp_ineachdb') IS NULL - EXEC ('CREATE PROCEDURE dbo.sp_ineachdb AS RETURN 0'); + EXEC ('CREATE PROCEDURE dbo.sp_ineachdb AS RETURN 0') GO -ALTER PROCEDURE dbo.sp_ineachdb +ALTER PROCEDURE [dbo].[sp_ineachdb] -- mssqltips.com/sqlservertip/5694/execute-a-command-in-the-context-of-each-database-in-sql-server--part-2/ @command nvarchar(max) = NULL, @replace_character nchar(1) = N'?', @@ -33,7 +33,7 @@ AS BEGIN SET NOCOUNT ON; - SELECT @Version = '2.4', @VersionDate = '20190320'; + SELECT @Version = '2.6', @VersionDate = '20190702'; IF(@VersionCheckMode = 1) BEGIN @@ -87,6 +87,9 @@ IF @Help = 1 */ '; + + RETURN -1; + END DECLARE @exec nvarchar(150), @sx nvarchar(18) = N'.sys.sp_executesql', @@ -96,6 +99,9 @@ IF @Help = 1 @thisdb sysname, @cr char(2) = CHAR(13) + CHAR(10); +DECLARE @SQLVersion AS tinyint = (@@microsoftversion / 0x1000000) & 0xff -- Stores the SQL Server Version Number(8(2000),9(2005),10(2008 & 2008R2),11(2012),12(2014),13(2016),14(2017)) +DECLARE @ServerName AS sysname = CONVERT(sysname, SERVERPROPERTY('ServerName')) -- Stores the SQL Server Instance name. + CREATE TABLE #ineachdb(id int, name nvarchar(512)); IF @database_list > N'' @@ -187,12 +193,14 @@ IF @Help = 1 -- https://docs.microsoft.com/en-us/sql/t-sql/functions/databasepropertyex-transact-sql ) OR (@state_desc <> N'ONLINE' AND state_desc <> @state_desc) - OR - ( - -- from Andy Mallon / First Responders Kit. Make sure that if we're an - -- AG secondary, we skip any database where allow connections is off - SERVERPROPERTY('IsHadrEnabled') = 1 - AND EXISTS + ) + ); + +-- from Andy Mallon / First Responders Kit. Make sure that if we're an +-- AG secondary, we skip any database where allow connections is off +if @SQLVersion >= 11 + DELETE dbs FROM #ineachdb AS dbs + WHERE EXISTS ( SELECT 1 FROM sys.dm_hadr_database_replica_states AS drs INNER JOIN sys.availability_replicas AS ar @@ -201,10 +209,7 @@ IF @Help = 1 ON ags.group_id = ar.group_id WHERE drs.database_id = dbs.id AND ar.secondary_role_allow_connections = 0 - AND ags.primary_replica <> @@SERVERNAME - ) - ) - ) + AND ags.primary_replica <> @ServerName ); -- Well, if we deleted them all... @@ -265,5 +270,4 @@ IF @Help = 1 CLOSE dbs; DEALLOCATE dbs; END -END GO