diff --git a/.github/ISSUE_TEMPLATE.md b/.github/ISSUE_TEMPLATE.md index aa21be249..f065b84a3 100644 --- a/.github/ISSUE_TEMPLATE.md +++ b/.github/ISSUE_TEMPLATE.md @@ -2,7 +2,7 @@ **What is the current behavior?** -**If the current behavior is a bug, please provide the steps to reproduce and if possible a minimal demo of the problem via https://jsfiddle.net +**If the current behavior is a bug, please provide the steps to reproduce and if possible a minimal demo of the problem via http://sqlfiddle.com **What is the expected behavior?** diff --git a/Documentation/sp_Blitz Checks by Priority.md b/Documentation/sp_Blitz Checks by Priority.md index 8bed1aa11..af0399438 100644 --- a/Documentation/sp_Blitz Checks by Priority.md +++ b/Documentation/sp_Blitz Checks by Priority.md @@ -34,6 +34,7 @@ If you want to change anything about a check - the priority, finding, URL, or ID | 20 | Reliability | Dangerous Build of SQL Server (Security) | https://technet.microsoft.com/en-us/library/security/MS14-044 | 157 | | 20 | Reliability | Databases in Unusual States | http://BrentOzar.com/go/repair | 102 | | 20 | Reliability | Memory Dumps Have Occurred | http://BrentOzar.com/go/dump | 171 | +| 20 | Reliability | No Failover Cluster Nodes Available | http://BrentOzar.com/go/node | 184 | | 20 | Reliability | Plan Guides Failing | http://BrentOzar.com/go/guides | 164 | | 20 | Reliability | Query Store Cleanup Disabled | http://BrentOzar.com/go/cleanup | 182 | | 20 | Reliability | Unsupported Build of SQL Server | http://BrentOzar.com/go/unsupported | 128 | @@ -61,9 +62,11 @@ If you want to change anything about a check - the priority, finding, URL, or ID | 100 | Performance | Max Memory Set Too High | http://BrentOzar.com/go/max | 50 | | 100 | Performance | Memory Pressure Affecting Queries | http://BrentOzar.com/go/grants | 117 | | 100 | Performance | Partitioned database with non-aligned indexes | http://BrentOzar.com/go/aligned | 72 | +| 100 | Performance | Repetitive Maintenance Tasks | https://ola.hallengren.com | 181 | | 100 | Performance | Resource Governor Enabled | http://BrentOzar.com/go/rg | 10 | | 100 | Performance | Server Triggers Enabled | http://BrentOzar.com/go/logontriggers/ | 11 | | 100 | Performance | Shrink Database Job | http://BrentOzar.com/go/autoshrink | 79 | +| 100 | Performance | Shrink Database Step In Maintenance Plan | http://BrentOzar.com/go/autoshrink | 180 | | 100 | Performance | Single-Use Plans in Procedure Cache | http://BrentOzar.com/go/single | 35 | | 100 | Performance | Stored Procedure WITH RECOMPILE | http://BrentOzar.com/go/recompile | 78 | | 100 | Performance | Unusual SQL Server Edition | http://BrentOzar.com/go/workgroup | 97 | @@ -106,6 +109,7 @@ If you want to change anything about a check - the priority, finding, URL, or ID | 170 | Reliability | Max File Size Set | http://BrentOzar.com/go/maxsize | 80 | | 200 | Backup | Backing Up Unneeded Database | http://BrentOzar.com/go/reportservertempdb | 127 | | 200 | Backup | MSDB Backup History Not Purged | http://BrentOzar.com/go/history | 3 | +| 200 | Backup | MSDB Backup History Purged Too Frequently | http://BrentOzar.com/go/history | 186 | | 200 | Informational | @@Servername not set | http://BrentOzar.com/go/servername | 70 | | 200 | Informational | Agent Jobs Starting Simultaneously | http://BrentOzar.com/go/busyagent | 123 | | 200 | Informational | Backup Compression Default Off | http://BrentOzar.com/go/backup | 116 | @@ -230,6 +234,7 @@ If you want to change anything about a check - the priority, finding, URL, or ID | 230 | Security | Control Server Permissions | http://BrentOzar.com/go/sa | 104 | | 230 | Security | Database Owner <> SA | http://BrentOzar.com/go/owndb | 55 | | 230 | Security | Elevated Permissions on a Database | http://BrentOzar.com/go/elevated | 86 | +| 230 | Security | Endpoints Owned by Users | http://BrentOzar.com/go/owners | 187 | | 230 | Security | Jobs Owned By Users | http://BrentOzar.com/go/owners | 6 | | 230 | Security | Security Admins | http://BrentOzar.com/go/sa | 5 | | 230 | Security | Server Audits Running | http://BrentOzar.com/go/audits | 8 | @@ -238,6 +243,7 @@ If you want to change anything about a check - the priority, finding, URL, or ID | 230 | Security | Sysadmins | http://BrentOzar.com/go/sa | 4 | | 240 | Wait Stats | No Significant Waits Detected | http://BrentOzar.com/go/waits | 153 | | 240 | Wait Stats | Top Wait Stats | http://BrentOzar.com/go/waits | 152 | +| 240 | Wait Stats | Wait Stats Have Been Cleared | http://BrentOzar.com/go/waits | 185 | | 250 | Informational | SQL Server Agent is running under an NT Service account | http://BrentOzar.com/go/setup | 170 | | 250 | Informational | SQL Server is running under an NT Service account | http://BrentOzar.com/go/setup | 169 | | 250 | Server Info | Agent is Currently Offline | | 167 | @@ -255,5 +261,3 @@ If you want to change anything about a check - the priority, finding, URL, or ID | 250 | Server Info | Virtual Server | http://BrentOzar.com/go/virtual | 103 | | 250 | Server Info | Windows Version | | 172 | | 254 | Rundate | (Current Date) | | 156 | -| 100 | Performance | Shrink Database Step In Maintenance Plan | http://BrentOzar.com/go/autoshrink | 180 | -| 100 | Performance | Repetitive Maintenance Tasks | https://ola.hallengren.com | 181 | diff --git a/sp_Blitz.sql b/sp_Blitz.sql index cc9246a5e..1891fbb0d 100755 --- a/sp_Blitz.sql +++ b/sp_Blitz.sql @@ -29,7 +29,8 @@ ALTER PROCEDURE [dbo].[sp_Blitz] AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SET @VersionDate = '20160903' + SET @VersionDate = '20161014'; + SET @OutputType = UPPER(@OutputType); IF @Help = 1 PRINT ' /* @@ -56,7 +57,7 @@ AS - None. (If we knew them, they would be known. Duh.) Changes - for the full list of improvements and fixes in this version, see: - https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/milestone/4?closed=1 + https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ Parameter explanations: @@ -66,7 +67,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 | ''SCHEMA''=version and field list | ''NONE'' = none + @OutputType ''TABLE''=table | ''COUNT''=row with number found | ''MARKDOWN''=bulleted list | ''SCHEMA''=version and field list | ''NONE'' = none @IgnorePrioritiesBelow 50=ignore priorities below 50 @IgnorePrioritiesAbove 50=ignore priorities above 50 For the rest of the parameters, see http://www.brentozar.com/blitz/documentation for details. @@ -132,9 +133,15 @@ AS ,@CurrentFinding VARCHAR(200) ,@CurrentURL VARCHAR(200) ,@CurrentDetails NVARCHAR(4000) - ,@MSSinceStartup DECIMAL(38,0) - ,@CPUMSsinceStartup DECIMAL(38,0); + ,@MsSinceWaitsCleared DECIMAL(38,0) + ,@CpuMsSinceWaitsCleared DECIMAL(38,0) + ,@ResultText NVARCHAR(MAX) + ,@crlf NVARCHAR(2); + + SET @crlf = NCHAR(13) + NCHAR(10); + SET @ResultText = 'sp_Blitz Results: ' + @crlf; + IF OBJECT_ID('tempdb..#BlitzResults') IS NOT NULL DROP TABLE #BlitzResults; CREATE TABLE #BlitzResults @@ -236,6 +243,8 @@ AS INSERT INTO #SkipChecks (CheckID) VALUES (100); /* Remote DAC disabled */ INSERT INTO #SkipChecks (CheckID) VALUES (123); INSERT INTO #SkipChecks (CheckID) VALUES (177); + INSERT INTO #SkipChecks (CheckID) VALUES (180); /* 180/181 are maintenance plans */ + INSERT INTO #SkipChecks (CheckID) VALUES (181); END /* Amazon RDS skipped checks */ @@ -403,26 +412,101 @@ AS [Text] NVARCHAR(1000) ); + IF OBJECT_ID('tempdb..#IgnorableWaits') IS NOT NULL + DROP TABLE #IgnorableWaits; + CREATE TABLE #IgnorableWaits (wait_type NVARCHAR(60)); + INSERT INTO #IgnorableWaits VALUES ('BROKER_EVENTHANDLER'); + INSERT INTO #IgnorableWaits VALUES ('BROKER_RECEIVE_WAITFOR'); + INSERT INTO #IgnorableWaits VALUES ('BROKER_TASK_STOP'); + INSERT INTO #IgnorableWaits VALUES ('BROKER_TO_FLUSH'); + INSERT INTO #IgnorableWaits VALUES ('BROKER_TRANSMITTER'); + INSERT INTO #IgnorableWaits VALUES ('CHECKPOINT_QUEUE'); + INSERT INTO #IgnorableWaits VALUES ('CLR_AUTO_EVENT'); + INSERT INTO #IgnorableWaits VALUES ('CLR_MANUAL_EVENT'); + INSERT INTO #IgnorableWaits VALUES ('CLR_SEMAPHORE'); + INSERT INTO #IgnorableWaits VALUES ('DBMIRROR_DBM_EVENT'); + INSERT INTO #IgnorableWaits VALUES ('DBMIRROR_DBM_MUTEX'); + INSERT INTO #IgnorableWaits VALUES ('DBMIRROR_EVENTS_QUEUE'); + INSERT INTO #IgnorableWaits VALUES ('DBMIRROR_WORKER_QUEUE'); + INSERT INTO #IgnorableWaits VALUES ('DBMIRRORING_CMD'); + INSERT INTO #IgnorableWaits VALUES ('DIRTY_PAGE_POLL'); + INSERT INTO #IgnorableWaits VALUES ('DISPATCHER_QUEUE_SEMAPHORE'); + INSERT INTO #IgnorableWaits VALUES ('FT_IFTS_SCHEDULER_IDLE_WAIT'); + INSERT INTO #IgnorableWaits VALUES ('FT_IFTSHC_MUTEX'); + INSERT INTO #IgnorableWaits VALUES ('HADR_CLUSAPI_CALL'); + INSERT INTO #IgnorableWaits VALUES ('HADR_FILESTREAM_IOMGR_IOCOMPLETION'); + INSERT INTO #IgnorableWaits VALUES ('HADR_LOGCAPTURE_WAIT'); + INSERT INTO #IgnorableWaits VALUES ('HADR_NOTIFICATION_DEQUEUE'); + INSERT INTO #IgnorableWaits VALUES ('HADR_TIMER_TASK'); + INSERT INTO #IgnorableWaits VALUES ('HADR_WORK_QUEUE'); + INSERT INTO #IgnorableWaits VALUES ('LAZYWRITER_SLEEP'); + INSERT INTO #IgnorableWaits VALUES ('LOGMGR_QUEUE'); + INSERT INTO #IgnorableWaits VALUES ('ONDEMAND_TASK_QUEUE'); + INSERT INTO #IgnorableWaits VALUES ('PREEMPTIVE_HADR_LEASE_MECHANISM'); + INSERT INTO #IgnorableWaits VALUES ('PREEMPTIVE_SP_SERVER_DIAGNOSTICS'); + INSERT INTO #IgnorableWaits VALUES ('QDS_ASYNC_QUEUE'); + INSERT INTO #IgnorableWaits VALUES ('QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP'); + INSERT INTO #IgnorableWaits VALUES ('QDS_PERSIST_TASK_MAIN_LOOP_SLEEP'); + INSERT INTO #IgnorableWaits VALUES ('QDS_SHUTDOWN_QUEUE'); + INSERT INTO #IgnorableWaits VALUES ('REDO_THREAD_PENDING_WORK'); + INSERT INTO #IgnorableWaits VALUES ('REQUEST_FOR_DEADLOCK_SEARCH'); + INSERT INTO #IgnorableWaits VALUES ('SLEEP_SYSTEMTASK'); + INSERT INTO #IgnorableWaits VALUES ('SLEEP_TASK'); + INSERT INTO #IgnorableWaits VALUES ('SP_SERVER_DIAGNOSTICS_SLEEP'); + INSERT INTO #IgnorableWaits VALUES ('SQLTRACE_BUFFER_FLUSH'); + INSERT INTO #IgnorableWaits VALUES ('SQLTRACE_INCREMENTAL_FLUSH_SLEEP'); + INSERT INTO #IgnorableWaits VALUES ('UCS_SESSION_REGISTRATION'); + INSERT INTO #IgnorableWaits VALUES ('WAIT_XTP_OFFLINE_CKPT_NEW_LOG'); + INSERT INTO #IgnorableWaits VALUES ('WAITFOR'); + INSERT INTO #IgnorableWaits VALUES ('XE_DISPATCHER_WAIT'); + INSERT INTO #IgnorableWaits VALUES ('XE_LIVE_TARGET_TVF'); + INSERT INTO #IgnorableWaits VALUES ('XE_TIMER_EVENT'); + + /* Used for the default trace checks. */ DECLARE @TracePath NVARCHAR(256); SELECT @TracePath=CAST(value as NVARCHAR(256)) FROM sys.fn_trace_getinfo(1) WHERE traceid=1 AND property=2; - SELECT @MSSinceStartup = DATEDIFF(MINUTE, create_date, CURRENT_TIMESTAMP) + SELECT @MsSinceWaitsCleared = DATEDIFF(MINUTE, create_date, CURRENT_TIMESTAMP) * 60000 FROM sys.databases WHERE name='tempdb'; - SET @MSSinceStartup = @MSSinceStartup * 60000; + /* Have they cleared wait stats? Using a 10% fudge factor */ + IF @MsSinceWaitsCleared * .9 > (SELECT wait_time_ms FROM sys.dm_os_wait_stats WHERE wait_type = 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP') + BEGIN + SET @MsSinceWaitsCleared = (SELECT wait_time_ms FROM sys.dm_os_wait_stats WHERE wait_type = 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP') + INSERT INTO #BlitzResults + ( CheckID , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + VALUES( 185, + 240, + 'Wait Stats', + 'Wait Stats Have Been Cleared', + 'http://BrentOzar.com/go/waits', + 'Someone ran DBCC SQLPERF to clear sys.dm_os_wait_stats at approximately: ' + CONVERT(NVARCHAR(100), DATEADD(ms, (-1 * @MsSinceWaitsCleared), GETDATE()), 120)) + END - SELECT @CPUMSsinceStartup = @MSSinceStartup * scheduler_count + /* @CpuMsSinceWaitsCleared is used for waits stats calculations */ + SELECT @CpuMsSinceWaitsCleared = @MsSinceWaitsCleared * scheduler_count FROM sys.dm_os_sys_info; - /* If we're outputting CSV, don't bother checking the plan cache because we cannot export plans. */ - IF @OutputType = 'CSV' + /* If we're outputting CSV or Markdown, don't bother checking the plan cache because we cannot export plans. */ + IF @OutputType = 'CSV' OR @OutputType = 'MARKDOWN' SET @CheckProcedureCache = 0; + /* If we're posting a question on Stack, include background info on the server */ + IF @OutputType = 'MARKDOWN' + SET @CheckServerInfo = 1; + + /* Only run CheckUserDatabaseObjects if there are less than 50 databases. */ IF @BringThePain = 0 AND 50 <= (SELECT COUNT(*) FROM sys.databases) AND @CheckUserDatabaseObjects = 1 BEGIN @@ -491,7 +575,7 @@ AS 'Backup' AS FindingsGroup , 'Backups Not Performed Recently' AS Finding , 'http://BrentOzar.com/go/nobak' AS URL , - 'Database ' + d.name + ' last backed up: ' + 'Last backed up: ' + COALESCE(CAST(MAX(b.backup_finish_date) AS VARCHAR(25)),'never') AS Details FROM master.sys.databases d LEFT OUTER JOIN msdb.dbo.backupset b ON d.name COLLATE SQL_Latin1_General_CP1_CI_AS = b.database_name COLLATE SQL_Latin1_General_CP1_CI_AS @@ -641,10 +725,13 @@ AS INNER JOIN msdb.dbo.backupset AS bs ON bmf.media_set_id = bs.media_set_id AND bs.backup_start_date >= ( DATEADD(dd, -14, GETDATE()) ) + /* Filter out databases that were recently restored: */ + LEFT OUTER JOIN msdb.dbo.restorehistory rh ON bs.database_name = rh.destination_database_name AND rh.restore_date > DATEADD(dd, -14, GETDATE()) WHERE UPPER(LEFT(bmf.physical_device_name COLLATE SQL_Latin1_General_CP1_CI_AS, 3)) IN ( SELECT DISTINCT UPPER(LEFT(mf.physical_name COLLATE SQL_Latin1_General_CP1_CI_AS, 3)) FROM sys.master_files AS mf ) + AND rh.destination_database_name IS NULL GROUP BY UPPER(LEFT(bmf.physical_device_name, 3)) END @@ -674,6 +761,7 @@ AS FROM #SkipChecks WHERE DatabaseName IS NULL AND CheckID = 3 ) BEGIN + IF DATEADD(dd, -60, GETDATE()) > (SELECT TOP 1 backup_start_date FROM msdb.dbo.backupset ORDER BY 1) INSERT INTO #BlitzResults ( CheckID , DatabaseName , @@ -693,18 +781,43 @@ AS ( 'Database backup history retained back to ' + CAST(bs.backup_start_date AS VARCHAR(20)) ) AS Details FROM msdb.dbo.backupset bs - WHERE bs.backup_start_date <= DATEADD(dd, -60, - GETDATE()) ORDER BY backup_set_id ASC; END + IF NOT EXISTS ( SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 186 ) + BEGIN + IF DATEADD(dd, -2, GETDATE()) < (SELECT TOP 1 backup_start_date FROM msdb.dbo.backupset ORDER BY 1) + INSERT INTO #BlitzResults + ( CheckID , + DatabaseName , + Priority , + FindingsGroup , + Finding , + URL , + Details + ) + SELECT TOP 1 + 186 AS CheckID , + 'msdb' , + 200 AS Priority , + 'Backup' AS FindingsGroup , + 'MSDB Backup History Purged Too Frequently' AS Finding , + 'http://BrentOzar.com/go/history' AS URL , + ( 'Database backup history only retained back to ' + + CAST(bs.backup_start_date AS VARCHAR(20)) ) AS Details + FROM msdb.dbo.backupset bs + ORDER BY backup_set_id ASC; + END + IF NOT EXISTS ( SELECT 1 FROM #SkipChecks WHERE DatabaseName IS NULL AND CheckID = 178 ) AND EXISTS (SELECT * FROM msdb.dbo.backupset bs WHERE bs.type = 'D' - AND bs.compressed_backup_size >= 50000000000 /* At least 50GB */ + AND bs.backup_size >= 50000000000 /* At least 50GB */ AND DATEDIFF(SECOND, bs.backup_start_date, bs.backup_finish_date) <= 60 /* Backup took less than 60 seconds */ AND bs.backup_finish_date >= DATEADD(DAY, -14, GETDATE()) /* In the last 2 weeks */) BEGIN @@ -724,7 +837,7 @@ AS ( CAST(COUNT(*) AS VARCHAR(20)) + ' snapshot-looking backups have occurred in the last two weeks, indicating that IO may be freezing up.') AS Details FROM msdb.dbo.backupset bs WHERE bs.type = 'D' - AND bs.compressed_backup_size >= 50000000000 /* At least 50GB */ + AND bs.backup_size >= 50000000000 /* At least 50GB */ AND DATEDIFF(SECOND, bs.backup_start_date, bs.backup_finish_date) <= 60 /* Backup took less than 60 seconds */ AND bs.backup_finish_date >= DATEADD(DAY, -14, GETDATE()) /* In the last 2 weeks */ END @@ -3483,6 +3596,7 @@ IF @ProductVersionMajor >= 10 AND @ProductVersionMinor >= 50 IF NOT EXISTS ( SELECT 1 FROM #SkipChecks WHERE DatabaseName IS NULL AND CheckID = 180 ) + AND CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')) LIKE '1%' /* Only run on 2008+ */ BEGIN ; WITH XMLNAMESPACES ('www.microsoft.com/SqlServer/Dts' AS [dts]) @@ -3517,6 +3631,7 @@ IF @ProductVersionMajor >= 10 AND @ProductVersionMinor >= 50 IF NOT EXISTS ( SELECT 1 FROM #SkipChecks WHERE DatabaseName IS NULL AND CheckID = 181 ) + AND CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')) LIKE '1%' /* Only run on 2008+ */ BEGIN ; WITH XMLNAMESPACES ('www.microsoft.com/SqlServer/Dts' AS [dts]) @@ -3557,6 +3672,30 @@ IF @ProductVersionMajor >= 10 AND @ProductVersionMinor >= 50 END + /* Reliability - No Failover Cluster Nodes Available - 184 */ + IF NOT EXISTS ( SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 184 ) + AND CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)) NOT LIKE '10%' + AND CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)) NOT LIKE '9%' + BEGIN + SET @StringToExecute = 'INSERT INTO #BlitzResults (CheckID, Priority, FindingsGroup, Finding, URL, Details) + SELECT TOP 1 + 184 AS CheckID , + 20 AS Priority , + ''Reliability'' AS FindingsGroup , + ''No Failover Cluster Nodes Available'' AS Finding , + ''http://BrentOzar.com/go/node'' AS URL , + ''There are no failover cluster nodes available if the active node fails'' AS Details + FROM ( + SELECT SUM(CASE WHEN [status] = 0 AND [is_current_owner] = 0 THEN 1 ELSE 0 END) AS [available_nodes] + FROM sys.dm_os_cluster_nodes + ) a + WHERE [available_nodes] < 1'; + EXECUTE(@StringToExecute); + END + + IF @CheckUserDatabaseObjects = 1 BEGIN @@ -4119,7 +4258,7 @@ IF @ProductVersionMajor >= 10 AND @ProductVersionMinor >= 50 FROM #SkipChecks WHERE DatabaseName IS NULL AND CheckID = 86 ) BEGIN - EXEC dbo.sp_MSforeachdb 'USE [?]; INSERT INTO #BlitzResults (CheckID, DatabaseName, Priority, FindingsGroup, Finding, URL, Details) SELECT DISTINCT 86, DB_NAME(), 230, ''Security'', ''Elevated Permissions on a Database'', ''http://BrentOzar.com/go/elevated'', (''In ['' + DB_NAME() + ''], user ['' + u.name + ''] has the role ['' + g.name + '']. This user can perform tasks beyond just reading and writing data.'') FROM [?].dbo.sysmembers m inner join [?].dbo.sysusers u on m.memberuid = u.uid inner join sysusers g on m.groupuid = g.uid where u.name <> ''dbo'' and g.name in (''db_owner'' , ''db_accessAdmin'' , ''db_securityadmin'' , ''db_ddladmin'')'; + EXEC dbo.sp_MSforeachdb 'USE [?]; INSERT INTO #BlitzResults (CheckID, DatabaseName, Priority, FindingsGroup, Finding, URL, Details) SELECT DISTINCT 86, DB_NAME(), 230, ''Security'', ''Elevated Permissions on a Database'', ''http://BrentOzar.com/go/elevated'', (''In ['' + DB_NAME() + ''], user ['' + u.name + ''] has the role ['' + g.name + '']. This user can perform tasks beyond just reading and writing data.'') FROM [?].dbo.sysmembers m inner join [?].dbo.sysusers u on m.memberuid = u.uid inner join sysusers g on m.groupuid = g.uid where u.name <> ''dbo'' and g.name in (''db_owner'' , ''db_accessadmin'' , ''db_securityadmin'' , ''db_ddladmin'')'; END @@ -4718,6 +4857,34 @@ IF @ProductVersionMajor >= 10 AND @ProductVersionMinor >= 50 END END /* IF @CheckProcedureCache = 1 */ + + /*Check to see if the HA endpoint account is set at the same as the SQL Server Service Account*/ + IF @ProductVersionMajor >= 10 + AND NOT EXISTS ( SELECT 1 + FROM #SkipChecks + WHERE DatabaseName IS NULL AND CheckID = 187 ) + + IF SERVERPROPERTY('IsHadrEnabled') = 1 + BEGIN + INSERT INTO [#BlitzResults] + ( [CheckID] , + [Priority] , + [FindingsGroup] , + [Finding] , + [URL] , + [Details] ) + SELECT + 187 AS [CheckID] , + 230 AS [Priority] , + 'Security' AS [FindingsGroup] , + 'Endpoints Owned by Users' AS [Finding] , + 'http://BrentOzar.com/go/owners' AS [URL] , + ( 'Endpoint ' + ep.[name] + ' is owned by ' + SUSER_NAME(ep.principal_id) + '. If the endpoint owner login is disabled or not available due to Active Directory problems, the high availability will stop working.' + ) AS [Details] + FROM sys.database_mirroring_endpoints ep + LEFT OUTER JOIN sys.dm_server_services s ON SUSER_NAME(ep.principal_id) = s.service_account + WHERE s.service_account IS NULL; + END /*Check for the last good DBCC CHECKDB date */ IF NOT EXISTS ( SELECT 1 @@ -4756,16 +4923,12 @@ IF @ProductVersionMajor >= 10 AND @ProductVersionMinor >= 50 'Reliability' AS FindingsGroup , 'Last good DBCC CHECKDB over 2 weeks old' AS Finding , 'http://BrentOzar.com/go/checkdb' AS URL , - 'Database [' + DB2.DbName + ']' + 'Last successful CHECKDB: ' + CASE DB2.Value WHEN '1900-01-01 00:00:00.000' - THEN ' never had a successful DBCC CHECKDB.' - ELSE ' last had a successful DBCC CHECKDB run on ' - + DB2.Value + '.' - END - + ' This check should be run regularly to catch any database corruption as soon as possible.' - + ' Note: you can restore a backup of a busy production database to a test server and run DBCC CHECKDB ' - + ' against that to minimize impact. If you do that, you can ignore this warning.' AS Details + THEN ' never.' + ELSE DB2.Value + END AS Details FROM DB2 WHERE DB2.DbName <> 'tempdb' AND DB2.DbName NOT IN ( SELECT DISTINCT @@ -5119,7 +5282,7 @@ IF @ProductVersionMajor >= 10 AND @ProductVersionMinor >= 50 250 AS [Priority] , 'Server Info' AS [FindingsGroup] , 'Windows Version' AS [Finding] , - 'http://BrentOzar.com/go/' AS [URL] , + 'https://en.wikipedia.org/wiki/List_of_Microsoft_Windows_versions' AS [URL] , ( CASE WHEN [owi].[windows_release] = '5' THEN 'You''re running a really old version: Windows 2000, version ' + CAST([owi].[windows_release] AS VARCHAR(5)) WHEN [owi].[windows_release] > '5' AND [owi].[windows_release] < '6' THEN 'You''re running a really old version: Windows Server 2003/2003R2 era, version ' + CAST([owi].[windows_release] AS VARCHAR(5)) @@ -5480,98 +5643,19 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1 FROM #SkipChecks WHERE DatabaseName IS NULL AND CheckID = 152 ) BEGIN - IF EXISTS (SELECT * FROM sys.dm_os_wait_stats WHERE wait_time_ms > .1 * @CPUMSsinceStartup AND waiting_tasks_count > 0 - AND wait_type NOT IN ('REQUEST_FOR_DEADLOCK_SEARCH', - 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', - 'SQLTRACE_BUFFER_FLUSH', - 'LAZYWRITER_SLEEP', - 'XE_TIMER_EVENT', - 'XE_DISPATCHER_WAIT', - 'FT_IFTS_SCHEDULER_IDLE_WAIT', - 'LOGMGR_QUEUE', - 'CHECKPOINT_QUEUE', - 'BROKER_TO_FLUSH', - 'BROKER_TASK_STOP', - 'BROKER_EVENTHANDLER', - 'SLEEP_TASK', - 'WAITFOR', - 'DBMIRROR_DBM_MUTEX', - 'DBMIRROR_EVENTS_QUEUE', - 'DBMIRRORING_CMD', - 'DISPATCHER_QUEUE_SEMAPHORE', - 'BROKER_RECEIVE_WAITFOR', - 'CLR_AUTO_EVENT', - 'DIRTY_PAGE_POLL', - 'HADR_FILESTREAM_IOMGR_IOCOMPLETION', - 'ONDEMAND_TASK_QUEUE', - 'FT_IFTSHC_MUTEX', - 'CLR_MANUAL_EVENT', - 'CLR_SEMAPHORE', - 'DBMIRROR_WORKER_QUEUE', - 'DBMIRROR_DBM_EVENT', - 'SP_SERVER_DIAGNOSTICS_SLEEP', - 'HADR_CLUSAPI_CALL', - 'HADR_LOGCAPTURE_WAIT', - 'HADR_NOTIFICATION_DEQUEUE', - 'HADR_TIMER_TASK', - 'HADR_WORK_QUEUE', - 'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', - 'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', - 'REDO_THREAD_PENDING_WORK', - 'UCS_SESSION_REGISTRATION', - 'BROKER_TRANSMITTER', - 'QDS_ASYNC_QUEUE')) + IF EXISTS (SELECT * FROM sys.dm_os_wait_stats ws + LEFT OUTER JOIN #IgnorableWaits i ON ws.wait_type = i.wait_type + WHERE wait_time_ms > .1 * @CpuMsSinceWaitsCleared AND waiting_tasks_count > 0 + AND i.wait_type IS NULL) BEGIN /* Check for waits that have had more than 10% of the server's wait time */ WITH os(wait_type, waiting_tasks_count, wait_time_ms, max_wait_time_ms, signal_wait_time_ms) AS - (SELECT wait_type, waiting_tasks_count, wait_time_ms, max_wait_time_ms, signal_wait_time_ms - FROM sys.dm_os_wait_stats - WHERE wait_type NOT IN ('REQUEST_FOR_DEADLOCK_SEARCH', - 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', - 'SQLTRACE_BUFFER_FLUSH', - 'LAZYWRITER_SLEEP', - 'XE_TIMER_EVENT', - 'XE_DISPATCHER_WAIT', - 'FT_IFTS_SCHEDULER_IDLE_WAIT', - 'LOGMGR_QUEUE', - 'CHECKPOINT_QUEUE', - 'BROKER_TO_FLUSH', - 'BROKER_TASK_STOP', - 'BROKER_EVENTHANDLER', - 'SLEEP_TASK', - 'WAITFOR', - 'DBMIRROR_DBM_MUTEX', - 'DBMIRROR_EVENTS_QUEUE', - 'DBMIRRORING_CMD', - 'DISPATCHER_QUEUE_SEMAPHORE', - 'BROKER_RECEIVE_WAITFOR', - 'CLR_AUTO_EVENT', - 'DIRTY_PAGE_POLL', - 'HADR_FILESTREAM_IOMGR_IOCOMPLETION', - 'ONDEMAND_TASK_QUEUE', - 'FT_IFTSHC_MUTEX', - 'CLR_MANUAL_EVENT', - 'CLR_SEMAPHORE', - 'DBMIRROR_WORKER_QUEUE', - 'DBMIRROR_DBM_EVENT', - 'SP_SERVER_DIAGNOSTICS_SLEEP', - 'HADR_CLUSAPI_CALL', - 'HADR_LOGCAPTURE_WAIT', - 'HADR_NOTIFICATION_DEQUEUE', - 'HADR_TIMER_TASK', - 'HADR_WORK_QUEUE', - 'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', - 'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', - 'REDO_THREAD_PENDING_WORK', - 'UCS_SESSION_REGISTRATION', - 'BROKER_TRANSMITTER', - 'PREEMPTIVE_SP_SERVER_DIAGNOSTICS', - 'PREEMPTIVE_HADR_LEASE_MECHANISM', - 'SLEEP_SYSTEMTASK', - 'QDS_SHUTDOWN_QUEUE', - 'XE_LIVE_TARGET_TVF') - AND wait_time_ms > .1 * @CPUMSsinceStartup + (SELECT ws.wait_type, waiting_tasks_count, wait_time_ms, max_wait_time_ms, signal_wait_time_ms + FROM sys.dm_os_wait_stats ws + LEFT OUTER JOIN #IgnorableWaits i ON ws.wait_type = i.wait_type + WHERE i.wait_type IS NULL + AND wait_time_ms > .1 * @CpuMsSinceWaitsCleared AND waiting_tasks_count > 0) INSERT INTO #BlitzResults ( CheckID , @@ -5588,7 +5672,7 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1 , CAST(ROW_NUMBER() OVER(ORDER BY os.wait_time_ms DESC) AS NVARCHAR(10)) + N' - ' + os.wait_type AS Finding ,'http://BrentOzar.com/go/waits' AS URL , Details = CAST(CAST(SUM(os.wait_time_ms / 1000.0 / 60 / 60) OVER (PARTITION BY os.wait_type) AS NUMERIC(18,1)) AS NVARCHAR(20)) + N' hours of waits, ' + - CAST(CAST((SUM(60.0 * os.wait_time_ms) OVER (PARTITION BY os.wait_type) ) / @MSSinceStartup AS NUMERIC(18,1)) AS NVARCHAR(20)) + N' minutes average wait time per hour, ' + + CAST(CAST((SUM(60.0 * os.wait_time_ms) OVER (PARTITION BY os.wait_type) ) / @MsSinceWaitsCleared AS NUMERIC(18,1)) AS NVARCHAR(20)) + N' minutes average wait time per hour, ' + /* CAST(CAST( 100.* SUM(os.wait_time_ms) OVER (PARTITION BY os.wait_type) / (1. * SUM(os.wait_time_ms) OVER () ) @@ -5972,6 +6056,27 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1 Finding , Details; END + ELSE IF @OutputType = 'MARKDOWN' + BEGIN + WITH Results AS (SELECT row_number() OVER (ORDER BY Priority, FindingsGroup, Finding, DatabaseName, Details) AS rownum, * + FROM #BlitzResults + WHERE Priority > 0 AND Priority < 255 AND FindingsGroup IS NOT NULL AND Finding IS NOT NULL + AND FindingsGroup <> 'Security' /* Specifically excluding security checks for public exports */) + SELECT + CASE + WHEN r.Priority <> COALESCE(rPrior.Priority, 0) OR r.FindingsGroup <> rPrior.FindingsGroup THEN @crlf + N'**Priority ' + CAST(COALESCE(r.Priority,N'') AS NVARCHAR(5)) + N': ' + COALESCE(r.FindingsGroup,N'') + N'**:' + @crlf + @crlf + ELSE N'' + END + + CASE WHEN r.Finding <> COALESCE(rPrior.Finding,N'') AND r.Finding <> rNext.Finding THEN N'- ' + COALESCE(r.Finding,N'') + N' ' + COALESCE(r.DatabaseName, N'') + N' - ' + COALESCE(r.Details,N'') + @crlf + WHEN r.Finding <> COALESCE(rPrior.Finding,N'') AND r.Finding = rNext.Finding AND r.Details = rNext.Details THEN N'- ' + COALESCE(r.Finding,N'') + N' - ' + COALESCE(r.Details,N'') + @crlf + @crlf + N' * ' + COALESCE(r.DatabaseName, N'') + @crlf + WHEN r.Finding <> COALESCE(rPrior.Finding,N'') AND r.Finding = rNext.Finding THEN N'- ' + COALESCE(r.Finding,N'') + @crlf + CASE WHEN r.DatabaseName IS NULL THEN N'' ELSE N' * ' + COALESCE(r.DatabaseName,N'') END + CASE WHEN r.Details <> rPrior.Details THEN N' - ' + COALESCE(r.Details,N'') + @crlf ELSE '' END + ELSE CASE WHEN r.DatabaseName IS NULL THEN N'' ELSE N' * ' + COALESCE(r.DatabaseName,N'') END + CASE WHEN r.Details <> rPrior.Details THEN N' - ' + COALESCE(r.Details,N'') + @crlf ELSE N'' + @crlf END + END + @crlf + FROM Results r + LEFT OUTER JOIN Results rPrior ON r.rownum = rPrior.rownum + 1 + LEFT OUTER JOIN Results rNext ON r.rownum = rNext.rownum - 1 + ORDER BY r.rownum FOR XML PATH(N''); + END ELSE IF @OutputType <> 'NONE' BEGIN SELECT [Priority] , @@ -5993,7 +6098,7 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1 DROP TABLE #BlitzResults; IF @OutputProcedureCache = 1 - AND @CheckProcedureCache = 1 + AND @CheckProcedureCache = 1 SELECT TOP 20 total_worker_time / execution_count AS AvgCPU , total_worker_time AS TotalCPU , diff --git a/sp_BlitzFirst.sql b/sp_BlitzFirst.sql index ed5be8127..71cd5c4d2 100644 --- a/sp_BlitzFirst.sql +++ b/sp_BlitzFirst.sql @@ -28,7 +28,7 @@ AS BEGIN SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SET @VersionDate = '20160903' +SET @VersionDate = '20161014' IF @Help = 1 PRINT ' sp_BlitzFirst from http://FirstResponderKit.org @@ -54,8 +54,7 @@ Unknown limitations of this version: - None. Like Zombo.com, the only limit is yourself. Changes - for the full list of improvements and fixes in this version, see: -https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/milestone/4?closed=1 - +https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ MIT License @@ -164,277 +163,17 @@ BEGIN END /* IF @AsOf IS NOT NULL AND @OutputDatabaseName IS NOT NULL AND @OutputSchemaName IS NOT NULL AND @OutputTableName IS NOT NULL */ ELSE IF @Question IS NULL /* IF @OutputType = 'SCHEMA' */ BEGIN - - /* Get the major and minor build numbers */ - DECLARE @ProductVersion NVARCHAR(128) - ,@ProductVersionMajor DECIMAL(10,2) - ,@ProductVersionMinor DECIMAL(10,2) - ,@EnhanceFlag BIT = 0 - ,@EnhanceSQL NVARCHAR(MAX) = - N'[query_stats].last_dop, - [query_stats].min_dop, - [query_stats].max_dop, - [query_stats].last_grant_kb, - [query_stats].min_grant_kb, - [query_stats].max_grant_kb, - [query_stats].last_used_grant_kb, - [query_stats].min_used_grant_kb, - [query_stats].max_used_grant_kb, - [query_stats].last_ideal_grant_kb, - [query_stats].min_ideal_grant_kb, - [query_stats].max_ideal_grant_kb, - [query_stats].last_reserved_threads, - [query_stats].min_reserved_threads, - [query_stats].max_reserved_threads, - [query_stats].last_used_threads, - [query_stats].min_used_threads, - [query_stats].max_used_threads,' - - SET @ProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)); - SELECT @ProductVersionMajor = SUBSTRING(@ProductVersion, 1,CHARINDEX('.', @ProductVersion) + 1 ), - @ProductVersionMinor = PARSENAME(CONVERT(VARCHAR(32), @ProductVersion), 2) - - /* What's running right now? This is the first and last result set. */ IF @SinceStartup = 0 AND @Seconds > 0 AND @ExpertMode = 1 BEGIN - IF @ProductVersionMajor > 9 and @ProductVersionMajor < 11 - BEGIN - SET @StringToExecute = N' - SELECT GETDATE() AS [run_date] , - CONVERT(VARCHAR, DATEADD(ms, [r].[total_elapsed_time], 0), 114) AS [elapsed_time] , - [s].[session_id] , - [wt].[wait_info] , - [s].[status] , - ISNULL(SUBSTRING([dest].[text], - ( [query_stats].[statement_start_offset] / 2 ) + 1, - ( ( CASE [query_stats].[statement_end_offset] - WHEN -1 THEN DATALENGTH([dest].[text]) - ELSE [query_stats].[statement_end_offset] - END - [query_stats].[statement_start_offset] ) - / 2 ) + 1), [dest].[text]) AS [query_text] , - [derp].[query_plan] , - [qmg].[query_cost] , - [r].[blocking_session_id] , - [s].[cpu_time] , - [s].[logical_reads] , - [s].[writes] , - [s].[reads] AS [physical_reads] , - [s].[memory_usage] , - [r].[estimated_completion_time] , - [r].[deadlock_priority] , - CASE [s].[transaction_isolation_level] - WHEN 0 THEN ''Unspecified'' - WHEN 1 THEN ''Read Uncommitted'' - WHEN 2 THEN ''Read Committed'' - WHEN 3 THEN ''Repeatable Read'' - WHEN 4 THEN ''Serializable'' - WHEN 5 THEN ''Snapshot'' - ELSE ''WHAT HAVE YOU DONE?'' - END AS [transaction_isolation_level] , - [r].[open_transaction_count] , - [qmg].[dop] AS [degree_of_parallelism] , - [qmg].[request_time] , - COALESCE(CAST([qmg].[grant_time] AS VARCHAR), ''N/A'') AS [grant_time] , - [qmg].[requested_memory_kb] , - [qmg].[granted_memory_kb] AS [grant_memory_kb], - CASE WHEN [qmg].[grant_time] IS NULL THEN ''N/A'' - WHEN [qmg].[requested_memory_kb] < [qmg].[granted_memory_kb] - THEN ''Query Granted Less Than Query Requested'' - ELSE ''Memory Request Granted'' - END AS [is_request_granted] , - [qmg].[required_memory_kb] , - [qmg].[used_memory_kb] , - [qmg].[ideal_memory_kb] , - [qmg].[is_small] , - [qmg].[timeout_sec] , - [qmg].[resource_semaphore_id] , - COALESCE(CAST([qmg].[wait_order] AS VARCHAR), ''N/A'') AS [wait_order] , - COALESCE(CAST([qmg].[wait_time_ms] AS VARCHAR), - ''N/A'') AS [wait_time_ms] , - CASE [qmg].[is_next_candidate] - WHEN 0 THEN ''No'' - WHEN 1 THEN ''Yes'' - ELSE ''N/A'' - END AS ''Next Candidate For Memory Grant'' , - [qrs].[target_memory_kb] , - COALESCE(CAST([qrs].[max_target_memory_kb] AS VARCHAR), - ''Small Query Resource Semaphore'') AS [max_target_memory_kb] , - [qrs].[total_memory_kb] , - [qrs].[available_memory_kb] , - [qrs].[granted_memory_kb] , - [qrs].[used_memory_kb] , - [qrs].[grantee_count] , - [qrs].[waiter_count] , - [qrs].[timeout_error_count] , - COALESCE(CAST([qrs].[forced_grant_count] AS VARCHAR), - ''Small Query Resource Semaphore'') AS [forced_grant_count], - [s].[nt_domain] , - [s].[host_name] , - [s].[login_name] , - [s].[nt_user_name] , - [s].[program_name] , - [s].[client_interface_name] , - [s].[login_time] , - [r].[start_time] - FROM [sys].[dm_exec_sessions] AS [s] - JOIN [sys].[dm_exec_requests] AS [r] - ON [r].[session_id] = [s].[session_id] - LEFT JOIN ( SELECT DISTINCT - [wait].[session_id] , - ( SELECT [waitwait].[wait_type] + N'' ('' - + CAST(SUM([waitwait].[wait_duration_ms]) AS NVARCHAR(128)) - + N'' ms) '' - FROM [sys].[dm_os_waiting_tasks] AS [waitwait] - WHERE [waitwait].[session_id] = [wait].[session_id] - GROUP BY [waitwait].[wait_type] - ORDER BY SUM([waitwait].[wait_duration_ms]) DESC - FOR - XML PATH('''') ) AS [wait_info] - FROM [sys].[dm_os_waiting_tasks] AS [wait] ) AS [wt] - ON [s].[session_id] = [wt].[session_id] - LEFT JOIN [sys].[dm_exec_query_stats] AS [query_stats] - ON [r].[sql_handle] = [query_stats].[sql_handle] - AND [r].[statement_start_offset] = [query_stats].[statement_start_offset] - AND [r].[statement_end_offset] = [query_stats].[statement_end_offset] - LEFT JOIN [sys].[dm_exec_query_memory_grants] [qmg] - ON [r].[session_id] = [qmg].[session_id] - LEFT JOIN [sys].[dm_exec_query_resource_semaphores] [qrs] - ON [qmg].[resource_semaphore_id] = [qrs].[resource_semaphore_id] - AND [qmg].[pool_id] = [qrs].[pool_id] - OUTER APPLY [sys].[dm_exec_sql_text]([r].[sql_handle]) AS [dest] - OUTER APPLY [sys].[dm_exec_query_plan]([r].[plan_handle]) AS [derp] - WHERE [r].[session_id] <> @@SPID - AND [s].[status] <> ''sleeping'' - ORDER BY 2 DESC; - ' - END - IF @ProductVersionMajor >= 11 - BEGIN - SELECT @EnhanceFlag = - CASE WHEN @ProductVersionMajor = 11 AND @ProductVersionMinor >= 6020 THEN 1 - WHEN @ProductVersionMajor = 12 AND @ProductVersionMinor >= 5000 THEN 1 - WHEN @ProductVersionMajor = 13 AND @ProductVersionMinor >= 1601 THEN 1 - ELSE 0 - END - - SELECT @StringToExecute = N' - SELECT GETDATE() AS [run_date] , - CONVERT(VARCHAR, DATEADD(ms, [r].[total_elapsed_time], 0), 114) AS [elapsed_time] , - [s].[session_id] , - [wt].[wait_info] , - [s].[status] , - ISNULL(SUBSTRING([dest].[text], - ( [query_stats].[statement_start_offset] / 2 ) + 1, - ( ( CASE [query_stats].[statement_end_offset] - WHEN -1 THEN DATALENGTH([dest].[text]) - ELSE [query_stats].[statement_end_offset] - END - [query_stats].[statement_start_offset] ) - / 2 ) + 1), [dest].[text]) AS [query_text] , - [derp].[query_plan] , - [qmg].[query_cost] , - [r].[blocking_session_id] , - [s].[cpu_time] , - [s].[logical_reads] , - [s].[writes] , - [s].[reads] AS [physical_reads] , - [s].[memory_usage] , - [r].[estimated_completion_time] , - [r].[deadlock_priority] ,' - + - CASE @EnhanceFlag - WHEN 1 THEN @EnhanceSQL - ELSE N'' END + - N'CASE [s].[transaction_isolation_level] - WHEN 0 THEN ''Unspecified'' - WHEN 1 THEN ''Read Uncommitted'' - WHEN 2 THEN ''Read Committed'' - WHEN 3 THEN ''Repeatable Read'' - WHEN 4 THEN ''Serializable'' - WHEN 5 THEN ''Snapshot'' - ELSE ''WHAT HAVE YOU DONE?'' - END AS [transaction_isolation_level] , - [r].[open_transaction_count] , - [qmg].[dop] AS [degree_of_parallelism] , - [qmg].[request_time] , - COALESCE(CAST([qmg].[grant_time] AS VARCHAR), ''Memory Not Granted'') AS [grant_time] , - [qmg].[requested_memory_kb] , - [qmg].[granted_memory_kb] AS [grant_memory_kb], - CASE WHEN [qmg].[grant_time] IS NULL THEN ''N/A'' - WHEN [qmg].[requested_memory_kb] < [qmg].[granted_memory_kb] - THEN ''Query Granted Less Than Query Requested'' - ELSE ''Memory Request Granted'' - END AS [is_request_granted] , - [qmg].[required_memory_kb] , - [qmg].[used_memory_kb] , - [qmg].[ideal_memory_kb] , - [qmg].[is_small] , - [qmg].[timeout_sec] , - [qmg].[resource_semaphore_id] , - COALESCE(CAST([qmg].[wait_order] AS VARCHAR), ''N/A'') AS [wait_order] , - COALESCE(CAST([qmg].[wait_time_ms] AS VARCHAR), - ''N/A'') AS [wait_time_ms] , - CASE [qmg].[is_next_candidate] - WHEN 0 THEN ''No'' - WHEN 1 THEN ''Yes'' - ELSE ''N/A'' - END AS ''Next Candidate For Memory Grant'' , - [qrs].[target_memory_kb] , - COALESCE(CAST([qrs].[max_target_memory_kb] AS VARCHAR), - ''Small Query Resource Semaphore'') AS [max_target_memory_kb] , - [qrs].[total_memory_kb] , - [qrs].[available_memory_kb] , - [qrs].[granted_memory_kb] , - [qrs].[used_memory_kb] , - [qrs].[grantee_count] , - [qrs].[waiter_count] , - [qrs].[timeout_error_count] , - COALESCE(CAST([qrs].[forced_grant_count] AS VARCHAR), - ''Small Query Resource Semaphore'') AS [forced_grant_count], - [s].[nt_domain] , - [s].[host_name] , - [s].[login_name] , - [s].[nt_user_name] , - [s].[program_name] , - [s].[client_interface_name] , - [s].[login_time] , - [r].[start_time] - FROM [sys].[dm_exec_sessions] AS [s] - JOIN [sys].[dm_exec_requests] AS [r] - ON [r].[session_id] = [s].[session_id] - LEFT JOIN ( SELECT DISTINCT - [wait].[session_id] , - ( SELECT [waitwait].[wait_type] + N'' ('' - + CAST(SUM([waitwait].[wait_duration_ms]) AS NVARCHAR(128)) - + N'' ms) '' - FROM [sys].[dm_os_waiting_tasks] AS [waitwait] - WHERE [waitwait].[session_id] = [wait].[session_id] - GROUP BY [waitwait].[wait_type] - ORDER BY SUM([waitwait].[wait_duration_ms]) DESC - FOR - XML PATH('''') ) AS [wait_info] - FROM [sys].[dm_os_waiting_tasks] AS [wait] ) AS [wt] - ON [s].[session_id] = [wt].[session_id] - LEFT JOIN [sys].[dm_exec_query_stats] AS [query_stats] - ON [r].[sql_handle] = [query_stats].[sql_handle] - AND [r].[statement_start_offset] = [query_stats].[statement_start_offset] - AND [r].[statement_end_offset] = [query_stats].[statement_end_offset] - LEFT JOIN [sys].[dm_exec_query_memory_grants] [qmg] - ON [r].[session_id] = [qmg].[session_id] - LEFT JOIN [sys].[dm_exec_query_resource_semaphores] [qrs] - ON [qmg].[resource_semaphore_id] = [qrs].[resource_semaphore_id] - AND [qmg].[pool_id] = [qrs].[pool_id] - OUTER APPLY [sys].[dm_exec_sql_text]([r].[sql_handle]) AS [dest] - OUTER APPLY [sys].[dm_exec_query_plan]([r].[plan_handle]) AS [derp] - WHERE [r].[session_id] <> @@SPID - AND [s].[status] <> ''sleeping'' - ORDER BY 2 DESC; - ' - - END - - EXEC(@StringToExecute); - + IF OBJECT_ID('dbo.sp_BlitzWho') IS NULL + BEGIN + PRINT N'sp_BlitzWho is not installed in the current database_files. You can get a copy from http://FirstResponderKit.org' + END + ELSE + BEGIN + EXEC [dbo].[sp_BlitzWho] + END END /* IF @SinceStartup = 0 AND @Seconds > 0 AND @ExpertMode = 1 - What's running right now? This is the first and last result set. */ @@ -2661,243 +2400,10 @@ BEGIN /* What's running right now? This is the first and last result set. */ IF @SinceStartup = 0 AND @Seconds > 0 AND @ExpertMode = 1 BEGIN - IF @ProductVersionMajor > 9 and @ProductVersionMajor < 11 - BEGIN - SET @StringToExecute = N' - SELECT GETDATE() AS [run_date] , - CONVERT(VARCHAR, DATEADD(ms, [r].[total_elapsed_time], 0), 114) AS [elapsed_time] , - [s].[session_id] , - [wt].[wait_info] , - [s].[status] , - ISNULL(SUBSTRING([dest].[text], - ( [query_stats].[statement_start_offset] / 2 ) + 1, - ( ( CASE [query_stats].[statement_end_offset] - WHEN -1 THEN DATALENGTH([dest].[text]) - ELSE [query_stats].[statement_end_offset] - END - [query_stats].[statement_start_offset] ) - / 2 ) + 1), [dest].[text]) AS [query_text] , - [derp].[query_plan] , - [qmg].[query_cost] , - [r].[blocking_session_id] , - [s].[cpu_time] , - [s].[logical_reads] , - [s].[writes] , - [s].[reads] AS [physical_reads] , - [s].[memory_usage] , - [r].[estimated_completion_time] , - [r].[deadlock_priority] , - CASE [s].[transaction_isolation_level] - WHEN 0 THEN ''Unspecified'' - WHEN 1 THEN ''Read Uncommitted'' - WHEN 2 THEN ''Read Committed'' - WHEN 3 THEN ''Repeatable Read'' - WHEN 4 THEN ''Serializable'' - WHEN 5 THEN ''Snapshot'' - ELSE ''WHAT HAVE YOU DONE?'' - END AS [transaction_isolation_level] , - [r].[open_transaction_count] , - [qmg].[dop] AS [degree_of_parallelism] , - [qmg].[request_time] , - COALESCE(CAST([qmg].[grant_time] AS VARCHAR), ''N/A'') AS [grant_time] , - [qmg].[requested_memory_kb] , - [qmg].[granted_memory_kb] AS [grant_memory_kb], - CASE WHEN [qmg].[grant_time] IS NULL THEN ''N/A'' - WHEN [qmg].[requested_memory_kb] < [qmg].[granted_memory_kb] - THEN ''Query Granted Less Than Query Requested'' - ELSE ''Memory Request Granted'' - END AS [is_request_granted] , - [qmg].[required_memory_kb] , - [qmg].[used_memory_kb] , - [qmg].[ideal_memory_kb] , - [qmg].[is_small] , - [qmg].[timeout_sec] , - [qmg].[resource_semaphore_id] , - COALESCE(CAST([qmg].[wait_order] AS VARCHAR), ''N/A'') AS [wait_order] , - COALESCE(CAST([qmg].[wait_time_ms] AS VARCHAR), - ''N/A'') AS [wait_time_ms] , - CASE [qmg].[is_next_candidate] - WHEN 0 THEN ''No'' - WHEN 1 THEN ''Yes'' - ELSE ''N/A'' - END AS ''Next Candidate For Memory Grant'' , - [qrs].[target_memory_kb] , - COALESCE(CAST([qrs].[max_target_memory_kb] AS VARCHAR), - ''Small Query Resource Semaphore'') AS [max_target_memory_kb] , - [qrs].[total_memory_kb] , - [qrs].[available_memory_kb] , - [qrs].[granted_memory_kb] , - [qrs].[used_memory_kb] , - [qrs].[grantee_count] , - [qrs].[waiter_count] , - [qrs].[timeout_error_count] , - COALESCE(CAST([qrs].[forced_grant_count] AS VARCHAR), - ''Small Query Resource Semaphore'') AS [forced_grant_count], - [s].[nt_domain] , - [s].[host_name] , - [s].[login_name] , - [s].[nt_user_name] , - [s].[program_name] , - [s].[client_interface_name] , - [s].[login_time] , - [r].[start_time] - FROM [sys].[dm_exec_sessions] AS [s] - JOIN [sys].[dm_exec_requests] AS [r] - ON [r].[session_id] = [s].[session_id] - LEFT JOIN ( SELECT DISTINCT - [wait].[session_id] , - ( SELECT [waitwait].[wait_type] + N'' ('' - + CAST(SUM([waitwait].[wait_duration_ms]) AS NVARCHAR(128)) - + N'' ms) '' - FROM [sys].[dm_os_waiting_tasks] AS [waitwait] - WHERE [waitwait].[session_id] = [wait].[session_id] - GROUP BY [waitwait].[wait_type] - ORDER BY SUM([waitwait].[wait_duration_ms]) DESC - FOR - XML PATH('''') ) AS [wait_info] - FROM [sys].[dm_os_waiting_tasks] AS [wait] ) AS [wt] - ON [s].[session_id] = [wt].[session_id] - LEFT JOIN [sys].[dm_exec_query_stats] AS [query_stats] - ON [r].[sql_handle] = [query_stats].[sql_handle] - AND [r].[statement_start_offset] = [query_stats].[statement_start_offset] - AND [r].[statement_end_offset] = [query_stats].[statement_end_offset] - LEFT OUTER JOIN [sys].[dm_exec_query_memory_grants] [qmg] - ON [r].[session_id] = [qmg].[session_id] - LEFT OUTER JOIN [sys].[dm_exec_query_resource_semaphores] [qrs] - ON [qmg].[resource_semaphore_id] = [qrs].[resource_semaphore_id] - AND [qmg].[pool_id] = [qrs].[pool_id] - OUTER APPLY [sys].[dm_exec_sql_text]([r].[sql_handle]) AS [dest] - OUTER APPLY [sys].[dm_exec_query_plan]([r].[plan_handle]) AS [derp] - WHERE [r].[session_id] <> @@SPID - AND [s].[status] <> ''sleeping'' - ORDER BY 2 DESC; - ' - END - IF @ProductVersionMajor >= 11 - BEGIN - SELECT @EnhanceFlag = - CASE WHEN @ProductVersionMajor = 11 AND @ProductVersionMinor >= 6020 THEN 1 - WHEN @ProductVersionMajor = 12 AND @ProductVersionMinor >= 5000 THEN 1 - WHEN @ProductVersionMajor = 13 AND @ProductVersionMinor >= 1708 THEN 1 - ELSE 0 - END - - SELECT @StringToExecute = N' - SELECT GETDATE() AS [run_date] , - CONVERT(VARCHAR, DATEADD(ms, [r].[total_elapsed_time], 0), 114) AS [elapsed_time] , - [s].[session_id] , - [wt].[wait_info] , - [s].[status] , - ISNULL(SUBSTRING([dest].[text], - ( [query_stats].[statement_start_offset] / 2 ) + 1, - ( ( CASE [query_stats].[statement_end_offset] - WHEN -1 THEN DATALENGTH([dest].[text]) - ELSE [query_stats].[statement_end_offset] - END - [query_stats].[statement_start_offset] ) - / 2 ) + 1), [dest].[text]) AS [query_text] , - [derp].[query_plan] , - [qmg].[query_cost] , - [r].[blocking_session_id] , - [s].[cpu_time] , - [s].[logical_reads] , - [s].[writes] , - [s].[reads] AS [physical_reads] , - [s].[memory_usage] , - [r].[estimated_completion_time] , - [r].[deadlock_priority] ,' - + - CASE @EnhanceFlag - WHEN 1 THEN @EnhanceSQL - ELSE N'' END + - N'CASE [s].[transaction_isolation_level] - WHEN 0 THEN ''Unspecified'' - WHEN 1 THEN ''Read Uncommitted'' - WHEN 2 THEN ''Read Committed'' - WHEN 3 THEN ''Repeatable Read'' - WHEN 4 THEN ''Serializable'' - WHEN 5 THEN ''Snapshot'' - ELSE ''WHAT HAVE YOU DONE?'' - END AS [transaction_isolation_level] , - [r].[open_transaction_count] , - [qmg].[dop] AS [degree_of_parallelism] , - [qmg].[request_time] , - COALESCE(CAST([qmg].[grant_time] AS VARCHAR), ''Memory Not Granted'') AS [grant_time] , - [qmg].[requested_memory_kb] , - [qmg].[granted_memory_kb] AS [grant_memory_kb], - CASE WHEN [qmg].[grant_time] IS NULL THEN ''N/A'' - WHEN [qmg].[requested_memory_kb] < [qmg].[granted_memory_kb] - THEN ''Query Granted Less Than Query Requested'' - ELSE ''Memory Request Granted'' - END AS [is_request_granted] , - [qmg].[required_memory_kb] , - [qmg].[used_memory_kb] , - [qmg].[ideal_memory_kb] , - [qmg].[is_small] , - [qmg].[timeout_sec] , - [qmg].[resource_semaphore_id] , - COALESCE(CAST([qmg].[wait_order] AS VARCHAR), ''N/A'') AS [wait_order] , - COALESCE(CAST([qmg].[wait_time_ms] AS VARCHAR), - ''N/A'') AS [wait_time_ms] , - CASE [qmg].[is_next_candidate] - WHEN 0 THEN ''No'' - WHEN 1 THEN ''Yes'' - ELSE ''N/A'' - END AS ''Next Candidate For Memory Grant'' , - [qrs].[target_memory_kb] , - COALESCE(CAST([qrs].[max_target_memory_kb] AS VARCHAR), - ''Small Query Resource Semaphore'') AS [max_target_memory_kb] , - [qrs].[total_memory_kb] , - [qrs].[available_memory_kb] , - [qrs].[granted_memory_kb] , - [qrs].[used_memory_kb] , - [qrs].[grantee_count] , - [qrs].[waiter_count] , - [qrs].[timeout_error_count] , - COALESCE(CAST([qrs].[forced_grant_count] AS VARCHAR), - ''Small Query Resource Semaphore'') AS [forced_grant_count], - [s].[nt_domain] , - [s].[host_name] , - [s].[login_name] , - [s].[nt_user_name] , - [s].[program_name] , - [s].[client_interface_name] , - [s].[login_time] , - [r].[start_time] - FROM [sys].[dm_exec_sessions] AS [s] - JOIN [sys].[dm_exec_requests] AS [r] - ON [r].[session_id] = [s].[session_id] - LEFT JOIN ( SELECT DISTINCT - [wait].[session_id] , - ( SELECT [waitwait].[wait_type] + N'' ('' - + CAST(SUM([waitwait].[wait_duration_ms]) AS NVARCHAR(128)) - + N'' ms) '' - FROM [sys].[dm_os_waiting_tasks] AS [waitwait] - WHERE [waitwait].[session_id] = [wait].[session_id] - GROUP BY [waitwait].[wait_type] - ORDER BY SUM([waitwait].[wait_duration_ms]) DESC - FOR - XML PATH('''') ) AS [wait_info] - FROM [sys].[dm_os_waiting_tasks] AS [wait] ) AS [wt] - ON [s].[session_id] = [wt].[session_id] - LEFT JOIN [sys].[dm_exec_query_stats] AS [query_stats] - ON [r].[sql_handle] = [query_stats].[sql_handle] - AND [r].[statement_start_offset] = [query_stats].[statement_start_offset] - AND [r].[statement_end_offset] = [query_stats].[statement_end_offset] - LEFT OUTER JOIN [sys].[dm_exec_query_memory_grants] [qmg] - ON [r].[session_id] = [qmg].[session_id] - LEFT OUTER JOIN [sys].[dm_exec_query_resource_semaphores] [qrs] - ON [qmg].[resource_semaphore_id] = [qrs].[resource_semaphore_id] - AND [qmg].[pool_id] = [qrs].[pool_id] - OUTER APPLY [sys].[dm_exec_sql_text]([r].[sql_handle]) AS [dest] - OUTER APPLY [sys].[dm_exec_query_plan]([r].[plan_handle]) AS [derp] - WHERE [r].[session_id] <> @@SPID - AND [s].[status] <> ''sleeping'' - ORDER BY 2 DESC; - ' - - END - - EXEC(@StringToExecute); - + IF OBJECT_ID('dbo.sp_BlitzWho') IS NOT NULL + BEGIN + EXEC [dbo].[sp_BlitzWho] + END END /* IF @SinceStartup = 0 AND @Seconds > 0 AND @ExpertMode = 1 - What's running right now? This is the first and last result set. */ END /* IF @Question IS NULL */ @@ -2957,4 +2463,4 @@ EXEC sp_BlitzFirst @Seconds = 60 , @OutputTableNameFileStats = 'BlitzFirstResults_FileStats' , @OutputTableNamePerfmonStats = 'BlitzFirstResults_PerfmonStats' , @OutputTableNameWaitStats = 'BlitzFirstResults_WaitStats' -*/ +*/ \ No newline at end of file diff --git a/sp_BlitzIndex.sql b/sp_BlitzIndex.sql index 3fea151e8..88247bd4a 100644 --- a/sp_BlitzIndex.sql +++ b/sp_BlitzIndex.sql @@ -34,8 +34,8 @@ AS SET NOCOUNT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; DECLARE @Version VARCHAR(30); -SET @Version = '4.2'; -SET @VersionDate = '20160903'; +SET @Version = '4.3'; +SET @VersionDate = '20161014'; IF @Help = 1 PRINT ' /* sp_BlitzIndex from http://FirstResponderKit.org @@ -146,6 +146,12 @@ IF OBJECT_ID('tempdb..#IndexCreateTsql') IS NOT NULL IF OBJECT_ID('tempdb..#DatabaseList') IS NOT NULL DROP TABLE #DatabaseList; +IF OBJECT_ID('tempdb..#Statistics') IS NOT NULL + DROP TABLE #Statistics; + +IF OBJECT_ID('tempdb..#PartitionCompressionInfo') IS NOT NULL + DROP TABLE #PartitionCompressionInfo; + RAISERROR (N'Create temp tables.',0,1) WITH NOWAIT; CREATE TABLE #BlitzIndexResults ( @@ -209,8 +215,63 @@ IF OBJECT_ID('tempdb..#DatabaseList') IS NOT NULL secret_columns NVARCHAR(MAX) NULL, count_secret_columns INT NULL, create_date DATETIME NOT NULL, - modify_date DATETIME NOT NULL - ); + modify_date DATETIME NOT NULL, + [db_schema_object_name] AS [schema_name] + '.' + [object_name] , + [db_schema_object_indexid] AS [schema_name] + '.' + [object_name] + + CASE WHEN [index_name] IS NOT NULL THEN '.' + index_name + ELSE '' + END + ' (' + CAST(index_id AS NVARCHAR(20)) + ')' , + first_key_column_name AS CASE WHEN count_key_columns > 1 + THEN LEFT(key_column_names, CHARINDEX(',', key_column_names, 0) - 1) + ELSE key_column_names + END , + index_definition AS + CASE WHEN partition_key_column_name IS NOT NULL + THEN N'[PARTITIONED BY:' + partition_key_column_name + N']' + ELSE '' + END + + CASE index_id + WHEN 0 THEN N'[HEAP] ' + WHEN 1 THEN N'[CX] ' + ELSE N'' END + CASE WHEN is_indexed_view = 1 THEN '[VIEW] ' + ELSE N'' END + CASE WHEN is_primary_key = 1 THEN N'[PK] ' + ELSE N'' END + CASE WHEN is_XML = 1 THEN N'[XML] ' + ELSE N'' END + CASE WHEN is_spatial = 1 THEN N'[SPATIAL] ' + ELSE N'' END + CASE WHEN is_NC_columnstore = 1 THEN N'[COLUMNSTORE] ' + ELSE N'' END + CASE WHEN is_disabled = 1 THEN N'[DISABLED] ' + ELSE N'' END + CASE WHEN is_hypothetical = 1 THEN N'[HYPOTHETICAL] ' + ELSE N'' END + CASE WHEN is_unique = 1 AND is_primary_key = 0 THEN N'[UNIQUE] ' + ELSE N'' END + CASE WHEN count_key_columns > 0 THEN + N'[' + CAST(count_key_columns AS VARCHAR(10)) + N' KEY' + + CASE WHEN count_key_columns > 1 THEN N'S' ELSE N'' END + + N'] ' + LTRIM(key_column_names_with_sort_order) + ELSE N'' END + CASE WHEN count_included_columns > 0 THEN + N' [' + CAST(count_included_columns AS VARCHAR(10)) + N' INCLUDE' + + + CASE WHEN count_included_columns > 1 THEN N'S' ELSE N'' END + + N'] ' + include_column_names + ELSE N'' END + CASE WHEN filter_definition <> N'' THEN N' [FILTER] ' + filter_definition + ELSE N'' END , + [total_reads] AS user_seeks + user_scans + user_lookups, + [reads_per_write] AS CAST(CASE WHEN user_updates > 0 + THEN ( user_seeks + user_scans + user_lookups ) / (1.0 * user_updates) + ELSE 0 END AS MONEY) , + [index_usage_summary] AS N'Reads: ' + + REPLACE(CONVERT(NVARCHAR(30),CAST((user_seeks + user_scans + user_lookups) AS MONEY), 1), '.00', '') + + CASE WHEN user_seeks + user_scans + user_lookups > 0 THEN + N' (' + + RTRIM( + CASE WHEN user_seeks > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_seeks) AS MONEY), 1), '.00', '') + N' seek ' ELSE N'' END + + CASE WHEN user_scans > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_scans) AS MONEY), 1), '.00', '') + N' scan ' ELSE N'' END + + CASE WHEN user_lookups > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_lookups) AS MONEY), 1), '.00', '') + N' lookup' ELSE N'' END + ) + + N') ' + ELSE N' ' END + + N'Writes:' + + REPLACE(CONVERT(NVARCHAR(30),CAST(user_updates AS MONEY), 1), '.00', ''), + [more_info] AS N'EXEC dbo.sp_BlitzIndex @DatabaseName=' + QUOTENAME([database_name],'''') + + N', @SchemaName=' + QUOTENAME([schema_name],'''') + N', @TableName=' + QUOTENAME([object_name],'''') + N';' + ); + CREATE TABLE #IndexPartitionSanity ( @@ -270,7 +331,85 @@ IF OBJECT_ID('tempdb..#DatabaseList') IS NOT NULL avg_page_lock_wait_in_ms BIGINT NULL , total_index_lock_promotion_attempt_count BIGINT NULL , total_index_lock_promotion_count BIGINT NULL , - data_compression_desc VARCHAR(8000) NULL + data_compression_desc VARCHAR(8000) NULL, + index_size_summary AS ISNULL( + CASE WHEN partition_count > 1 + THEN N'[' + CAST(partition_count AS NVARCHAR(10)) + N' PARTITIONS] ' + ELSE N'' + END + REPLACE(CONVERT(NVARCHAR(30),CAST([total_rows] AS MONEY), 1), N'.00', N'') + N' rows; ' + + CASE WHEN total_reserved_MB > 1024 THEN + CAST(CAST(total_reserved_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB' + ELSE + CAST(CAST(total_reserved_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB' + END + + CASE WHEN total_reserved_LOB_MB > 1024 THEN + N'; ' + CAST(CAST(total_reserved_LOB_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB LOB' + WHEN total_reserved_LOB_MB > 0 THEN + N'; ' + CAST(CAST(total_reserved_LOB_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB LOB' + ELSE '' + END + + CASE WHEN total_reserved_row_overflow_MB > 1024 THEN + N'; ' + CAST(CAST(total_reserved_row_overflow_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB Row Overflow' + WHEN total_reserved_row_overflow_MB > 0 THEN + N'; ' + CAST(CAST(total_reserved_row_overflow_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB Row Overflow' + ELSE '' + END , + N'Error- NULL in computed column'), + index_op_stats AS ISNULL( + ( + REPLACE(CONVERT(NVARCHAR(30),CAST(total_singleton_lookup_count AS MONEY), 1),N'.00',N'') + N' singleton lookups; ' + + REPLACE(CONVERT(NVARCHAR(30),CAST(total_range_scan_count AS MONEY), 1),N'.00',N'') + N' scans/seeks; ' + + REPLACE(CONVERT(NVARCHAR(30),CAST(total_leaf_delete_count AS MONEY), 1),N'.00',N'') + N' deletes; ' + + REPLACE(CONVERT(NVARCHAR(30),CAST(total_leaf_update_count AS MONEY), 1),N'.00',N'') + N' updates; ' + + CASE WHEN ISNULL(total_forwarded_fetch_count,0) >0 THEN + REPLACE(CONVERT(NVARCHAR(30),CAST(total_forwarded_fetch_count AS MONEY), 1),N'.00',N'') + N' forward records fetched; ' + ELSE N'' END + + /* rows will only be in this dmv when data is in memory for the table */ + ), N'Table metadata not in memory'), + index_lock_wait_summary AS ISNULL( + CASE WHEN total_row_lock_wait_count = 0 AND total_page_lock_wait_count = 0 AND + total_index_lock_promotion_attempt_count = 0 THEN N'0 lock waits.' + ELSE + CASE WHEN total_row_lock_wait_count > 0 THEN + N'Row lock waits: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_row_lock_wait_count AS MONEY), 1), N'.00', N'') + + N'; total duration: ' + + CASE WHEN total_row_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/ + REPLACE(CONVERT(NVARCHAR(30),CAST((total_row_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; ' + ELSE + REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_row_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; ' + END + + N'avg duration: ' + + CASE WHEN avg_row_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/ + REPLACE(CONVERT(NVARCHAR(30),CAST((avg_row_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; ' + ELSE + REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(avg_row_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; ' + END + ELSE N'' + END + + CASE WHEN total_page_lock_wait_count > 0 THEN + N'Page lock waits: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_page_lock_wait_count AS MONEY), 1), N'.00', N'') + + N'; total duration: ' + + CASE WHEN total_page_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/ + REPLACE(CONVERT(NVARCHAR(30),CAST((total_page_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; ' + ELSE + REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_page_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; ' + END + + N'avg duration: ' + + CASE WHEN avg_page_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/ + REPLACE(CONVERT(NVARCHAR(30),CAST((avg_page_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; ' + ELSE + REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(avg_page_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; ' + END + ELSE N'' + END + + CASE WHEN total_index_lock_promotion_attempt_count > 0 THEN + N'Lock escalation attempts: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_index_lock_promotion_attempt_count AS MONEY), 1), N'.00', N'') + + N'; Actual Escalations: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_index_lock_promotion_count,0) AS MONEY), 1), N'.00', N'') + N'.' + ELSE N'' + END + END + ,'Error- NULL in computed column') ); CREATE TABLE #IndexColumns @@ -314,7 +453,41 @@ IF OBJECT_ID('tempdb..#DatabaseList') IS NOT NULL unique_compiles BIGINT NULL, equality_columns NVARCHAR(4000), inequality_columns NVARCHAR(4000), - included_columns NVARCHAR(4000) + included_columns NVARCHAR(4000), + [index_estimated_impact] AS + REPLACE(CONVERT(NVARCHAR(256),CAST(CAST( + (user_seeks + user_scans) + AS BIGINT) AS MONEY), 1), '.00', '') + N' use' + + CASE WHEN (user_seeks + user_scans) > 1 THEN N's' ELSE N'' END + +N'; Impact: ' + CAST(avg_user_impact AS NVARCHAR(30)) + + N'%; Avg query cost: ' + + CAST(avg_total_user_cost AS NVARCHAR(30)), + [missing_index_details] AS + CASE WHEN equality_columns IS NOT NULL THEN N'EQUALITY: ' + equality_columns + N' ' + ELSE N'' + END + CASE WHEN inequality_columns IS NOT NULL THEN N'INEQUALITY: ' + inequality_columns + N' ' + ELSE N'' + END + CASE WHEN included_columns IS NOT NULL THEN N'INCLUDES: ' + included_columns + N' ' + ELSE N'' + END, + [create_tsql] AS N'CREATE INDEX [ix_' + table_name + N'_' + + REPLACE(REPLACE(REPLACE(REPLACE( + ISNULL(equality_columns,N'')+ + CASE WHEN equality_columns IS NOT NULL AND inequality_columns IS NOT NULL THEN N'_' ELSE N'' END + + ISNULL(inequality_columns,''),',','') + ,'[',''),']',''),' ','_') + + CASE WHEN included_columns IS NOT NULL THEN N'_includes' ELSE N'' END + N'] ON ' + + [statement] + N' (' + ISNULL(equality_columns,N'') + + CASE WHEN equality_columns IS NOT NULL AND inequality_columns IS NOT NULL THEN N', ' ELSE N'' END + + CASE WHEN inequality_columns IS NOT NULL THEN inequality_columns ELSE N'' END + + ') ' + CASE WHEN included_columns IS NOT NULL THEN N' INCLUDE (' + included_columns + N')' ELSE N'' END + + N' WITH (' + + N'FILLFACTOR=100, ONLINE=?, SORT_IN_TEMPDB=?' + + N')' + + N';' + , + [more_info] AS N'EXEC dbo.sp_BlitzIndex @DatabaseName=' + QUOTENAME([database_name],'''') + + N', @SchemaName=' + QUOTENAME([schema_name],'''') + N', @TableName=' + QUOTENAME([table_name],'''') + N';' ); CREATE TABLE #ForeignKeys ( @@ -342,6 +515,32 @@ IF OBJECT_ID('tempdb..#DatabaseList') IS NOT NULL DatabaseName NVARCHAR(256) ) + CREATE TABLE #PartitionCompressionInfo ( + [index_sanity_id] INT NULL, + [partition_compression_detail] VARCHAR(8000) NULL + ) + + CREATE TABLE #Statistics ( + database_name NVARCHAR(256) NOT NULL, + table_name NVARCHAR(128) NULL, + index_name sysname NOT NULL, + column_name sysname NOT NULL, + statistics_name NVARCHAR(128) NOT NULL, + last_statistics_update DATETIME NULL, + days_since_last_stats_update INT NULL, + rows BIGINT NULL, + rows_sampled BIGINT NULL, + percent_sampled DECIMAL(18, 1) NULL, + histogram_steps INT NULL, + modification_counter BIGINT NULL, + percent_modifications DECIMAL(18, 1) NULL, + modifications_before_auto_update INT NULL, + index_type_desc NVARCHAR(128) NOT NULL, + table_create_date DATETIME NULL, + table_modify_date DATETIME NULL + ); + + IF @GetAllDatabases = 1 BEGIN INSERT INTO #DatabaseList (DatabaseName) @@ -1099,64 +1298,6 @@ BEGIN TRY s.object_id=fk.referenced_object_id AND LEFT(s.key_column_names,LEN(fk.referenced_fk_columns)) = fk.referenced_fk_columns - RAISERROR (N'Add computed columns to #IndexSanity to simplify queries.',0,1) WITH NOWAIT; - IF NOT EXISTS(SELECT 1 FROM tempdb.sys.columns WHERE name='db_schema_object_name') - ALTER TABLE #IndexSanity ADD - [db_schema_object_name] AS [schema_name] + '.' + [object_name] , - [db_schema_object_indexid] AS [schema_name] + '.' + [object_name] - + CASE WHEN [index_name] IS NOT NULL THEN '.' + index_name - ELSE '' - END + ' (' + CAST(index_id AS NVARCHAR(20)) + ')' , - first_key_column_name AS CASE WHEN count_key_columns > 1 - THEN LEFT(key_column_names, CHARINDEX(',', key_column_names, 0) - 1) - ELSE key_column_names - END , - index_definition AS - CASE WHEN partition_key_column_name IS NOT NULL - THEN N'[PARTITIONED BY:' + partition_key_column_name + N']' - ELSE '' - END + - CASE index_id - WHEN 0 THEN N'[HEAP] ' - WHEN 1 THEN N'[CX] ' - ELSE N'' END + CASE WHEN is_indexed_view = 1 THEN '[VIEW] ' - ELSE N'' END + CASE WHEN is_primary_key = 1 THEN N'[PK] ' - ELSE N'' END + CASE WHEN is_XML = 1 THEN N'[XML] ' - ELSE N'' END + CASE WHEN is_spatial = 1 THEN N'[SPATIAL] ' - ELSE N'' END + CASE WHEN is_NC_columnstore = 1 THEN N'[COLUMNSTORE] ' - ELSE N'' END + CASE WHEN is_disabled = 1 THEN N'[DISABLED] ' - ELSE N'' END + CASE WHEN is_hypothetical = 1 THEN N'[HYPOTHETICAL] ' - ELSE N'' END + CASE WHEN is_unique = 1 AND is_primary_key = 0 THEN N'[UNIQUE] ' - ELSE N'' END + CASE WHEN count_key_columns > 0 THEN - N'[' + CAST(count_key_columns AS VARCHAR(10)) + N' KEY' - + CASE WHEN count_key_columns > 1 THEN N'S' ELSE N'' END - + N'] ' + LTRIM(key_column_names_with_sort_order) - ELSE N'' END + CASE WHEN count_included_columns > 0 THEN - N' [' + CAST(count_included_columns AS VARCHAR(10)) + N' INCLUDE' + - + CASE WHEN count_included_columns > 1 THEN N'S' ELSE N'' END - + N'] ' + include_column_names - ELSE N'' END + CASE WHEN filter_definition <> N'' THEN N' [FILTER] ' + filter_definition - ELSE N'' END , - [total_reads] AS user_seeks + user_scans + user_lookups, - [reads_per_write] AS CAST(CASE WHEN user_updates > 0 - THEN ( user_seeks + user_scans + user_lookups ) / (1.0 * user_updates) - ELSE 0 END AS MONEY) , - [index_usage_summary] AS N'Reads: ' + - REPLACE(CONVERT(NVARCHAR(30),CAST((user_seeks + user_scans + user_lookups) AS MONEY), 1), '.00', '') - + CASE WHEN user_seeks + user_scans + user_lookups > 0 THEN - N' (' - + RTRIM( - CASE WHEN user_seeks > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_seeks) AS MONEY), 1), '.00', '') + N' seek ' ELSE N'' END - + CASE WHEN user_scans > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_scans) AS MONEY), 1), '.00', '') + N' scan ' ELSE N'' END - + CASE WHEN user_lookups > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_lookups) AS MONEY), 1), '.00', '') + N' lookup' ELSE N'' END - ) - + N') ' - ELSE N' ' END - + N'Writes:' + - REPLACE(CONVERT(NVARCHAR(30),CAST(user_updates AS MONEY), 1), '.00', ''), - [more_info] AS N'EXEC dbo.sp_BlitzIndex @DatabaseName=' + QUOTENAME([database_name],'''') + - N', @SchemaName=' + QUOTENAME([schema_name],'''') + N', @TableName=' + QUOTENAME([object_name],'''') + N';' - RAISERROR (N'Update index_secret on #IndexSanity for NC indexes.',0,1) WITH NOWAIT; UPDATE nc SET secret_columns= @@ -1186,132 +1327,6 @@ BEGIN TRY WHERE tb.index_id = 0 /*Heaps-- these have the RID */ OR (tb.index_id=1 AND tb.is_unique=0); /* Non-unique CX: has uniquifer (when needed) */ - RAISERROR (N'Add computed columns to #IndexSanitySize to simplify queries.',0,1) WITH NOWAIT; - - IF NOT EXISTS(SELECT 1 FROM tempdb.sys.columns AS sc - JOIN tempdb..sysobjects AS so ON so.id = sc.object_id - WHERE sc.name='index_size_summary' AND so.name LIKE '#IndexSanitySize_%') - ALTER TABLE #IndexSanitySize ADD - index_size_summary AS ISNULL( - CASE WHEN partition_count > 1 - THEN N'[' + CAST(partition_count AS NVARCHAR(10)) + N' PARTITIONS] ' - ELSE N'' - END + REPLACE(CONVERT(NVARCHAR(30),CAST([total_rows] AS MONEY), 1), N'.00', N'') + N' rows; ' - + CASE WHEN total_reserved_MB > 1024 THEN - CAST(CAST(total_reserved_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB' - ELSE - CAST(CAST(total_reserved_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB' - END - + CASE WHEN total_reserved_LOB_MB > 1024 THEN - N'; ' + CAST(CAST(total_reserved_LOB_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB LOB' - WHEN total_reserved_LOB_MB > 0 THEN - N'; ' + CAST(CAST(total_reserved_LOB_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB LOB' - ELSE '' - END - + CASE WHEN total_reserved_row_overflow_MB > 1024 THEN - N'; ' + CAST(CAST(total_reserved_row_overflow_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB Row Overflow' - WHEN total_reserved_row_overflow_MB > 0 THEN - N'; ' + CAST(CAST(total_reserved_row_overflow_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB Row Overflow' - ELSE '' - END , - N'Error- NULL in computed column'), - index_op_stats AS ISNULL( - ( - REPLACE(CONVERT(NVARCHAR(30),CAST(total_singleton_lookup_count AS MONEY), 1),N'.00',N'') + N' singleton lookups; ' - + REPLACE(CONVERT(NVARCHAR(30),CAST(total_range_scan_count AS MONEY), 1),N'.00',N'') + N' scans/seeks; ' - + REPLACE(CONVERT(NVARCHAR(30),CAST(total_leaf_delete_count AS MONEY), 1),N'.00',N'') + N' deletes; ' - + REPLACE(CONVERT(NVARCHAR(30),CAST(total_leaf_update_count AS MONEY), 1),N'.00',N'') + N' updates; ' - + CASE WHEN ISNULL(total_forwarded_fetch_count,0) >0 THEN - REPLACE(CONVERT(NVARCHAR(30),CAST(total_forwarded_fetch_count AS MONEY), 1),N'.00',N'') + N' forward records fetched; ' - ELSE N'' END - - /* rows will only be in this dmv when data is in memory for the table */ - ), N'Table metadata not in memory'), - index_lock_wait_summary AS ISNULL( - CASE WHEN total_row_lock_wait_count = 0 AND total_page_lock_wait_count = 0 AND - total_index_lock_promotion_attempt_count = 0 THEN N'0 lock waits.' - ELSE - CASE WHEN total_row_lock_wait_count > 0 THEN - N'Row lock waits: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_row_lock_wait_count AS MONEY), 1), N'.00', N'') - + N'; total duration: ' + - CASE WHEN total_row_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/ - REPLACE(CONVERT(NVARCHAR(30),CAST((total_row_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; ' - ELSE - REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_row_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; ' - END - + N'avg duration: ' + - CASE WHEN avg_row_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/ - REPLACE(CONVERT(NVARCHAR(30),CAST((avg_row_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; ' - ELSE - REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(avg_row_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; ' - END - ELSE N'' - END + - CASE WHEN total_page_lock_wait_count > 0 THEN - N'Page lock waits: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_page_lock_wait_count AS MONEY), 1), N'.00', N'') - + N'; total duration: ' + - CASE WHEN total_page_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/ - REPLACE(CONVERT(NVARCHAR(30),CAST((total_page_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; ' - ELSE - REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_page_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; ' - END - + N'avg duration: ' + - CASE WHEN avg_page_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/ - REPLACE(CONVERT(NVARCHAR(30),CAST((avg_page_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; ' - ELSE - REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(avg_page_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; ' - END - ELSE N'' - END + - CASE WHEN total_index_lock_promotion_attempt_count > 0 THEN - N'Lock escalation attempts: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_index_lock_promotion_attempt_count AS MONEY), 1), N'.00', N'') - + N'; Actual Escalations: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_index_lock_promotion_count,0) AS MONEY), 1), N'.00', N'') + N'.' - ELSE N'' - END - END - ,'Error- NULL in computed column') - - RAISERROR (N'Add computed columns to #missing_index to simplify queries.',0,1) WITH NOWAIT; - IF NOT EXISTS(SELECT 1 FROM tempdb.sys.columns AS sc - JOIN tempdb..sysobjects AS so ON so.id = sc.object_id - WHERE sc.name='index_estimated_impact' AND so.name LIKE '#MissingIndexes_%') - - ALTER TABLE #MissingIndexes ADD - [index_estimated_impact] AS - REPLACE(CONVERT(NVARCHAR(256),CAST(CAST( - (user_seeks + user_scans) - AS BIGINT) AS MONEY), 1), '.00', '') + N' use' - + CASE WHEN (user_seeks + user_scans) > 1 THEN N's' ELSE N'' END - +N'; Impact: ' + CAST(avg_user_impact AS NVARCHAR(30)) - + N'%; Avg query cost: ' - + CAST(avg_total_user_cost AS NVARCHAR(30)), - [missing_index_details] AS - CASE WHEN equality_columns IS NOT NULL THEN N'EQUALITY: ' + equality_columns + N' ' - ELSE N'' - END + CASE WHEN inequality_columns IS NOT NULL THEN N'INEQUALITY: ' + inequality_columns + N' ' - ELSE N'' - END + CASE WHEN included_columns IS NOT NULL THEN N'INCLUDES: ' + included_columns + N' ' - ELSE N'' - END, - [create_tsql] AS N'CREATE INDEX [ix_' + table_name + N'_' - + REPLACE(REPLACE(REPLACE(REPLACE( - ISNULL(equality_columns,N'')+ - CASE WHEN equality_columns IS NOT NULL AND inequality_columns IS NOT NULL THEN N'_' ELSE N'' END - + ISNULL(inequality_columns,''),',','') - ,'[',''),']',''),' ','_') - + CASE WHEN included_columns IS NOT NULL THEN N'_includes' ELSE N'' END + N'] ON ' - + [statement] + N' (' + ISNULL(equality_columns,N'') - + CASE WHEN equality_columns IS NOT NULL AND inequality_columns IS NOT NULL THEN N', ' ELSE N'' END - + CASE WHEN inequality_columns IS NOT NULL THEN inequality_columns ELSE N'' END + - ') ' + CASE WHEN included_columns IS NOT NULL THEN N' INCLUDE (' + included_columns + N')' ELSE N'' END - + N' WITH (' - + N'FILLFACTOR=100, ONLINE=?, SORT_IN_TEMPDB=?' - + N')' - + N';' - , - [more_info] AS N'EXEC dbo.sp_BlitzIndex @DatabaseName=' + QUOTENAME([database_name],'''') + - N', @SchemaName=' + QUOTENAME([schema_name],'''') + N', @TableName=' + QUOTENAME([table_name],'''') + N';' - ; RAISERROR (N'Populate #IndexCreateTsql.',0,1) WITH NOWAIT; INSERT #IndexCreateTsql (index_sanity_id, create_tsql) @@ -1370,8 +1385,155 @@ BEGIN TRY AS create_tsql FROM #IndexSanity WHERE database_id = @DatabaseID; - - END + + ;WITH [maps] + AS ( SELECT + index_sanity_id, + partition_number, + data_compression_desc, + partition_number - ROW_NUMBER() OVER (PARTITION BY ips.index_sanity_id, data_compression_desc ORDER BY partition_number ) AS [rN] + FROM #IndexPartitionSanity ips + ), + [grps] + AS ( SELECT MIN([maps].[partition_number]) AS [MinKey] , + MAX([maps].[partition_number]) AS [MaxKey] , + index_sanity_id, + maps.data_compression_desc + FROM [maps] + GROUP BY [maps].[rN], index_sanity_id, maps.data_compression_desc) + INSERT #PartitionCompressionInfo + (index_sanity_id, partition_compression_detail) + SELECT DISTINCT grps.index_sanity_id , SUBSTRING(( STUFF((SELECT ', ' + ' Partition' + + CASE WHEN [grps2].[MinKey] < [grps2].[MaxKey] + THEN +'s ' + + CAST([grps2].[MinKey] AS VARCHAR) + + ' - ' + + CAST([grps2].[MaxKey] AS VARCHAR) + + ' use ' + grps2.data_compression_desc + ELSE ' ' + + CAST([grps2].[MinKey] AS VARCHAR) + + ' uses ' + grps2.data_compression_desc + END AS [Partitions] + FROM [grps] AS grps2 + WHERE grps2.index_sanity_id = grps.index_sanity_id + ORDER BY grps2.MinKey, grps2.MaxKey + FOR XML PATH('') , + TYPE + ).[value]('.', 'VARCHAR(MAX)'), 1, 1, '') ), 0, 8000) AS [partition_compression_detail] + FROM grps; + + UPDATE sz + SET sz.data_compression_desc = pci.partition_compression_detail + FROM #IndexSanitySize sz + JOIN #PartitionCompressionInfo AS pci + ON pci.index_sanity_id = sz.index_sanity_id; + + + + + IF ((PARSENAME(@SQLServerProductVersion, 4) >= 12) + OR (PARSENAME(@SQLServerProductVersion, 4) = 11 AND PARSENAME(@SQLServerProductVersion, 2) >= 3000) + OR (PARSENAME(@SQLServerProductVersion, 4) = 10 AND PARSENAME(@SQLServerProductVersion, 3) = 50 AND PARSENAME(@SQLServerProductVersion, 2) >= 2500)) + BEGIN + RAISERROR (N'Gathering Statistics Info With Newer Syntax.',0,1) WITH NOWAIT; + SET @dsql=N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + SELECT ' + QUOTENAME(@DatabaseName,'''') + N' AS database_name, + OBJECT_NAME(s.object_id) AS table_name, + ISNULL(i.name, ''System Statistic'') AS index_name, + c.name AS column_name, + s.name AS statistics_name, + CONVERT(DATETIME, ddsp.last_updated) AS last_statistics_update, + DATEDIFF(DAY, ddsp.last_updated, GETDATE()) AS days_since_last_stats_update, + ddsp.rows, + ddsp.rows_sampled, + CAST(ddsp.rows_sampled / ( 1. * ddsp.rows ) * 100 AS DECIMAL(18, 1)) AS percent_sampled, + ddsp.steps AS histogram_steps, + ddsp.modification_counter, + CASE WHEN ddsp.modification_counter > 0 + THEN CAST(ddsp.modification_counter / ( 1. * ddsp.rows ) * 100 AS DECIMAL(18, 1)) + ELSE ddsp.modification_counter + END AS percent_modifications, + CASE WHEN ddsp.rows < 500 THEN 500 + ELSE CAST(( ddsp.rows * .20 ) + 500 AS INT) + END AS modifications_before_auto_update, + ISNULL(i.type_desc, ''System Statistic - N/A'') AS index_type_desc, + CONVERT(DATETIME, obj.create_date) AS table_create_date, + CONVERT(DATETIME, obj.modify_date) AS table_modify_date + FROM ' + QUOTENAME(@DatabaseName) + N'.sys.stats AS s + JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.stats_columns sc + ON sc.object_id = s.object_id + AND sc.stats_id = s.stats_id + JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.columns c + ON c.object_id = sc.object_id + AND c.column_id = sc.column_id + JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.objects obj + ON s.object_id = obj.object_id + LEFT JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.indexes AS i + ON i.object_id = s.object_id + AND i.index_id = s.stats_id + CROSS APPLY ' + QUOTENAME(@DatabaseName) + N'.sys.dm_db_stats_properties(s.object_id, s.stats_id) AS ddsp + WHERE obj.is_ms_shipped = 0;' + + IF @dsql IS NULL + RAISERROR('@dsql is null',16,1); + + RAISERROR (N'Inserting data into #Statistics',0,1) WITH NOWAIT; + INSERT #Statistics ( database_name, table_name, index_name, column_name, statistics_name, last_statistics_update, + days_since_last_stats_update, rows, rows_sampled, percent_sampled, histogram_steps, modification_counter, + percent_modifications, modifications_before_auto_update, index_type_desc, table_create_date, table_modify_date) + + EXEC sp_executesql @dsql; + + END + ELSE + BEGIN + RAISERROR (N'Gathering Statistics Info With Older Syntax.',0,1) WITH NOWAIT; + SET @dsql=N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + SELECT ' + QUOTENAME(@DatabaseName,'''') + N' AS DatabaseName, + OBJECT_NAME(s.object_id) AS table_name, + ISNULL(i.name, ''System Statistic'') AS index_name, + c.name AS column_name, + s.name AS statistics_name, + CONVERT(DATETIME, STATS_DATE(obj.object_id, i.index_id)) AS last_statistics_update, + DATEDIFF(DAY, STATS_DATE(obj.object_id, i.index_id), GETDATE()) AS days_since_last_stats_update, + si.rowcnt, + si.rowmodctr, + CASE WHEN si.rowmodctr > 0 THEN CAST(si.rowmodctr / ( 1. * si.rowcnt ) * 100 AS DECIMAL(18, 1)) + ELSE si.rowmodctr + END AS percent_modifications, + CASE WHEN si.rowcnt < 500 THEN 500 + ELSE CAST(( si.rowcnt * .20 ) + 500 AS INT) + END AS modifications_before_auto_update, + ISNULL(i.type_desc, ''System Statistic - N/A'') AS index_type_desc, + CONVERT(DATETIME, obj.create_date) AS table_create_date, + CONVERT(DATETIME, obj.modify_date) AS table_modify_date + FROM ' + QUOTENAME(@DatabaseName) + N'.sys.stats AS s + JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.sysindexes si + ON si.name = s.name + JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.stats_columns sc + ON sc.object_id = s.object_id + AND sc.stats_id = s.stats_id + JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.columns c + ON c.object_id = sc.object_id + AND c.column_id = sc.column_id + JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.objects obj + ON s.object_id = obj.object_id + LEFT JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.indexes AS i + ON i.object_id = s.object_id + AND i.index_id = s.stats_id + WHERE obj.is_ms_shipped = 0;' + + IF @dsql IS NULL + RAISERROR('@dsql is null',16,1); + + RAISERROR (N'Inserting data into #Statistics',0,1) WITH NOWAIT; + INSERT #Statistics(database_name, table_name, index_name, column_name, statistics_name, + last_statistics_update, days_since_last_stats_update, rows, modification_counter, + percent_modifications, modifications_before_auto_update, index_type_desc, table_create_date, table_modify_date) + + EXEC sp_executesql @dsql; + END +END END TRY BEGIN CATCH RAISERROR (N'Failure populating temp tables.', 0,1) WITH NOWAIT; @@ -1430,12 +1592,12 @@ BEGIN SELECT DISTINCT grps.index_sanity_id , SUBSTRING(( STUFF((SELECT ', ' + ' Partition' + CASE WHEN [grps2].[MinKey] < [grps2].[MaxKey] THEN +'s ' - + CAST([grps2].[MinKey] AS VARCHAR) + + CAST([grps2].[MinKey] AS VARCHAR(100)) + ' - ' - + CAST([grps2].[MaxKey] AS VARCHAR) + + CAST([grps2].[MaxKey] AS VARCHAR(100)) + ' use ' + grps2.data_compression_desc ELSE ' ' - + CAST([grps2].[MinKey] AS VARCHAR) + + CAST([grps2].[MinKey] AS VARCHAR(100)) + ' uses ' + grps2.data_compression_desc END AS [Partitions] FROM [grps] AS grps2 @@ -1653,7 +1815,8 @@ BEGIN; FROM #IndexSanity WHERE index_type IN (1,2) /* Clustered, NC only*/ AND is_hypothetical=0 - AND is_disabled=0) + AND is_disabled=0 + AND is_primary_key = 0) INSERT #BlitzIndexResults ( check_id, index_sanity_id, Priority, findings_group, finding, [database_name], URL, details, index_definition, secret_columns, index_usage_summary, index_size_summary ) SELECT 2 AS check_id, @@ -1678,6 +1841,7 @@ BEGIN; di.key_column_names <> ip.key_column_names AND di.number_dupes > 1 ) + AND ip.is_primary_key = 0 /* WHERE clause skips near-duplicate indexes when getting all databases or using PainRelief mode */ AND NOT (@GetAllDatabases = 1 OR @Mode = 0) @@ -2841,6 +3005,58 @@ BEGIN; END + + ---------------------------------------- + --Statistics Info: Check_id 90-99 + ---------------------------------------- + BEGIN + + RAISERROR(N'check_id 90: Outdated statistics', 0,1) WITH NOWAIT; + INSERT #BlitzIndexResults ( check_id, Priority, findings_group, finding, [database_name], URL, details, index_definition, + secret_columns, index_usage_summary, index_size_summary ) + SELECT 90 AS check_id, + 200 AS Priority, + 'Functioning Statistaholics' AS findings_group, + 'Statistic Abandonment Issues', + s.database_name, + '' AS URL, + 'Statistics on this table were last updated ' + + CASE s.last_statistics_update WHEN NULL THEN N' NEVER ' + ELSE CONVERT(NVARCHAR(20), s.last_statistics_update) + + ' have had ' + CONVERT(NVARCHAR(100), s.modification_counter) + + ' modifications in that time, which is ' + + CONVERT(NVARCHAR(100), s.percent_modifications) + + '% of the table.' + END, + QUOTENAME(database_name) + '.' + QUOTENAME(s.index_name) + '.' + QUOTENAME(s.statistics_name) + '.' + QUOTENAME(s.column_name) AS index_definition, + 'N/A' AS secret_columns, + 'N/A' AS index_usage_summary, + 'N/A' AS index_size_summary + FROM #Statistics AS s + WHERE s.last_statistics_update <= CONVERT(DATETIME, GETDATE() - 7) + AND s.percent_modifications >= 10. + AND s.rows >= 10000 + + RAISERROR(N'check_id 91: Statistics with a low sample rate', 0,1) WITH NOWAIT; + INSERT #BlitzIndexResults ( check_id, Priority, findings_group, finding, [database_name], URL, details, index_definition, + secret_columns, index_usage_summary, index_size_summary ) + SELECT 91 AS check_id, + 200 AS Priority, + 'Functioning Statistaholics' AS findings_group, + 'Antisocial Samples', + s.database_name, + '' AS URL, + 'Only ' + CONVERT(NVARCHAR(100), s.percent_sampled) + '% of the rows were samplped during the last statistics update. This may lead to poor cardinality estimates.' , + QUOTENAME(database_name) + '.' + QUOTENAME(s.index_name) + '.' + QUOTENAME(s.statistics_name) + '.' + QUOTENAME(s.column_name) AS index_definition, + 'N/A' AS secret_columns, + 'N/A' AS index_usage_summary, + 'N/A' AS index_size_summary + FROM #Statistics AS s + WHERE s.rows_sampled < 1. + AND s.rows >= 10000 + + + END RAISERROR(N'Insert a row to help people find help', 0,1) WITH NOWAIT; IF DATEDIFF(MM, @VersionDate, GETDATE()) > 6 @@ -2931,13 +3147,15 @@ BEGIN; LEFT JOIN #IndexCreateTsql ts ON br.index_sanity_id=ts.index_sanity_id WHERE br.check_id IN (0, 1, 11, 22, 43, 68, 50, 60, 61, 62, 63, 64, 65) - ORDER BY Priority, br.findings_group, br.finding, ISNULL(SUBSTRING(br.details, CHARINDEX(': ', br.details) + 2, LEN(br.details) - CHARINDEX(': ', br.details)), 0) DESC, br.database_name ASC, [check_id] ASC, blitz_result_id ASC; + ORDER BY br.Priority ASC, br.check_id ASC, br.blitz_result_id ASC, br.findings_group ASC + OPTION (RECOMPILE); END ELSE IF (@Mode = 4) SELECT Priority, ISNULL(br.findings_group,N'') + CASE WHEN ISNULL(br.finding,N'') <> N'' THEN N': ' ELSE N'' END + br.finding AS [Finding], + br.[database_name] AS [Database Name], br.details AS [Details: schema.table.index(indexid)], br.index_definition AS [Definition: [Property]] ColumnName {datatype maxbytes}], ISNULL(br.secret_columns,'') AS [Secret Columns], @@ -2951,7 +3169,8 @@ BEGIN; br.index_sanity_id=sn.index_sanity_id LEFT JOIN #IndexCreateTsql ts ON br.index_sanity_id=ts.index_sanity_id - ORDER BY Priority, br.findings_group, br.finding, ISNULL(SUBSTRING(br.details, CHARINDEX(': ', br.details) + 2, LEN(br.details) - CHARINDEX(': ', br.details)), 0) DESC, br.database_name ASC, [check_id] ASC, blitz_result_id ASC; + ORDER BY br.Priority ASC, br.check_id ASC, br.blitz_result_id ASC, br.findings_group ASC + OPTION (RECOMPILE); END; /* End @Mode=0 or 4 (diagnose)*/ ELSE IF @Mode=1 /*Summarize*/ @@ -2959,7 +3178,7 @@ BEGIN; --This mode is to give some overall stats on the database. RAISERROR(N'@Mode=1, we are summarizing.', 0,1) WITH NOWAIT; - SELECT DB_NAME(i.database_id), + SELECT DB_NAME(i.database_id) AS [Database Name], CAST((COUNT(*)) AS NVARCHAR(256)) AS [Number Objects], CAST(CAST(SUM(sz.total_reserved_MB)/ 1024. AS NUMERIC(29,1)) AS NVARCHAR(500)) AS [All GB], @@ -3024,7 +3243,7 @@ BEGIN; --This supports slicing AND dicing in Excel RAISERROR(N'@Mode=2, here''s the details on existing indexes.', 0,1) WITH NOWAIT; - SELECT database_name AS [Database Name], + SELECT [database_name] AS [Database Name], [schema_name] AS [Schema Name], [object_name] AS [Object Name], ISNULL(index_name, '') AS [Index Name], @@ -3093,7 +3312,7 @@ BEGIN; ELSE IF @Mode=3 /*Missing index Detail*/ BEGIN SELECT - database_name AS [Database], + database_name AS [Database Name], [schema_name] AS [Schema], table_name AS [Table], CAST((magic_benefit_number/@DaysUptime) AS BIGINT) @@ -3124,6 +3343,7 @@ BEGIN; NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL, NULL, 0 AS display_order ORDER BY [Display Order] ASC, [Magic Benefit Number] DESC + OPTION (RECOMPILE); END /* End @Mode=3 (index detail)*/ END @@ -3144,6 +3364,4 @@ BEGIN CATCH RETURN; END CATCH; - -GO - +GO \ No newline at end of file diff --git a/sp_BlitzWho.sql b/sp_BlitzWho.sql new file mode 100644 index 000000000..8ae92cf82 --- /dev/null +++ b/sp_BlitzWho.sql @@ -0,0 +1,329 @@ +IF OBJECT_ID('dbo.sp_BlitzWho') IS NULL + EXEC ('CREATE PROCEDURE dbo.sp_BlitzWho AS RETURN 0;') +GO + +ALTER PROCEDURE [dbo].[sp_BlitzWho] + @Help TINYINT = 0 +AS +BEGIN + SET NOCOUNT ON; + SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; + + IF @Help = 1 + PRINT ' +sp_BlitzWho from http://FirstResponderKit.org + +This script gives you a snapshot of everything currently executing on your SQL Server. + +To learn more, visit http://FirstResponderKit.org where you can download new +versions for free, watch training videos on how it works, get more info on +the findings, contribute your own code, and more. + +Known limitations of this version: + - Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000. + +MIT License + +Copyright (c) 2016 Brent Ozar Unlimited + +Permission is hereby granted, free of charge, to any person obtaining a copy +of this software and associated documentation files (the "Software"), to deal +in the Software without restriction, including without limitation the rights +to use, copy, modify, merge, publish, distribute, sublicense, and/or sell +copies of the Software, and to permit persons to whom the Software is +furnished to do so, subject to the following conditions: + +The above copyright notice and this permission notice shall be included in all +copies or substantial portions of the Software. + +THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE +SOFTWARE. +'; + +/* Get the major and minor build numbers */ +DECLARE @ProductVersion NVARCHAR(128) + ,@ProductVersionMajor DECIMAL(10,2) + ,@ProductVersionMinor DECIMAL(10,2) + ,@EnhanceFlag BIT = 0 + ,@StringToExecute NVARCHAR(MAX) + ,@EnhanceSQL NVARCHAR(MAX) = + N'[query_stats].last_dop, + [query_stats].min_dop, + [query_stats].max_dop, + [query_stats].last_grant_kb, + [query_stats].min_grant_kb, + [query_stats].max_grant_kb, + [query_stats].last_used_grant_kb, + [query_stats].min_used_grant_kb, + [query_stats].max_used_grant_kb, + [query_stats].last_ideal_grant_kb, + [query_stats].min_ideal_grant_kb, + [query_stats].max_ideal_grant_kb, + [query_stats].last_reserved_threads, + [query_stats].min_reserved_threads, + [query_stats].max_reserved_threads, + [query_stats].last_used_threads, + [query_stats].min_used_threads, + [query_stats].max_used_threads,' + +SET @ProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)); +SELECT @ProductVersionMajor = SUBSTRING(@ProductVersion, 1,CHARINDEX('.', @ProductVersion) + 1 ), +@ProductVersionMinor = PARSENAME(CONVERT(VARCHAR(32), @ProductVersion), 2) + + + +IF @ProductVersionMajor > 9 and @ProductVersionMajor < 11 +BEGIN +SET @StringToExecute = N' + SELECT GETDATE() AS [run_date] , + CONVERT(VARCHAR, DATEADD(ms, [r].[total_elapsed_time], 0), 114) AS [elapsed_time] , + [s].[session_id] , + [wt].[wait_info] , + [s].[status] , + ISNULL(SUBSTRING([dest].[text], + ( [query_stats].[statement_start_offset] / 2 ) + 1, + ( ( CASE [query_stats].[statement_end_offset] + WHEN -1 THEN DATALENGTH([dest].[text]) + ELSE [query_stats].[statement_end_offset] + END - [query_stats].[statement_start_offset] ) + / 2 ) + 1), [dest].[text]) AS [query_text] , + [derp].[query_plan] , + [qmg].[query_cost] , + [r].[blocking_session_id] , + [r].[cpu_time] AS [request_cpu_time], + [r].[logical_reads] AS [request_logical_reads], + [r].[writes] AS [request_writes], + [r].[reads] AS [request_physical_reads] , + [s].[cpu_time] AS [session_cpu], + [s].[logical_reads] AS [session_logical_reads], + [s].[reads] AS [session_physical_reads] , + [s].[writes] AS [session_writes], + [s].[memory_usage] , + [r].[estimated_completion_time] , + [r].[deadlock_priority] , + CASE [s].[transaction_isolation_level] + WHEN 0 THEN ''Unspecified'' + WHEN 1 THEN ''Read Uncommitted'' + WHEN 2 THEN ''Read Committed'' + WHEN 3 THEN ''Repeatable Read'' + WHEN 4 THEN ''Serializable'' + WHEN 5 THEN ''Snapshot'' + ELSE ''WHAT HAVE YOU DONE?'' + END AS [transaction_isolation_level] , + [r].[open_transaction_count] , + [qmg].[dop] AS [degree_of_parallelism] , + [qmg].[request_time] , + COALESCE(CAST([qmg].[grant_time] AS VARCHAR), ''N/A'') AS [grant_time] , + [qmg].[requested_memory_kb] , + [qmg].[granted_memory_kb] AS [grant_memory_kb], + CASE WHEN [qmg].[grant_time] IS NULL THEN ''N/A'' + WHEN [qmg].[requested_memory_kb] < [qmg].[granted_memory_kb] + THEN ''Query Granted Less Than Query Requested'' + ELSE ''Memory Request Granted'' + END AS [is_request_granted] , + [qmg].[required_memory_kb] , + [qmg].[used_memory_kb] , + [qmg].[ideal_memory_kb] , + [qmg].[is_small] , + [qmg].[timeout_sec] , + [qmg].[resource_semaphore_id] , + COALESCE(CAST([qmg].[wait_order] AS VARCHAR), ''N/A'') AS [wait_order] , + COALESCE(CAST([qmg].[wait_time_ms] AS VARCHAR), + ''N/A'') AS [wait_time_ms] , + CASE [qmg].[is_next_candidate] + WHEN 0 THEN ''No'' + WHEN 1 THEN ''Yes'' + ELSE ''N/A'' + END AS [next_candidate_for_memory_grant] , + [qrs].[target_memory_kb] , + COALESCE(CAST([qrs].[max_target_memory_kb] AS VARCHAR), + ''Small Query Resource Semaphore'') AS [max_target_memory_kb] , + [qrs].[total_memory_kb] , + [qrs].[available_memory_kb] , + [qrs].[granted_memory_kb] , + [qrs].[used_memory_kb] , + [qrs].[grantee_count] , + [qrs].[waiter_count] , + [qrs].[timeout_error_count] , + COALESCE(CAST([qrs].[forced_grant_count] AS VARCHAR), + ''Small Query Resource Semaphore'') AS [forced_grant_count], + [s].[nt_domain] , + [s].[host_name] , + [s].[login_name] , + [s].[nt_user_name] , + [s].[program_name] , + [s].[client_interface_name] , + [s].[login_time] , + [r].[start_time] + FROM [sys].[dm_exec_sessions] AS [s] + INNER JOIN [sys].[dm_exec_requests] AS [r] + ON [r].[session_id] = [s].[session_id] + LEFT JOIN ( SELECT DISTINCT + [wait].[session_id] , + ( SELECT [waitwait].[wait_type] + N'' ('' + + CAST(SUM([waitwait].[wait_duration_ms]) AS NVARCHAR(128)) + + N'' ms) '' + FROM [sys].[dm_os_waiting_tasks] AS [waitwait] + WHERE [waitwait].[session_id] = [wait].[session_id] + GROUP BY [waitwait].[wait_type] + ORDER BY SUM([waitwait].[wait_duration_ms]) DESC + FOR + XML PATH('''') ) AS [wait_info] + FROM [sys].[dm_os_waiting_tasks] AS [wait] ) AS [wt] + ON [s].[session_id] = [wt].[session_id] + LEFT JOIN [sys].[dm_exec_query_stats] AS [query_stats] + ON [r].[sql_handle] = [query_stats].[sql_handle] + AND [r].[plan_handle] = [query_stats].[plan_handle] + AND [r].[statement_start_offset] = [query_stats].[statement_start_offset] + AND [r].[statement_end_offset] = [query_stats].[statement_end_offset] + LEFT JOIN [sys].[dm_exec_query_memory_grants] [qmg] + ON [r].[session_id] = [qmg].[session_id] + AND [r].[request_id] = [qmg].[request_id] + LEFT JOIN [sys].[dm_exec_query_resource_semaphores] [qrs] + ON [qmg].[resource_semaphore_id] = [qrs].[resource_semaphore_id] + AND [qmg].[pool_id] = [qrs].[pool_id] + OUTER APPLY [sys].[dm_exec_sql_text]([r].[sql_handle]) AS [dest] + OUTER APPLY [sys].[dm_exec_query_plan]([r].[plan_handle]) AS [derp] + WHERE [r].[session_id] <> @@SPID + AND [s].[status] <> ''sleeping'' + ORDER BY 2 DESC; + ' +END +IF @ProductVersionMajor >= 11 +BEGIN +SELECT @EnhanceFlag = + CASE WHEN @ProductVersionMajor = 11 AND @ProductVersionMinor >= 6020 THEN 1 + WHEN @ProductVersionMajor = 12 AND @ProductVersionMinor >= 5000 THEN 1 + WHEN @ProductVersionMajor = 13 AND @ProductVersionMinor >= 1601 THEN 1 + ELSE 0 + END + +SELECT @StringToExecute = N' + SELECT GETDATE() AS [run_date] , + CONVERT(VARCHAR, DATEADD(ms, [r].[total_elapsed_time], 0), 114) AS [elapsed_time] , + [s].[session_id] , + [wt].[wait_info] , + [s].[status] , + ISNULL(SUBSTRING([dest].[text], + ( [query_stats].[statement_start_offset] / 2 ) + 1, + ( ( CASE [query_stats].[statement_end_offset] + WHEN -1 THEN DATALENGTH([dest].[text]) + ELSE [query_stats].[statement_end_offset] + END - [query_stats].[statement_start_offset] ) + / 2 ) + 1), [dest].[text]) AS [query_text] , + [derp].[query_plan] , + [qmg].[query_cost] , + [r].[blocking_session_id] , + [r].[cpu_time] AS [request_cpu_time], + [r].[logical_reads] AS [request_logical_reads], + [r].[writes] AS [request_writes], + [r].[reads] AS [request_physical_reads] , + [s].[cpu_time] AS [session_cpu], + [s].[logical_reads] AS [session_logical_reads], + [s].[reads] AS [session_physical_reads] , + [s].[writes] AS [session_writes], + [s].[memory_usage] , + [r].[estimated_completion_time] , + [r].[deadlock_priority] ,' + + + CASE @EnhanceFlag + WHEN 1 THEN @EnhanceSQL + ELSE N'' END + + N'CASE [s].[transaction_isolation_level] + WHEN 0 THEN ''Unspecified'' + WHEN 1 THEN ''Read Uncommitted'' + WHEN 2 THEN ''Read Committed'' + WHEN 3 THEN ''Repeatable Read'' + WHEN 4 THEN ''Serializable'' + WHEN 5 THEN ''Snapshot'' + ELSE ''WHAT HAVE YOU DONE?'' + END AS [transaction_isolation_level] , + [r].[open_transaction_count] , + [qmg].[dop] AS [degree_of_parallelism] , + [qmg].[request_time] , + COALESCE(CAST([qmg].[grant_time] AS VARCHAR), ''Memory Not Granted'') AS [grant_time] , + [qmg].[requested_memory_kb] , + [qmg].[granted_memory_kb] AS [grant_memory_kb], + CASE WHEN [qmg].[grant_time] IS NULL THEN ''N/A'' + WHEN [qmg].[requested_memory_kb] < [qmg].[granted_memory_kb] + THEN ''Query Granted Less Than Query Requested'' + ELSE ''Memory Request Granted'' + END AS [is_request_granted] , + [qmg].[required_memory_kb] , + [qmg].[used_memory_kb] , + [qmg].[ideal_memory_kb] , + [qmg].[is_small] , + [qmg].[timeout_sec] , + [qmg].[resource_semaphore_id] , + COALESCE(CAST([qmg].[wait_order] AS VARCHAR), ''N/A'') AS [wait_order] , + COALESCE(CAST([qmg].[wait_time_ms] AS VARCHAR), + ''N/A'') AS [wait_time_ms] , + CASE [qmg].[is_next_candidate] + WHEN 0 THEN ''No'' + WHEN 1 THEN ''Yes'' + ELSE ''N/A'' + END AS [next_candidate_for_memory_grant] , + [qrs].[target_memory_kb] , + COALESCE(CAST([qrs].[max_target_memory_kb] AS VARCHAR), + ''Small Query Resource Semaphore'') AS [max_target_memory_kb] , + [qrs].[total_memory_kb] , + [qrs].[available_memory_kb] , + [qrs].[granted_memory_kb] , + [qrs].[used_memory_kb] , + [qrs].[grantee_count] , + [qrs].[waiter_count] , + [qrs].[timeout_error_count] , + COALESCE(CAST([qrs].[forced_grant_count] AS VARCHAR), + ''Small Query Resource Semaphore'') AS [forced_grant_count], + [s].[nt_domain] , + [s].[host_name] , + [s].[login_name] , + [s].[nt_user_name] , + [s].[program_name] , + [s].[client_interface_name] , + [s].[login_time] , + [r].[start_time] + FROM [sys].[dm_exec_sessions] AS [s] + INNER JOIN [sys].[dm_exec_requests] AS [r] + ON [r].[session_id] = [s].[session_id] + LEFT JOIN ( SELECT DISTINCT + [wait].[session_id] , + ( SELECT [waitwait].[wait_type] + N'' ('' + + CAST(SUM([waitwait].[wait_duration_ms]) AS NVARCHAR(128)) + + N'' ms) '' + FROM [sys].[dm_os_waiting_tasks] AS [waitwait] + WHERE [waitwait].[session_id] = [wait].[session_id] + GROUP BY [waitwait].[wait_type] + ORDER BY SUM([waitwait].[wait_duration_ms]) DESC + FOR + XML PATH('''') ) AS [wait_info] + FROM [sys].[dm_os_waiting_tasks] AS [wait] ) AS [wt] + ON [s].[session_id] = [wt].[session_id] + LEFT JOIN [sys].[dm_exec_query_stats] AS [query_stats] + ON [r].[sql_handle] = [query_stats].[sql_handle] + AND [r].[plan_handle] = [query_stats].[plan_handle] + AND [r].[statement_start_offset] = [query_stats].[statement_start_offset] + AND [r].[statement_end_offset] = [query_stats].[statement_end_offset] + LEFT JOIN [sys].[dm_exec_query_memory_grants] [qmg] + ON [r].[session_id] = [qmg].[session_id] + AND [r].[request_id] = [qmg].[request_id] + LEFT JOIN [sys].[dm_exec_query_resource_semaphores] [qrs] + ON [qmg].[resource_semaphore_id] = [qrs].[resource_semaphore_id] + AND [qmg].[pool_id] = [qrs].[pool_id] + OUTER APPLY [sys].[dm_exec_sql_text]([r].[sql_handle]) AS [dest] + OUTER APPLY [sys].[dm_exec_query_plan]([r].[plan_handle]) AS [derp] + WHERE [r].[session_id] <> @@SPID + AND [s].[status] <> ''sleeping'' + ORDER BY 2 DESC; + ' + +END + +EXEC(@StringToExecute); + +END \ No newline at end of file diff --git a/sp_foreachdb.sql b/sp_foreachdb.sql new file mode 100644 index 000000000..f6e0339af --- /dev/null +++ b/sp_foreachdb.sql @@ -0,0 +1 @@ +Placeholder \ No newline at end of file