-- Azure SQL Database Diagnostic Information Queries -- Glenn Berry -- Last Modified: September 1, 2020 -- https://glennsqlperformance.com/ -- https://sqlserverperformance.wordpress.com/ -- YouTube: https://bit.ly/2PkoAM1 -- Twitter: GlennAlanBerry -- Diagnostic Queries are available here -- https://glennsqlperformance.com/resources/ -- If you like PowerShell, there is a very useful community solution for running these queries in an automated fashion -- https://dbatools.io/ -- Invoke-DbaDiagnosticQuery -- https://dbatools.io/functions/invoke-dbadiagnosticquery/ --****************************************************************************** --* Copyright (C) 2020 Glenn Berry --* All rights reserved. --* --* --* You may alter this code for your own *non-commercial* purposes. You may --* republish altered code as long as you include this copyright and give due credit. --* --* --* THIS CODE AND INFORMATION ARE PROVIDED "AS IS" WITHOUT WARRANTY OF --* ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED --* TO THE IMPLIED WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A --* PARTICULAR PURPOSE. --* --****************************************************************************** -- Make sure you are connected a user database, rather than the master system database -- Server level queries ******************************* -- SQL and OS Version information for current instance (Query 1) (Version Info) SELECT @@SERVERNAME AS [Server Name], @@VERSION AS [SQL Server and OS Version Info]; ------ -- Azure SQL Database does not expose as much information as on-premises SQL Server does -- Get logical instance-level configuration values for instance (Query 2) (Configuration Values) SELECT name, value, value_in_use, minimum, maximum, [description], is_dynamic, is_advanced FROM sys.configurations WITH (NOLOCK) ORDER BY name OPTION (RECOMPILE); ------ -- All of these settings are read-only in Azure SQL Database, so they are informational only -- SQL Server NUMA Node information (Query 3) (SQL Server NUMA Info) SELECT node_id, node_state_desc, memory_node_id, processor_group, cpu_count, online_scheduler_count, idle_scheduler_count, active_worker_count, avg_load_balance, resource_monitor_state FROM sys.dm_os_nodes WITH (NOLOCK) WHERE node_state_desc <> N'ONLINE DAC' OPTION (RECOMPILE); ------ -- Gives you some useful information about the composition and relative load on your NUMA nodes -- You want to see an equal number of schedulers on each NUMA node -- Calculates average stalls per read, per write, and per total input/output for each database file (Query 4) (IO Stalls by File) SELECT DB_NAME(fs.database_id) AS [Database Name], CAST(fs.io_stall_read_ms/(1.0 + fs.num_of_reads) AS NUMERIC(16,1)) AS [avg_read_stall_ms], CAST(fs.io_stall_write_ms/(1.0 + fs.num_of_writes) AS NUMERIC(16,1)) AS [avg_write_stall_ms], CAST((fs.io_stall_read_ms + fs.io_stall_write_ms)/(1.0 + fs.num_of_reads + fs.num_of_writes) AS NUMERIC(16,1)) AS [avg_io_stall_ms], fs.io_stall_read_ms, fs.num_of_reads, fs.io_stall_write_ms, fs.num_of_writes, fs.io_stall_read_ms + fs.io_stall_write_ms AS [io_stalls], fs.num_of_reads + fs.num_of_writes AS [total_io], io_stall_queued_read_ms AS [Resource Governor Total Read IO Latency (ms)], io_stall_queued_write_ms AS [Resource Governor Total Write IO Latency (ms)] FROM sys.dm_io_virtual_file_stats(null,null) AS fs ORDER BY avg_io_stall_ms DESC OPTION (RECOMPILE); ------ -- Helps determine which database files on the entire instance have the most I/O bottlenecks -- This can help you decide whether certain LUNs are overloaded and whether you might -- want to move some files to a different location or perhaps improve your I/O performance -- These latency numbers include all file activity against each SQL Server -- database file since SQL Server was last started -- Get I/O utilization by database (Query 5) (IO Usage By Database) WITH Aggregate_IO_Statistics AS (SELECT DB_NAME(database_id) AS [Database Name], CAST(SUM(num_of_bytes_read + num_of_bytes_written) / 1048576 AS DECIMAL(12, 2)) AS [ioTotalMB], CAST(SUM(num_of_bytes_read ) / 1048576 AS DECIMAL(12, 2)) AS [ioReadMB], CAST(SUM(num_of_bytes_written) / 1048576 AS DECIMAL(12, 2)) AS [ioWriteMB] FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS [DM_IO_STATS] GROUP BY database_id) SELECT ROW_NUMBER() OVER (ORDER BY ioTotalMB DESC) AS [I/O Rank], [Database Name], ioTotalMB AS [Total I/O (MB)], CAST(ioTotalMB / SUM(ioTotalMB) OVER () * 100.0 AS DECIMAL(5, 2)) AS [Total I/O %], ioReadMB AS [Read I/O (MB)], CAST(ioReadMB / SUM(ioReadMB) OVER () * 100.0 AS DECIMAL(5, 2)) AS [Read I/O %], ioWriteMB AS [Write I/O (MB)], CAST(ioWriteMB / SUM(ioWriteMB) OVER () * 100.0 AS DECIMAL(5, 2)) AS [Write I/O %] FROM Aggregate_IO_Statistics ORDER BY [I/O Rank] OPTION (RECOMPILE); ------ -- Helps determine which database is using the most I/O resources on the instance -- Get total buffer usage by database for current instance (Query 6) (Total Buffer Usage by Database) -- This make take some time to run on a busy instance WITH AggregateBufferPoolUsage AS (SELECT DB_NAME(database_id) AS [Database Name], COUNT(page_id) AS [Page Count], CAST(COUNT(*) * 8/1024.0 AS DECIMAL (10,2)) AS [CachedSize], AVG(read_microsec) AS [Avg Read Time (microseconds)] FROM sys.dm_os_buffer_descriptors WITH (NOLOCK) GROUP BY DB_NAME(database_id)) SELECT ROW_NUMBER() OVER(ORDER BY CachedSize DESC) AS [Buffer Pool Rank], [Database Name], CAST(CachedSize / SUM(CachedSize) OVER() * 100.0 AS DECIMAL(5,2)) AS [Buffer Pool Percent], [Page Count], CachedSize AS [Cached Size (MB)], [Avg Read Time (microseconds)] FROM AggregateBufferPoolUsage ORDER BY [Buffer Pool Rank] OPTION (RECOMPILE); ------ -- Tells you how much memory (in the buffer pool) -- is being used by each database on the instance -- Get a count of SQL connections by IP address (Query 7) (Connection Counts by IP Address) SELECT ec.client_net_address, es.[program_name], es.[host_name], es.login_name, COUNT(ec.session_id) AS [connection count] FROM sys.dm_exec_sessions AS es WITH (NOLOCK) INNER JOIN sys.dm_exec_connections AS ec WITH (NOLOCK) ON es.session_id = ec.session_id GROUP BY ec.client_net_address, es.[program_name], es.[host_name], es.login_name ORDER BY ec.client_net_address, es.[program_name] OPTION (RECOMPILE); ------ -- This helps you figure where your database load is coming from -- and verifies connectivity from other machines -- Solving Connectivity errors to SQL Server -- https://bit.ly/2EgzoD0 -- Get Average Task Counts (run multiple times) (Query 8) (Avg Task Counts) SELECT AVG(current_tasks_count) AS [Avg Task Count], AVG(work_queue_count) AS [Avg Work Queue Count], AVG(runnable_tasks_count) AS [Avg Runnable Task Count], AVG(pending_disk_io_count) AS [Avg Pending DiskIO Count] FROM sys.dm_os_schedulers WITH (NOLOCK) WHERE scheduler_id < 255 OPTION (RECOMPILE); ------ -- Sustained values above 10 suggest further investigation in that area (depending on your Service Tier) -- Avg Task Counts will be higher with lower service tiers -- High Avg Task Counts are often caused by blocking/deadlocking or other resource contention -- Sustained values above 1 suggest further investigation in that area -- High Avg Runnable Task Counts are a good sign of CPU pressure -- High Avg Pending DiskIO Counts are a sign of disk pressure -- Detect blocking (run multiple times) (Query 9) (Detect Blocking) SELECT t1.resource_type AS [lock type], DB_NAME(resource_database_id) AS [database], t1.resource_associated_entity_id AS [blk object],t1.request_mode AS [lock req], -- lock requested t1.request_session_id AS [waiter sid], t2.wait_duration_ms AS [wait time], -- spid of waiter (SELECT [text] FROM sys.dm_exec_requests AS r WITH (NOLOCK) -- get sql for waiter CROSS APPLY sys.dm_exec_sql_text(r.[sql_handle]) WHERE r.session_id = t1.request_session_id) AS [waiter_batch], (SELECT SUBSTRING(qt.[text],r.statement_start_offset/2, (CASE WHEN r.statement_end_offset = -1 THEN LEN(CONVERT(nvarchar(max), qt.[text])) * 2 ELSE r.statement_end_offset END - r.statement_start_offset)/2) FROM sys.dm_exec_requests AS r WITH (NOLOCK) CROSS APPLY sys.dm_exec_sql_text(r.[sql_handle]) AS qt WHERE r.session_id = t1.request_session_id) AS [waiter_stmt], -- statement blocked t2.blocking_session_id AS [blocker sid], -- spid of blocker (SELECT [text] FROM sys.sysprocesses AS p -- get sql for blocker CROSS APPLY sys.dm_exec_sql_text(p.[sql_handle]) WHERE p.spid = t2.blocking_session_id) AS [blocker_batch] FROM sys.dm_tran_locks AS t1 WITH (NOLOCK) INNER JOIN sys.dm_os_waiting_tasks AS t2 WITH (NOLOCK) ON t1.lock_owner_address = t2.resource_address OPTION (RECOMPILE); ------ -- Helps troubleshoot blocking and deadlocking issues -- The results will change from second to second on a busy system -- You should run this query multiple times when you see signs of blocking -- Page Life Expectancy (PLE) value for each NUMA node in current instance (Query 10) (PLE by NUMA Node) SELECT @@SERVERNAME AS [Server Name], RTRIM([object_name]) AS [Object Name], instance_name, cntr_value AS [Page Life Expectancy] FROM sys.dm_os_performance_counters WITH (NOLOCK) WHERE [object_name] LIKE N'%Buffer Node%' -- Handles named instances AND counter_name = N'Page life expectancy' OPTION (RECOMPILE); ------ -- PLE is a good measurement of internal memory pressure -- Higher PLE is better. Watch the trend over time, not the absolute value -- This will only return one row for non-NUMA systems -- Page Life Expectancy isn’t what you think… -- https://bit.ly/2EgynLa -- Memory Grants Pending value for current instance (Query 11) (Memory Grants Pending) SELECT @@SERVERNAME AS [Server Name], RTRIM([object_name]) AS [Object Name], cntr_value AS [Memory Grants Pending] FROM sys.dm_os_performance_counters WITH (NOLOCK) WHERE [object_name] LIKE N'%Memory Manager%' -- Handles named instances AND counter_name = N'Memory Grants Pending' OPTION (RECOMPILE); ------ -- Run multiple times, and run periodically if you suspect you are under memory pressure -- Memory Grants Pending above zero for a sustained period is a very strong indicator of internal memory pressure -- Memory Clerk Usage for instance (Query 12) (Memory Clerk Usage) -- Look for high value for CACHESTORE_SQLCP (Ad-hoc query plans) SELECT TOP(10) mc.[type] AS [Memory Clerk Type], CAST((SUM(mc.pages_kb)/1024.0) AS DECIMAL (15,2)) AS [Memory Usage (MB)] FROM sys.dm_os_memory_clerks AS mc WITH (NOLOCK) GROUP BY mc.[type] ORDER BY SUM(mc.pages_kb) DESC OPTION (RECOMPILE); ------ -- MEMORYCLERK_SQLBUFFERPOOL was new for SQL Server 2012. It should be your highest consumer of memory -- CACHESTORE_SQLCP SQL Plans -- These are cached SQL statements or batches that aren't in stored procedures, functions and triggers -- Watch out for high values for CACHESTORE_SQLCP -- Enabling 'optimize for ad hoc workloads' at the instance level can help reduce this -- CACHESTORE_OBJCP Object Plans -- These are compiled plans for stored procedures, functions and triggers -- Find single-use, ad-hoc and prepared queries that are bloating the plan cache (Query 13) (Ad hoc Queries) SELECT TOP(50) DB_NAME(t.[dbid]) AS [Database Name], t.[text] AS [Query Text], cp.objtype AS [Object Type], cp.cacheobjtype AS [Cache Object Type], cp.size_in_bytes/1024 AS [Plan Size in KB] FROM sys.dm_exec_cached_plans AS cp WITH (NOLOCK) CROSS APPLY sys.dm_exec_sql_text(plan_handle) AS t WHERE cp.cacheobjtype = N'Compiled Plan' AND cp.objtype IN (N'Adhoc', N'Prepared') AND cp.usecounts = 1 ORDER BY cp.size_in_bytes DESC, DB_NAME(t.[dbid]) OPTION (RECOMPILE); ------ -- Gives you the text, type and size of single-use ad-hoc and prepared queries that waste space in the plan cache -- Enabling forced parameterization for the database can help, but test first! -- Plan cache, adhoc workloads and clearing the single-use plan cache bloat -- https://bit.ly/2EfYOkl -- Database specific queries ***************************************************************** -- Azure SQL Database size (Query 14) (Azure SQL DB Size) SELECT CAST(SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint) * 8192.) / 1024 / 1024 AS DECIMAL(15,2)) AS [Database Size In MB], CAST(SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint) * 8192.) / 1024 / 1024 / 1024 AS DECIMAL(15,2)) AS [Database Size In GB] FROM sys.database_files WITH (NOLOCK) WHERE [type_desc] = N'ROWS' OPTION (RECOMPILE); ------ -- This gives you the actual space usage within the data file only, to match what the Azure portal shows for the database size -- Determining Database Size in Azure SQL Database V12 -- https://bit.ly/2JjrqNh -- Individual File Sizes and space available for current database (Query 15) (File Sizes and Space) SELECT f.name AS [File Name] , f.physical_name AS [Physical Name], CAST((f.size/128.0) AS DECIMAL(15,2)) AS [Total Size in MB], CAST(f.size/128.0 - CAST(FILEPROPERTY(f.name, 'SpaceUsed') AS int)/128.0 AS DECIMAL(15,2)) AS [Available Space In MB], f.[file_id], fg.name AS [Filegroup Name], f.is_percent_growth, f.growth, fg.is_default, fg.is_read_only, fg.is_autogrow_all_files FROM sys.database_files AS f WITH (NOLOCK) LEFT OUTER JOIN sys.filegroups AS fg WITH (NOLOCK) ON f.data_space_id = fg.data_space_id ORDER BY f.[file_id] OPTION (RECOMPILE); ------ -- Look at how large and how full the files are and where they are located -- is_autogrow_all_files was new for SQL Server 2016. Equivalent to TF 1117 for user databases -- SQL Server 2016: Changes in default behavior for autogrow and allocations for tempdb and user databases -- http://bit.ly/2evRZSR -- Log space usage for current database (Query 16) (Log Space Usage) SELECT DB_NAME(lsu.database_id) AS [Database Name], db.recovery_model_desc AS [Recovery Model], CAST(lsu.total_log_size_in_bytes/1048576.0 AS DECIMAL(10, 2)) AS [Total Log Space (MB)], CAST(lsu.used_log_space_in_bytes/1048576.0 AS DECIMAL(10, 2)) AS [Used Log Space (MB)], CAST(lsu.used_log_space_in_percent AS DECIMAL(10, 2)) AS [Used Log Space %], CAST(lsu.log_space_in_bytes_since_last_backup/1048576.0 AS DECIMAL(10, 2)) AS [Used Log Space Since Last Backup (MB)], db.log_reuse_wait_desc FROM sys.dm_db_log_space_usage AS lsu WITH (NOLOCK) INNER JOIN sys.databases AS db WITH (NOLOCK) ON lsu.database_id = db.database_id OPTION (RECOMPILE); ------ -- Look at log file size and usage, along with the log reuse wait description for the current database -- Get VLF Count for current database (Query 17) (VLF Counts) SELECT [name] AS [Database Name], [VLF Count] FROM sys.databases AS db WITH (NOLOCK) CROSS APPLY (SELECT file_id, COUNT(*) AS [VLF Count] FROM sys.dm_db_log_info(db.database_id) GROUP BY file_id) AS li WHERE [name] <> N'master' ORDER BY [VLF Count] DESC OPTION (RECOMPILE); ------ -- High VLF counts can affect write performance to the log file -- and they can make full database restores and crash recovery take much longer -- Try to keep your VLF counts under 200 in most cases (depending on log file size) -- Important change to VLF creation algorithm in SQL Server 2014 -- https://bit.ly/2Hsjbg4 -- Status of last VLF for current database (Query 18) (Last VLF Status) SELECT TOP(1) DB_NAME(li.database_id) AS [Database Name], li.[file_id], li.vlf_size_mb, li.vlf_sequence_number, li.vlf_active, li.vlf_status FROM sys.dm_db_log_info(DB_ID()) AS li ORDER BY vlf_sequence_number DESC OPTION (RECOMPILE); ------ -- Determine whether you will be able to shrink the transaction log file -- vlf_status Values -- 0 is inactive -- 1 is initialized but unused -- 2 is active -- Important database properties for current database (Query 19) (Database Properties) SELECT db.[name] AS [Database Name], db.recovery_model_desc AS [Recovery Model], db.state_desc, db.containment_desc, db.log_reuse_wait_desc AS [Log Reuse Wait Description], db.[compatibility_level] AS [DB Compatibility Level], db.is_mixed_page_allocation_on, db.page_verify_option_desc AS [Page Verify Option], db.is_auto_create_stats_on, db.is_auto_update_stats_on, db.is_auto_update_stats_async_on, db.is_parameterization_forced, db.snapshot_isolation_state_desc, db.is_read_committed_snapshot_on, db.is_auto_close_on, db.is_auto_shrink_on, db.target_recovery_time_in_seconds, db.is_cdc_enabled, db.is_memory_optimized_elevate_to_snapshot_on, db.delayed_durability_desc, db.is_auto_create_stats_incremental_on, db.is_query_store_on, db.is_sync_with_backup, db.is_temporal_history_retention_enabled, db.is_encrypted, is_result_set_caching_on, is_accelerated_database_recovery_on, is_tempdb_spill_to_remote_store FROM sys.databases AS db WITH (NOLOCK) WHERE db.[name] <> N'master' ORDER BY db.[name] OPTION (RECOMPILE); ------ -- Things to look at: -- What recovery model are you using? -- What is the log reuse wait description? -- What compatibility level is the database on? -- What is the Page Verify Option? (should be CHECKSUM) -- Is Auto Update Statistics Asynchronously enabled? -- Is Delayed Durability enabled? -- Get database scoped configuration values for current database (Query 20) (Database-scoped Configurations) SELECT configuration_id, [name], [value] AS [value_for_primary] FROM sys.database_scoped_configurations WITH (NOLOCK) OPTION (RECOMPILE); ------ -- This lets you see the value of these new properties for the current database -- Clear plan cache for current database -- ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; -- ALTER DATABASE SCOPED CONFIGURATION (Transact-SQL) -- https://bit.ly/2sOH7nb -- I/O Statistics by file for the current database (Query 21) (IO Stats By File) SELECT DB_NAME(DB_ID()) AS [Database Name], df.name AS [Logical Name], vfs.[file_id], df.type_desc, df.physical_name AS [Physical Name], CAST(vfs.size_on_disk_bytes/1048576.0 AS DECIMAL(10, 2)) AS [Size on Disk (MB)], vfs.num_of_reads, vfs.num_of_writes, vfs.io_stall_read_ms, vfs.io_stall_write_ms, CAST(100. * vfs.io_stall_read_ms/(vfs.io_stall_read_ms + vfs.io_stall_write_ms) AS DECIMAL(10,1)) AS [IO Stall Reads Pct], CAST(100. * vfs.io_stall_write_ms/(vfs.io_stall_write_ms + vfs.io_stall_read_ms) AS DECIMAL(10,1)) AS [IO Stall Writes Pct], (vfs.num_of_reads + vfs.num_of_writes) AS [Writes + Reads], CAST(vfs.num_of_bytes_read/1048576.0 AS DECIMAL(10, 2)) AS [MB Read], CAST(vfs.num_of_bytes_written/1048576.0 AS DECIMAL(10, 2)) AS [MB Written], CAST(100. * vfs.num_of_reads/(vfs.num_of_reads + vfs.num_of_writes) AS DECIMAL(10,1)) AS [# Reads Pct], CAST(100. * vfs.num_of_writes/(vfs.num_of_reads + vfs.num_of_writes) AS DECIMAL(10,1)) AS [# Write Pct], CAST(100. * vfs.num_of_bytes_read/(vfs.num_of_bytes_read + vfs.num_of_bytes_written) AS DECIMAL(10,1)) AS [Read Bytes Pct], CAST(100. * vfs.num_of_bytes_written/(vfs.num_of_bytes_read + vfs.num_of_bytes_written) AS DECIMAL(10,1)) AS [Written Bytes Pct] FROM sys.dm_io_virtual_file_stats(DB_ID(), NULL) AS vfs INNER JOIN sys.database_files AS df WITH (NOLOCK) ON vfs.[file_id]= df.[file_id] OPTION (RECOMPILE); ------ -- This helps you characterize your workload better from an I/O perspective for this database -- It helps you determine whether you has an OLTP or DW/DSS type of workload -- Get recent resource usage (Query 22) (Recent Resource Usage) SELECT end_time, dtu_limit, cpu_limit, avg_cpu_percent, avg_memory_usage_percent, avg_data_io_percent, avg_log_write_percent, xtp_storage_percent, max_worker_percent, max_session_percent, avg_login_rate_percent, avg_instance_cpu_percent, avg_instance_memory_percent FROM sys.dm_db_resource_stats WITH (NOLOCK) ORDER BY end_time DESC OPTION (RECOMPILE); ------ -- Returns a row of usage metrics every 15 seconds, going back 64 minutes -- The end_time column is UTC time -- sys.dm_db_resource_stats (Azure SQL Database) -- https://bit.ly/2HaSpKn -- Get recent resource usage (Query 23) (Avg/Max Resource Usage) SELECT CAST(AVG(avg_cpu_percent) AS DECIMAL(10,2)) AS [Average CPU Utilization In Percent], CAST(MAX(avg_cpu_percent) AS DECIMAL(10,2)) AS [Maximum CPU Utilization In Percent], CAST(AVG(avg_data_io_percent) AS DECIMAL(10,2)) AS [Average Data IO In Percent], CAST(MAX(avg_data_io_percent) AS DECIMAL(10,2)) AS [Maximum Data IO In Percent], CAST(AVG(avg_log_write_percent) AS DECIMAL(10,2)) AS [Average Log Write Utilization In Percent], CAST(MAX(avg_log_write_percent) AS DECIMAL(10,2)) AS [Maximum Log Write Utilization In Percent], CAST(AVG(avg_memory_usage_percent) AS DECIMAL(10,2)) AS [Average Memory Usage In Percent], CAST(MAX(avg_memory_usage_percent) AS DECIMAL(10,2)) AS [Maximum Memory Usage In Percent] FROM sys.dm_db_resource_stats WITH (NOLOCK) OPTION (RECOMPILE); ------ -- Isolate top waits for this database since last restart or failover (Query 24) (Top DB Waits) WITH [Waits] AS (SELECT wait_type, wait_time_ms/ 1000.0 AS [WaitS], (wait_time_ms - signal_wait_time_ms) / 1000.0 AS [ResourceS], signal_wait_time_ms / 1000.0 AS [SignalS], waiting_tasks_count AS [WaitCount], 100.0 * wait_time_ms / SUM (wait_time_ms) OVER() AS [Percentage], ROW_NUMBER() OVER(ORDER BY wait_time_ms DESC) AS [RowNum] FROM sys.dm_db_wait_stats WITH (NOLOCK) WHERE [wait_type] NOT IN ( N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH', N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE', N'CHKPT', N'CLR_AUTO_EVENT', N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE', N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD', N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE', N'EXECSYNC', N'FSAGENT', N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX', N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE', N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE', N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', N'LOGMGR_QUEUE', N'MEMORY_ALLOCATION_EXT', N'ONDEMAND_TASK_QUEUE', N'PREEMPTIVE_HADR_LEASE_MECHANISM', N'PREEMPTIVE_SP_SERVER_DIAGNOSTICS', N'PREEMPTIVE_ODBCOPS', N'PREEMPTIVE_OS_LIBRARYOPS', N'PREEMPTIVE_OS_COMOPS', N'PREEMPTIVE_OS_CRYPTOPS', N'PREEMPTIVE_OS_PIPEOPS', N'PREEMPTIVE_OS_AUTHENTICATIONOPS', N'PREEMPTIVE_OS_GENERICOPS', N'PREEMPTIVE_OS_VERIFYTRUST', N'PREEMPTIVE_OS_FILEOPS', N'PREEMPTIVE_OS_DEVICEOPS', N'PREEMPTIVE_OS_QUERYREGISTRY', N'PREEMPTIVE_OS_WRITEFILE', N'PREEMPTIVE_XE_CALLBACKEXECUTE', N'PREEMPTIVE_XE_DISPATCHER', N'PREEMPTIVE_XE_GETTARGETSTATE', N'PREEMPTIVE_XE_SESSIONCOMMIT', N'PREEMPTIVE_XE_TARGETINIT', N'PREEMPTIVE_XE_TARGETFINALIZE', N'PREEMPTIVE_XHTTP', N'PWAIT_ALL_COMPONENTS_INITIALIZED', N'PWAIT_DIRECTLOGCONSUMER_GETNEXT', N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', N'QDS_ASYNC_QUEUE', N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_GOVERNOR_IDLE', N'RESOURCE_QUEUE', N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP', N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY', N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', N'SLEEP_SYSTEMTASK', N'SLEEP_TASK', N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', N'SQLTRACE_WAIT_ENTRIES', N'WAIT_FOR_RESULTS', N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', N'WAIT_XTP_CKPT_CLOSE', N'WAIT_XTP_RECOVERY', N'XE_BUFFERMGR_ALLPROCESSED_EVENT', N'XE_DISPATCHER_JOIN', N'XE_DISPATCHER_WAIT', N'XE_LIVE_TARGET_TVF', N'XE_TIMER_EVENT') AND waiting_tasks_count > 0) SELECT MAX (W1.wait_type) AS [WaitType], CAST (MAX (W1.Percentage) AS DECIMAL (5,2)) AS [Wait Percentage], CAST ((MAX (W1.WaitS) / MAX (W1.WaitCount)) AS DECIMAL (16,4)) AS [AvgWait_Sec], CAST ((MAX (W1.ResourceS) / MAX (W1.WaitCount)) AS DECIMAL (16,4)) AS [AvgRes_Sec], CAST ((MAX (W1.SignalS) / MAX (W1.WaitCount)) AS DECIMAL (16,4)) AS [AvgSig_Sec], CAST (MAX (W1.WaitS) AS DECIMAL (16,2)) AS [Total_Wait_Sec], CAST (MAX (W1.ResourceS) AS DECIMAL (16,2)) AS [Resource_Sec], CAST (MAX (W1.SignalS) AS DECIMAL (16,2)) AS [Signal_Sec], MAX (W1.WaitCount) AS [Wait Count] FROM Waits AS W1 INNER JOIN Waits AS W2 ON W2.RowNum <= W1.RowNum GROUP BY W1.RowNum HAVING SUM (W2.Percentage) - MAX (W1.Percentage) < 99 -- percentage threshold OPTION (RECOMPILE); ------ -- Cumulative wait stats are not as useful on an idle instance that is not under load or performance pressure -- SQL Server Wait Types Library -- https://bit.ly/2ePzYO2 -- The SQL Server Wait Type Repository -- https://bit.ly/1afzfjC -- Wait statistics, or please tell me where it hurts -- https://bit.ly/2wsQHQE -- SQL Server 2005 Performance Tuning using the Waits and Queues -- https://bit.ly/1o2NFoF -- sys.dm_db_wait_stats (Azure SQL Database) -- https://bit.ly/2HoJOoT -- Get most frequently executed queries for this database (Query 25) (Query Execution Counts) SELECT TOP(50) LEFT(t.[text], 50) AS [Short Query Text], qs.execution_count AS [Execution Count], qs.total_logical_reads AS [Total Logical Reads], qs.total_logical_reads/qs.execution_count AS [Avg Logical Reads], qs.total_worker_time AS [Total Worker Time], qs.total_worker_time/qs.execution_count AS [Avg Worker Time], qs.total_elapsed_time AS [Total Elapsed Time], qs.total_elapsed_time/qs.execution_count AS [Avg Elapsed Time], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], qs.creation_time AS [Creation Time] --,t.[text] AS [Complete Query Text], qp.query_plan AS [Query Plan] -- uncomment out these columns if not copying results to Excel FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK) CROSS APPLY sys.dm_exec_sql_text(plan_handle) AS t CROSS APPLY sys.dm_exec_query_plan(plan_handle) AS qp WHERE t.dbid = DB_ID() ORDER BY qs.execution_count DESC OPTION (RECOMPILE); ------ -- Get top total worker time queries for this database (Query 26) (Top Worker Time Queries) SELECT TOP(50) DB_NAME(t.[dbid]) AS [Database Name], REPLACE(REPLACE(LEFT(t.[text], 50), CHAR(10),''), CHAR(13),'') AS [Short Query Text], qs.total_worker_time AS [Total Worker Time], qs.min_worker_time AS [Min Worker Time], qs.total_worker_time/qs.execution_count AS [Avg Worker Time], qs.max_worker_time AS [Max Worker Time], qs.min_elapsed_time AS [Min Elapsed Time], qs.total_elapsed_time/qs.execution_count AS [Avg Elapsed Time], qs.max_elapsed_time AS [Max Elapsed Time], qs.min_logical_reads AS [Min Logical Reads], qs.total_logical_reads/qs.execution_count AS [Avg Logical Reads], qs.max_logical_reads AS [Max Logical Reads], qs.execution_count AS [Execution Count], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], qs.creation_time AS [Creation Time] --,t.[text] AS [Query Text], qp.query_plan AS [Query Plan] -- uncomment out these columns if not copying results to Excel FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK) CROSS APPLY sys.dm_exec_sql_text(plan_handle) AS t CROSS APPLY sys.dm_exec_query_plan(plan_handle) AS qp WHERE t.dbid = DB_ID() ORDER BY qs.total_worker_time DESC OPTION (RECOMPILE); ------ -- Helps you find the most expensive queries from a CPU perspective for this database -- Can also help track down parameter sniffing issues -- Get top total logical reads queries for this database (Query 27) (Top Logical Reads Queries) SELECT TOP(50) DB_NAME(t.[dbid]) AS [Database Name], REPLACE(REPLACE(LEFT(t.[text], 50), CHAR(10),''), CHAR(13),'') AS [Short Query Text], qs.total_logical_reads AS [Total Logical Reads], qs.min_logical_reads AS [Min Logical Reads], qs.total_logical_reads/qs.execution_count AS [Avg Logical Reads], qs.max_logical_reads AS [Max Logical Reads], qs.min_worker_time AS [Min Worker Time], qs.total_worker_time/qs.execution_count AS [Avg Worker Time], qs.max_worker_time AS [Max Worker Time], qs.min_elapsed_time AS [Min Elapsed Time], qs.total_elapsed_time/qs.execution_count AS [Avg Elapsed Time], qs.max_elapsed_time AS [Max Elapsed Time], qs.execution_count AS [Execution Count], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], qs.creation_time AS [Creation Time] --,t.[text] AS [Complete Query Text], qp.query_plan AS [Query Plan] -- uncomment out these columns if not copying results to Excel FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK) CROSS APPLY sys.dm_exec_sql_text(plan_handle) AS t CROSS APPLY sys.dm_exec_query_plan(plan_handle) AS qp WHERE t.dbid = DB_ID() ORDER BY qs.total_logical_reads DESC OPTION (RECOMPILE); ------ -- Helps you find the most expensive queries from a memory perspective for this database -- Can also help track down parameter sniffing issues -- Get top average elapsed time queries for this database (Query 28) (Top Avg Elapsed Time Queries) SELECT TOP(50) DB_NAME(t.[dbid]) AS [Database Name], REPLACE(REPLACE(LEFT(t.[text], 255), CHAR(10),''), CHAR(13),'') AS [Short Query Text], qs.total_elapsed_time/qs.execution_count AS [Avg Elapsed Time], qs.min_elapsed_time, qs.max_elapsed_time, qs.last_elapsed_time, qs.execution_count AS [Execution Count], qs.total_logical_reads/qs.execution_count AS [Avg Logical Reads], qs.total_physical_reads/qs.execution_count AS [Avg Physical Reads], qs.total_worker_time/qs.execution_count AS [Avg Worker Time], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], qs.creation_time AS [Creation Time] , qp.query_plan AS [Query Plan] -- comment out this column if copying results to Excel FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK) CROSS APPLY sys.dm_exec_sql_text(plan_handle) AS t CROSS APPLY sys.dm_exec_query_plan(plan_handle) AS qp WHERE t.dbid = DB_ID() ORDER BY qs.total_elapsed_time/qs.execution_count DESC OPTION (RECOMPILE); ------ -- Helps you find the highest average elapsed time queries for this database -- Can also help track down parameter sniffing issues -- Top Cached SPs By Execution Count (Query 29) (SP Execution Counts) SELECT TOP(100) p.name AS [SP Name], qs.execution_count AS [Execution Count], ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute], qs.total_elapsed_time/qs.execution_count AS [Avg Elapsed Time], qs.total_worker_time/qs.execution_count AS [Avg Worker Time], qs.total_logical_reads/qs.execution_count AS [Avg Logical Reads], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], FORMAT(qs.last_execution_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Last Execution Time], FORMAT(qs.cached_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Plan Cached Time] -- ,qp.query_plan AS [Query Plan] -- Uncomment if you want the Query Plan FROM sys.procedures AS p WITH (NOLOCK) INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK) ON p.[object_id] = qs.[object_id] CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp WHERE qs.database_id = DB_ID() AND DATEDIFF(Minute, qs.cached_time, GETDATE()) > 0 ORDER BY qs.execution_count DESC OPTION (RECOMPILE); ------ -- Tells you which cached stored procedures are called the most often -- This helps you characterize and baseline your workload -- Top Cached SPs By Avg Elapsed Time (Query 30) (SP Avg Elapsed Time) SELECT TOP(25) p.name AS [SP Name], qs.min_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time], qs.max_elapsed_time, qs.last_elapsed_time, qs.total_elapsed_time, qs.execution_count, ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute], qs.total_worker_time/qs.execution_count AS [AvgWorkerTime], qs.total_worker_time AS [TotalWorkerTime], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], FORMAT(qs.last_execution_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Last Execution Time], FORMAT(qs.cached_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Plan Cached Time] -- ,qp.query_plan AS [Query Plan] -- Uncomment if you want the Query Plan FROM sys.procedures AS p WITH (NOLOCK) INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK) ON p.[object_id] = qs.[object_id] CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp WHERE qs.database_id = DB_ID() AND DATEDIFF(Minute, qs.cached_time, GETDATE()) > 0 ORDER BY avg_elapsed_time DESC OPTION (RECOMPILE); ------ -- This helps you find high average elapsed time cached stored procedures that -- may be easy to optimize with standard query tuning techniques -- Top Cached SPs By Total Worker time. Worker time relates to CPU cost (Query 31) (SP Worker Time) SELECT TOP(25) p.name AS [SP Name], qs.total_worker_time AS [TotalWorkerTime], qs.total_worker_time/qs.execution_count AS [AvgWorkerTime], qs.execution_count, ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute], qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], FORMAT(qs.last_execution_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Last Execution Time], FORMAT(qs.cached_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Plan Cached Time] -- ,qp.query_plan AS [Query Plan] -- Uncomment if you want the Query Plan FROM sys.procedures AS p WITH (NOLOCK) INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK) ON p.[object_id] = qs.[object_id] CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp WHERE qs.database_id = DB_ID() AND DATEDIFF(Minute, qs.cached_time, GETDATE()) > 0 ORDER BY qs.total_worker_time DESC OPTION (RECOMPILE); ------ -- This helps you find the most expensive cached stored procedures from a CPU perspective -- You should look at this if you see signs of CPU pressure -- Top Cached SPs By Total Logical Reads. Logical reads relate to memory pressure (Query 32) (SP Logical Reads) SELECT TOP(25) p.name AS [SP Name], qs.total_logical_reads AS [TotalLogicalReads], qs.total_logical_reads/qs.execution_count AS [AvgLogicalReads],qs.execution_count, ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute], qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], FORMAT(qs.last_execution_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Last Execution Time], FORMAT(qs.cached_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Plan Cached Time] -- ,qp.query_plan AS [Query Plan] -- Uncomment if you want the Query Plan FROM sys.procedures AS p WITH (NOLOCK) INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK) ON p.[object_id] = qs.[object_id] CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp WHERE qs.database_id = DB_ID() AND DATEDIFF(Minute, qs.cached_time, GETDATE()) > 0 ORDER BY qs.total_logical_reads DESC OPTION (RECOMPILE); ------ -- This helps you find the most expensive cached stored procedures from a memory perspective -- You should look at this if you see signs of memory pressure -- Top Cached SPs By Total Physical Reads. Physical reads relate to disk read I/O pressure (Query 33) (SP Physical Reads) SELECT TOP(25) p.name AS [SP Name],qs.total_physical_reads AS [TotalPhysicalReads], qs.total_physical_reads/qs.execution_count AS [AvgPhysicalReads], qs.execution_count, qs.total_logical_reads,qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], FORMAT(qs.last_execution_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Last Execution Time], FORMAT(qs.cached_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Plan Cached Time] -- ,qp.query_plan AS [Query Plan] -- Uncomment if you want the Query Plan FROM sys.procedures AS p WITH (NOLOCK) INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK) ON p.[object_id] = qs.[object_id] CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp WHERE qs.database_id = DB_ID() AND qs.total_physical_reads > 0 ORDER BY qs.total_physical_reads DESC, qs.total_logical_reads DESC OPTION (RECOMPILE); ------ -- This helps you find the most expensive cached stored procedures from a read I/O perspective -- You should look at this if you see signs of I/O pressure or of memory pressure -- Top Cached SPs By Total Logical Writes (Query 34) (SP Logical Writes) -- Logical writes relate to both memory and disk I/O pressure SELECT TOP(25) p.name AS [SP Name], qs.total_logical_writes AS [TotalLogicalWrites], qs.total_logical_writes/qs.execution_count AS [AvgLogicalWrites], qs.execution_count, ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute], qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time], CASE WHEN CONVERT(nvarchar(max), qp.query_plan) LIKE N'%%' THEN 1 ELSE 0 END AS [Has Missing Index], FORMAT(qs.last_execution_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Last Execution Time], FORMAT(qs.cached_time, 'yyyy-MM-dd HH:mm:ss', 'en-US') AS [Plan Cached Time] -- ,qp.query_plan AS [Query Plan] -- Uncomment if you want the Query Plan FROM sys.procedures AS p WITH (NOLOCK) INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK) ON p.[object_id] = qs.[object_id] CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp WHERE qs.database_id = DB_ID() AND qs.total_logical_writes > 0 AND DATEDIFF(Minute, qs.cached_time, GETDATE()) > 0 ORDER BY qs.total_logical_writes DESC OPTION (RECOMPILE); ------ -- This helps you find the most expensive cached stored procedures from a write I/O perspective -- You should look at this if you see signs of I/O pressure or of memory pressure -- Lists the top statements by average input/output usage for the current database (Query 35) (Top IO Statements) SELECT TOP(50) OBJECT_NAME(qt.objectid, dbid) AS [SP Name], (qs.total_logical_reads + qs.total_logical_writes) /qs.execution_count AS [Avg IO], qs.execution_count AS [Execution Count], SUBSTRING(qt.[text],qs.statement_start_offset/2, (CASE WHEN qs.statement_end_offset = -1 THEN LEN(CONVERT(nvarchar(max), qt.[text])) * 2 ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS [Query Text] FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK) CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS qt WHERE qt.[dbid] = DB_ID() ORDER BY [Avg IO] DESC OPTION (RECOMPILE); ------ -- Helps you find the most expensive statements for I/O by SP -- Possible Bad NC Indexes (writes > reads) (Query 36) (Bad NC Indexes) SELECT SCHEMA_NAME(o.[schema_id]) AS [Schema Name], OBJECT_NAME(s.[object_id]) AS [Table Name], i.name AS [Index Name], i.index_id, i.is_disabled, i.is_hypothetical, i.has_filter, i.fill_factor, s.user_updates AS [Total Writes], s.user_seeks + s.user_scans + s.user_lookups AS [Total Reads], s.user_updates - (s.user_seeks + s.user_scans + s.user_lookups) AS [Difference] FROM sys.dm_db_index_usage_stats AS s WITH (NOLOCK) INNER JOIN sys.indexes AS i WITH (NOLOCK) ON s.[object_id] = i.[object_id] AND i.index_id = s.index_id INNER JOIN sys.objects AS o WITH (NOLOCK) ON i.[object_id] = o.[object_id] WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1 AND s.database_id = DB_ID() AND s.user_updates > (s.user_seeks + s.user_scans + s.user_lookups) AND i.index_id > 1 AND i.[type_desc] = N'NONCLUSTERED' AND i.is_primary_key = 0 AND i.is_unique_constraint = 0 AND i.is_unique = 0 ORDER BY [Difference] DESC, [Total Writes] DESC, [Total Reads] ASC OPTION (RECOMPILE); ------ -- Look for indexes with high numbers of writes and zero or very low numbers of reads -- Consider your complete workload, and how long your instance has been running -- Investigate further before dropping an index! -- Missing Indexes for current database by Index Advantage (Query 37) (Missing Indexes) SELECT DISTINCT CONVERT(decimal(18,2), user_seeks * avg_total_user_cost * (avg_user_impact * 0.01)) AS [index_advantage], migs.last_user_seek, mid.[statement] AS [Database.Schema.Table], mid.equality_columns, mid.inequality_columns, mid.included_columns, migs.unique_compiles, migs.user_seeks, migs.avg_total_user_cost, migs.avg_user_impact, OBJECT_NAME(mid.[object_id]) AS [Table Name], p.rows AS [Table Rows] FROM sys.dm_db_missing_index_group_stats AS migs WITH (NOLOCK) INNER JOIN sys.dm_db_missing_index_groups AS mig WITH (NOLOCK) ON migs.group_handle = mig.index_group_handle INNER JOIN sys.dm_db_missing_index_details AS mid WITH (NOLOCK) ON mig.index_handle = mid.index_handle INNER JOIN sys.partitions AS p WITH (NOLOCK) ON p.[object_id] = mid.[object_id] WHERE mid.database_id = DB_ID() ORDER BY index_advantage DESC OPTION (RECOMPILE); ------ -- Look at index advantage, last user seek time, number of user seeks to help determine source and importance -- SQL Server is overly eager to add included columns, so beware -- Do not just blindly add indexes that show up from this query!!! -- Find missing index warnings for cached plans in the current database (Query 38) (Missing Index Warnings) -- Note: This query could take some time on a busy instance SELECT TOP(25) OBJECT_NAME(objectid) AS [ObjectName], cp.objtype, cp.usecounts, cp.size_in_bytes, query_plan FROM sys.dm_exec_cached_plans AS cp WITH (NOLOCK) CROSS APPLY sys.dm_exec_query_plan(cp.plan_handle) AS qp WHERE CAST(query_plan AS NVARCHAR(MAX)) LIKE N'%MissingIndex%' AND dbid = DB_ID() ORDER BY cp.usecounts DESC OPTION (RECOMPILE); ------ -- Helps you connect missing indexes to specific stored procedures or queries -- This can help you decide whether to add them or not -- Breaks down buffers used by current database by object (table, index) in the buffer cache (Query 39) (Buffer Usage) -- Note: This query could take some time on a busy instance SELECT SCHEMA_NAME(o.Schema_ID) AS [Schema Name], OBJECT_NAME(p.[object_id]) AS [Object Name], p.index_id, CAST(COUNT(*)/128.0 AS DECIMAL(10, 2)) AS [Buffer size(MB)], COUNT(*) AS [BufferCount], p.[Rows] AS [Row Count], p.data_compression_desc AS [Compression Type] FROM sys.allocation_units AS a WITH (NOLOCK) INNER JOIN sys.dm_os_buffer_descriptors AS b WITH (NOLOCK) ON a.allocation_unit_id = b.allocation_unit_id INNER JOIN sys.partitions AS p WITH (NOLOCK) ON a.container_id = p.hobt_id INNER JOIN sys.objects AS o WITH (NOLOCK) ON p.object_id = o.object_id WHERE b.database_id = CONVERT(int, DB_ID()) AND p.[object_id] > 100 AND OBJECT_NAME(p.[object_id]) NOT LIKE N'plan_%' AND OBJECT_NAME(p.[object_id]) NOT LIKE N'sys%' AND OBJECT_NAME(p.[object_id]) NOT LIKE N'xml_index_nodes%' GROUP BY o.Schema_ID, p.[object_id], p.index_id, p.data_compression_desc, p.[Rows] ORDER BY [BufferCount] DESC OPTION (RECOMPILE); ------ -- Tells you what tables and indexes are using the most memory in the buffer cache -- It can help identify possible candidates for data compression -- Get Table names, row counts, and compression status for clustered index or heap (Query 40) (Table Sizes) SELECT SCHEMA_NAME(o.Schema_ID) AS [Schema Name], OBJECT_NAME(p.object_id) AS [ObjectName], SUM(p.Rows) AS [RowCount], data_compression_desc AS [CompressionType] FROM sys.partitions AS p WITH (NOLOCK) INNER JOIN sys.objects AS o WITH (NOLOCK) ON p.object_id = o.object_id WHERE index_id < 2 --ignore the partitions from the non-clustered index if any AND OBJECT_NAME(p.object_id) NOT LIKE N'sys%' AND OBJECT_NAME(p.object_id) NOT LIKE N'spt_%' AND OBJECT_NAME(p.object_id) NOT LIKE N'queue_%' AND OBJECT_NAME(p.object_id) NOT LIKE N'filestream_tombstone%' AND OBJECT_NAME(p.object_id) NOT LIKE N'fulltext%' AND OBJECT_NAME(p.object_id) NOT LIKE N'ifts_comp_fragment%' AND OBJECT_NAME(p.object_id) NOT LIKE N'filetable_updates%' AND OBJECT_NAME(p.object_id) NOT LIKE N'xml_index_nodes%' AND OBJECT_NAME(p.object_id) NOT LIKE N'sqlagent_job%' AND OBJECT_NAME(p.object_id) NOT LIKE N'plan_persist%' GROUP BY SCHEMA_NAME(o.Schema_ID), p.object_id, data_compression_desc ORDER BY SUM(p.Rows) DESC OPTION (RECOMPILE); ------ -- Gives you an idea of table sizes, and possible data compression opportunities -- Get some key table properties (Query 41) (Table Properties) SELECT OBJECT_NAME(t.[object_id]) AS [ObjectName], p.[rows] AS [Table Rows], p.index_id, p.data_compression_desc AS [Index Data Compression], t.create_date, t.lock_on_bulk_load, t.lock_escalation_desc, t.is_memory_optimized, t.durability_desc, t.temporal_type_desc FROM sys.tables AS t WITH (NOLOCK) INNER JOIN sys.partitions AS p WITH (NOLOCK) ON t.[object_id] = p.[object_id] WHERE OBJECT_NAME(t.[object_id]) NOT LIKE N'sys%' ORDER BY OBJECT_NAME(t.[object_id]), p.index_id OPTION (RECOMPILE); ------ -- Gives you some good information about your tables -- is_memory_optimized and durability_desc were new in SQL Server 2014 -- temporal_type_desc, is_remote_data_archive_enabled, is_external are new in SQL Server 2016 -- sys.tables (Transact-SQL) -- https://bit.ly/2Gk7998 -- When were Statistics last updated on all indexes? (Query 42) (Statistics Update) SELECT SCHEMA_NAME(o.Schema_ID) + N'.' + o.[NAME] AS [Object Name], o.[type_desc] AS [Object Type], i.[name] AS [Index Name], STATS_DATE(i.[object_id], i.index_id) AS [Statistics Date], s.auto_created, s.no_recompute, s.user_created, s.is_incremental, s.is_temporary, st.row_count, st.used_page_count FROM sys.objects AS o WITH (NOLOCK) INNER JOIN sys.indexes AS i WITH (NOLOCK) ON o.[object_id] = i.[object_id] INNER JOIN sys.stats AS s WITH (NOLOCK) ON i.[object_id] = s.[object_id] AND i.index_id = s.stats_id INNER JOIN sys.dm_db_partition_stats AS st WITH (NOLOCK) ON o.[object_id] = st.[object_id] AND i.[index_id] = st.[index_id] WHERE o.[type] IN ('U', 'V') AND st.row_count > 0 ORDER BY STATS_DATE(i.[object_id], i.index_id) DESC OPTION (RECOMPILE); ------ -- Helps discover possible problems with out-of-date statistics -- Also gives you an idea which indexes are the most active -- sys.stats (Transact-SQL) -- https://bit.ly/2GyAxrn -- Look at most frequently modified indexes and statistics (Query 43) (Volatile Indexes) SELECT o.[name] AS [Object Name], o.[object_id], o.[type_desc], s.[name] AS [Statistics Name], s.stats_id, s.no_recompute, s.auto_created, s.is_incremental, s.is_temporary, sp.modification_counter, sp.[rows], sp.rows_sampled, sp.last_updated FROM sys.objects AS o WITH (NOLOCK) INNER JOIN sys.stats AS s WITH (NOLOCK) ON s.object_id = o.object_id CROSS APPLY sys.dm_db_stats_properties(s.object_id, s.stats_id) AS sp WHERE o.[type_desc] NOT IN (N'SYSTEM_TABLE', N'INTERNAL_TABLE') AND sp.modification_counter > 0 ORDER BY sp.modification_counter DESC, o.name OPTION (RECOMPILE); ------ -- This helps you understand your workload and make better decisions about -- things like data compression and adding new indexes to a table -- Get fragmentation info for all indexes above a certain size in the current database (Query 44) (Index Fragmentation) -- Note: This query could take some time on a very large database SELECT DB_NAME(ps.database_id) AS [Database Name], SCHEMA_NAME(o.[schema_id]) AS [Schema Name], OBJECT_NAME(ps.OBJECT_ID) AS [Object Name], i.[name] AS [Index Name], ps.index_id, ps.index_type_desc, ps.avg_fragmentation_in_percent, ps.fragment_count, ps.page_count, i.fill_factor, i.has_filter, i.filter_definition, i.[allow_page_locks] FROM sys.dm_db_index_physical_stats(DB_ID(),NULL, NULL, NULL , N'LIMITED') AS ps INNER JOIN sys.indexes AS i WITH (NOLOCK) ON ps.[object_id] = i.[object_id] AND ps.index_id = i.index_id INNER JOIN sys.objects AS o WITH (NOLOCK) ON i.[object_id] = o.[object_id] WHERE ps.database_id = DB_ID() AND ps.page_count > 2500 ORDER BY ps.avg_fragmentation_in_percent DESC OPTION (RECOMPILE); ------ -- Helps determine whether you have framentation in your relational indexes -- and how effective your index maintenance strategy is --- Index Read/Write stats (all tables in current DB) ordered by Reads (Query 45) (Overall Index Usage - Reads) SELECT OBJECT_NAME(i.[object_id]) AS [ObjectName], i.[name] AS [IndexName], i.index_id, s.user_seeks, s.user_scans, s.user_lookups, s.user_seeks + s.user_scans + s.user_lookups AS [Total Reads], s.user_updates AS [Writes], i.[type_desc] AS [Index Type], i.fill_factor AS [Fill Factor], i.has_filter, i.filter_definition, s.last_user_scan, s.last_user_lookup, s.last_user_seek FROM sys.indexes AS i WITH (NOLOCK) LEFT OUTER JOIN sys.dm_db_index_usage_stats AS s WITH (NOLOCK) ON i.[object_id] = s.[object_id] AND i.index_id = s.index_id AND s.database_id = DB_ID() WHERE OBJECTPROPERTY(i.[object_id],'IsUserTable') = 1 ORDER BY s.user_seeks + s.user_scans + s.user_lookups DESC OPTION (RECOMPILE); -- Order by reads ------ -- Show which indexes in the current database are most active for Reads --- Index Read/Write stats (all tables in current DB) ordered by Writes (Query 46) (Overall Index Usage - Writes) SELECT OBJECT_NAME(i.[object_id]) AS [ObjectName], i.[name] AS [IndexName], i.index_id, s.user_updates AS [Writes], s.user_seeks + s.user_scans + s.user_lookups AS [Total Reads], i.[type_desc] AS [Index Type], i.fill_factor AS [Fill Factor], i.has_filter, i.filter_definition, s.last_system_update, s.last_user_update FROM sys.indexes AS i WITH (NOLOCK) LEFT OUTER JOIN sys.dm_db_index_usage_stats AS s WITH (NOLOCK) ON i.[object_id] = s.[object_id] AND i.index_id = s.index_id AND s.database_id = DB_ID() WHERE OBJECTPROPERTY(i.[object_id],'IsUserTable') = 1 ORDER BY s.user_updates DESC OPTION (RECOMPILE); -- Order by writes ------ -- Show which indexes in the current database are most active for Writes -- Get in-memory OLTP index usage (Query 47) (XTP Index Usage) SELECT OBJECT_NAME(i.[object_id]) AS [Object Name], i.index_id, i.[name] AS [Index Name], i.[type_desc], xis.scans_started, xis.scans_retries, xis.rows_touched, xis.rows_returned FROM sys.dm_db_xtp_index_stats AS xis WITH (NOLOCK) INNER JOIN sys.indexes AS i WITH (NOLOCK) ON i.[object_id] = xis.[object_id] AND i.index_id = xis.index_id ORDER BY OBJECT_NAME(i.[object_id]) OPTION (RECOMPILE); ------ -- This gives you some index usage statistics for in-memory OLTP -- Returns no data if you are not using in-memory OLTP -- Guidelines for Using Indexes on Memory-Optimized Tables -- https://bit.ly/2GCP8lF -- Look at Columnstore index physical statistics (Query 48) (Columnstore Index Physical Stat) SELECT OBJECT_NAME(ps.object_id) AS [TableName], i.[name] AS [IndexName], ps.index_id, ps.partition_number, ps.delta_store_hobt_id, ps.state_desc, ps.total_rows, ps.size_in_bytes, ps.trim_reason_desc, ps.generation, ps.transition_to_compressed_state_desc, ps.has_vertipaq_optimization, ps.deleted_rows, 100 * (ISNULL(ps.deleted_rows, 0))/ps.total_rows AS [Fragmentation] FROM sys.dm_db_column_store_row_group_physical_stats AS ps WITH (NOLOCK) INNER JOIN sys.indexes AS i WITH (NOLOCK) ON ps.object_id = i.object_id AND ps.index_id = i.index_id ORDER BY ps.object_id, ps.partition_number, ps.row_group_id OPTION (RECOMPILE); ------ -- sys.dm_db_column_store_row_group_physical_stats (Transact-SQL) -- https://bit.ly/2q276XQ -- Get lock waits for current database (Query 49) (Lock Waits) SELECT o.name AS [table_name], i.name AS [index_name], ios.index_id, ios.partition_number, SUM(ios.row_lock_wait_count) AS [total_row_lock_waits], SUM(ios.row_lock_wait_in_ms) AS [total_row_lock_wait_in_ms], SUM(ios.page_lock_wait_count) AS [total_page_lock_waits], SUM(ios.page_lock_wait_in_ms) AS [total_page_lock_wait_in_ms], SUM(ios.page_lock_wait_in_ms)+ SUM(row_lock_wait_in_ms) AS [total_lock_wait_in_ms] FROM sys.dm_db_index_operational_stats(DB_ID(), NULL, NULL, NULL) AS ios INNER JOIN sys.objects AS o WITH (NOLOCK) ON ios.[object_id] = o.[object_id] INNER JOIN sys.indexes AS i WITH (NOLOCK) ON ios.[object_id] = i.[object_id] AND ios.index_id = i.index_id WHERE o.[object_id] > 100 GROUP BY o.name, i.name, ios.index_id, ios.partition_number HAVING SUM(ios.page_lock_wait_in_ms)+ SUM(row_lock_wait_in_ms) > 0 ORDER BY total_lock_wait_in_ms DESC OPTION (RECOMPILE); ------ -- This query is helpful for troubleshooting blocking and deadlocking issues -- Look at UDF execution statistics (Query 50) (UDF Statistics) SELECT OBJECT_NAME(object_id) AS [Function Name], total_worker_time, execution_count, total_elapsed_time, total_elapsed_time/execution_count AS [avg_elapsed_time], last_elapsed_time, last_execution_time, cached_time FROM sys.dm_exec_function_stats WITH (NOLOCK) WHERE database_id = DB_ID() ORDER BY total_worker_time DESC OPTION (RECOMPILE); ------ -- Helps you investigate scalar UDF performance issues -- sys.dm_exec_function_stats (Transact-SQL) -- https://bit.ly/2q1Q6BM -- Get QueryStore Options for this database (Query 51) (QueryStore Options) SELECT actual_state_desc, desired_state_desc, current_storage_size_mb, [max_storage_size_mb], query_capture_mode_desc, size_based_cleanup_mode_desc, wait_stats_capture_mode_desc, [flush_interval_seconds] FROM sys.database_query_store_options WITH (NOLOCK) OPTION (RECOMPILE); ------ -- Added in SQL Server 2016 -- Requires that QueryStore is enabled for this database -- Tuning Workload Performance with Query Store -- https://bit.ly/1kHSl7w -- Get highest aggregate duration queries over last hour (Query 52) (High Aggregate Duration Queries) WITH AggregatedDurationLastHour AS (SELECT q.query_id, SUM(count_executions * avg_duration) AS total_duration, COUNT (distinct p.plan_id) AS number_of_plans FROM sys.query_store_query_text AS qt WITH (NOLOCK) INNER JOIN sys.query_store_query AS q WITH (NOLOCK) ON qt.query_text_id = q.query_text_id INNER JOIN sys.query_store_plan AS p WITH (NOLOCK) ON q.query_id = p.query_id INNER JOIN sys.query_store_runtime_stats AS rs WITH (NOLOCK) ON rs.plan_id = p.plan_id INNER JOIN sys.query_store_runtime_stats_interval AS rsi WITH (NOLOCK) ON rsi.runtime_stats_interval_id = rs.runtime_stats_interval_id WHERE rsi.start_time >= DATEADD(hour, -1, GETUTCDATE()) AND rs.execution_type_desc = N'Regular' GROUP BY q.query_id), OrderedDuration AS (SELECT query_id, total_duration, number_of_plans, ROW_NUMBER () OVER (ORDER BY total_duration DESC, query_id) AS RN FROM AggregatedDurationLastHour) SELECT OBJECT_NAME(q.object_id) AS [Containing Object], qt.query_sql_text, od.total_duration AS [Total Duration (microsecs)], od.number_of_plans AS [Plan Count], p.is_forced_plan, p.is_parallel_plan, p.is_trivial_plan, q.query_parameterization_type_desc, p.[compatibility_level], p.last_compile_start_time, q.last_execution_time, CONVERT(xml, p.query_plan) AS query_plan_xml FROM OrderedDuration AS od INNER JOIN sys.query_store_query AS q WITH (NOLOCK) ON q.query_id = od.query_id INNER JOIN sys.query_store_query_text AS qt WITH (NOLOCK) ON q.query_text_id = qt.query_text_id INNER JOIN sys.query_store_plan AS p WITH (NOLOCK) ON q.query_id = p.query_id WHERE od.RN <= 50 ORDER BY total_duration DESC OPTION (RECOMPILE); ------ -- New for SQL Server 2016 -- Requires that QueryStore is enabled for this database -- Get input buffer information for the current database (Query 53) (Input Buffer) SELECT es.session_id, DB_NAME(es.database_id) AS [Database Name], es.login_time, es.cpu_time, es.logical_reads, es.[status], ib.event_info AS [Input Buffer] FROM sys.dm_exec_sessions AS es WITH (NOLOCK) CROSS APPLY sys.dm_exec_input_buffer(es.session_id, NULL) AS ib WHERE es.database_id = DB_ID() AND es.session_id > 50 AND es.session_id <> @@SPID OPTION (RECOMPILE); ------ -- Gives you input buffer information from all non-system sessions for the current database -- Replaces DBCC INPUTBUFFER -- New DMF for retrieving input buffer in SQL Server -- https://bit.ly/2uHKMbz -- Get any resumable index rebuild operation information (Query 54) (Resumable Index Rebuild) SELECT OBJECT_NAME(iro.object_id) AS [Object Name], iro.index_id, iro.name AS [Index Name], iro.sql_text, iro.last_max_dop_used, iro.partition_number, iro.state_desc, iro.start_time, iro.percent_complete FROM sys.index_resumable_operations AS iro WITH (NOLOCK) OPTION (RECOMPILE); ------ -- index_resumable_operations (Transact-SQL) -- https://bit.ly/2pYSWqq -- Get database automatic tuning options (Query 55) (Automatic Tuning Options) SELECT [name], desired_state_desc, actual_state_desc, reason_desc FROM sys.database_automatic_tuning_options WITH (NOLOCK) OPTION (RECOMPILE); ------ -- sys.database_automatic_tuning_options (Transact-SQL) -- https://bit.ly/2FHhLkL -- Get geo-replication link status for all secondary databases (Query 56) (Geo-Replication Link Status) SELECT link_guid, partner_server, partner_database, last_replication, replication_lag_sec, replication_state_desc, role_desc, secondary_allow_connections_desc FROM sys.dm_geo_replication_link_status WITH (NOLOCK) OPTION (RECOMPILE); ------ -- sys.dm_geo_replication_link_status (Azure SQL Database) -- https://bit.ly/2GwIqC2 -- Retrieve some Azure SQL Database properties (Query 57) (Azure SQL DB Properties) SELECT DATABASEPROPERTYEX (DB_NAME(DB_ID()), 'Edition') AS [Database Edition], DATABASEPROPERTYEX (DB_NAME(DB_ID()), 'ServiceObjective') AS [Service Objective], DATABASEPROPERTYEX (DB_NAME(DB_ID()), 'MaxSizeInBytes') AS [Max Size In Bytes], DATABASEPROPERTYEX (DB_NAME(DB_ID()), 'IsXTPSupported') AS [Is XTP Supported] OPTION (RECOMPILE); ------ -- DATABASEPROPERTYEX (Transact-SQL) -- https://bit.ly/2ItexPg -- These six Pluralsight Courses go into more detail about how to run these queries and interpret the results -- Azure SQL Database: Diagnosing Performance Issues with DMVs -- https://bit.ly/2meDRCN -- SQL Server 2017: Diagnosing Performance Issues with DMVs -- https://bit.ly/2FqCeti -- SQL Server 2017: Diagnosing Configuration Issues with DMVs -- https://bit.ly/2MSUDUL -- SQL Server 2014 DMV Diagnostic Queries – Part 1 -- https://bit.ly/2plxCer -- SQL Server 2014 DMV Diagnostic Queries – Part 2 -- https://bit.ly/2IuJpzI -- SQL Server 2014 DMV Diagnostic Queries – Part 3 -- https://bit.ly/2FIlCPb -- Microsoft Visual Studio Dev Essentials -- https://bit.ly/2qjNRxi -- Microsoft Azure Learn -- https://bit.ly/2O0Hacc