SQL Server 2008 Diagnostic Information Queries
-- SQL Server 2008 Diagnostic Information Queries -- Many of these queries will not work if you have databases in 80 compatibility mode --****************************************************************************** --* Copyright (C) 2014 Glenn Berry, SQLskills.com --* All rights reserved. --* --* For more scripts and sample code, check out --* http://sqlskills.com/blogs/glenn --* --* 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. --* --****************************************************************************** -- Check the major product version to see if it is SQL Server 2008 IF NOT EXISTS (SELECT * WHERE CONVERT(varchar(128), SERVERPROPERTY('ProductVersion')) LIKE '10%') BEGIN DECLARE @ProductVersion varchar(128) = CONVERT(varchar(128), SERVERPROPERTY('ProductVersion')); RAISERROR ('Script does not match the ProductVersion [%s] of this instance. Many of these queries may not work on this version.' , 18 , 16 , @ProductVersion); END -- Instance 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]; -- Any build older than 10.0.5500 is on an "unsupported service pack" -- SQL Server 2008 RTM Builds SQL Server 2008 SP1 Builds SQL Server 2008 SP2 Builds SQL Server 2008 SP3 Builds -- Build Description Build Description Build Description Build Description -- 10.0.1600 Gold RTM -- 10.0.1763 RTM CU1 -- 10.0.1779 RTM CU2 -- 10.0.1787 RTM CU3 --> 10.0.2531 SP1 RTM -- 10.0.1798 RTM CU4 --> 10.0.2710 SP1 CU1 -- 10.0.1806 RTM CU5 --> 10.0.2714 SP1 CU2 -- 10.0.1812 RTM CU6 --> 10.0.2723 SP1 CU3 -- 10.0.1818 RTM CU7 --> 10.0.2734 SP1 CU4 -- 10.0.1823 RTM CU8 --> 10.0.2746 SP1 CU5 -- 10.0.1828 RTM CU9 --> 10.0.2757 SP1 CU6 -- 10.0.1835 RTM CU10 --> 10.0.2766 SP1 CU7 -- RTM Branch Retired --> 10.0.2775 SP1 CU8 --> 10.0.4000 SP2 RTM -- 10.0.2789 SP1 CU9 -- 10.0.2799 SP1 CU10 -- 10.0.2804 SP1 CU11 --> 10.0.4266 SP2 CU1 -- 10.0.2808 SP1 CU12 --> 10.0.4272 SP2 CU2 -- 10.0.2816 SP1 CU13 --> 10.0.4279 SP2 CU3 -- 10.0.2821 SP1 CU14 --> 10.0.4285 SP2 CU4 --> 10.0.5500 SP3 RTM -- 10.0.2847 SP1 CU15 --> 10.0.4316 SP2 CU5 -- 10.0.2850 SP1 CU16 --> 10.0.4321 SP2 CU6 --> 10.0.5766 SP3 CU1 10/17/2011 -- SP1 Branch Retired --> 10.0,4323 SP2 CU7 --> 10.0.5768 SP3 CU2 11/21/2011 -- 10.0.4326 SP2 CU8 --> 10.0.5770 SP3 CU3 1/16/2012 -- 10.0.4330 SP2 CU9 --> 10.0.5775 SP3 CU4 3/19/2012 -- 10.0.4332 SP2 CU10 --> 10.0.5785 SP3 CU5 5/21/2012 -- 10.0.4333 SP2 CU11 --> 10.0.5788 SP3 CU6 7/16/2012 -- SP2 Branch Retired 10.0.5794 SP3 CU7 9/17/2012 -- 10.0.5828 SP3 CU8 11/19/2012 -- 10.0.5829 SP3 CU9 1/21/2013 -- 10.0.5835 SP3 CU10 3/19/2013 -- 10.0.5841 SP3 CU11 5/20/2013 -- 10.0.5844 SP3 CU12 7/15/2013 -- 10.0.5846 SP3 CU13 9/16/2013 -- 10.0.5848 SP3 CU14 11/18/2013 -- 10.0.5850 SP3 CU15 1/20/2014 -- SQL Server 2008 RTM is considered an "unsupported service pack" as of April 13, 2010 -- SQL Server 2008 SP1 is considered an "unsupported service pack" as of September 19, 2011 -- SQL Server 2008 SP2 is considered an "unsupported service pack" as of September 17, 2012 -- The SQL Server 2008 builds that were released after SQL Server 2008 was released -- http://support.microsoft.com/kb/956909 -- The SQL Server 2008 builds that were released after SQL Server 2008 Service Pack 1 was released -- http://support.microsoft.com/kb/970365 -- -- The SQL Server 2008 builds that were released after SQL Server 2008 Service Pack 2 was released -- http://support.microsoft.com/kb/2402659 -- -- The SQL Server 2008 builds that were released after SQL Server 2008 Service Pack 3 was released -- http://support.microsoft.com/kb/2629969 -- When was SQL Server installed (Query 2) (SQL Server Install Date) SELECT @@SERVERNAME AS [Server Name], createdate AS [SQL Server Install Date], loginname, [sid] FROM sys.syslogins WITH (NOLOCK) WHERE loginname = N'NT AUTHORITY\SYSTEM' OR loginname = N'NT AUTHORITY\NETWORK SERVICE'; -- Tells you the date and time that SQL Server was installed -- It is a good idea to know how old your instance is -- Get selected server properties (SQL Server 2008) (Query 3) (Server Properties) SELECT SERVERPROPERTY('MachineName') AS [MachineName], SERVERPROPERTY('ServerName') AS [ServerName], SERVERPROPERTY('InstanceName') AS [Instance], SERVERPROPERTY('IsClustered') AS [IsClustered], SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS [ComputerNamePhysicalNetBIOS], SERVERPROPERTY('Edition') AS [Edition], SERVERPROPERTY('ProductLevel') AS [ProductLevel], SERVERPROPERTY('ProductVersion') AS [ProductVersion], SERVERPROPERTY('ProcessID') AS [ProcessID], SERVERPROPERTY('Collation') AS [Collation], SERVERPROPERTY('IsFullTextInstalled') AS [IsFullTextInstalled], SERVERPROPERTY('IsIntegratedSecurityOnly') AS [IsIntegratedSecurityOnly]; -- This gives you a lot of useful information about your instance of SQL Server, -- such as the ProcessID for SQL Server and your collation -- Get SQL Server Agent jobs and Category information (Query 4) (SQL Server Agent Jobs) SELECT sj.name AS [JobName], sj.[description] AS [JobDescription], SUSER_SNAME(sj.owner_sid) AS [JobOwner], sj.date_created, sj.[enabled], sj.notify_email_operator_id, sc.name AS [CategoryName] FROM msdb.dbo.sysjobs AS sj WITH (NOLOCK) INNER JOIN msdb.dbo.syscategories AS sc WITH (NOLOCK) ON sj.category_id = sc.category_id ORDER BY sj.name OPTION (RECOMPILE); -- Gives you some basic information about your SQL Server Agent jobs, who owns them and how they are configured -- Get SQL Server Agent Alert Information (Query 5) (SQL Server Agent Alerts) SELECT name, event_source, message_id, severity, [enabled], has_notification, delay_between_responses, occurrence_count, last_occurrence_date, last_occurrence_time FROM msdb.dbo.sysalerts WITH (NOLOCK) ORDER BY name OPTION (RECOMPILE); -- Gives you some basic information about your SQL Server Agent Alerts (which are different from SQL Server Agent jobs) -- Read more about Agent Alerts here: http://www.sqlskills.com/blogs/glenn/creating-sql-server-agent-alerts-for-critical-errors/ -- Returns a list of all global trace flags that are enabled (Query 6) (Global Trace Flags) DBCC TRACESTATUS (-1); -- If no global trace flags are enabled, no results will be returned. -- It is very useful to know what global trace flags are currently enabled -- as part of the diagnostic process. -- Common trace flags that should be enabled in most cases -- TF 3226 - Supresses logging of successful database backup messages to the SQL Server Error Log -- TF 1118 - Helps alleviate allocation contention in tempdb (more important with older versions of SQL Server) -- SQL Server NUMA Node information (Query 7) (SQL Server NUMA Info) SELECT node_id, node_state_desc, memory_node_id, online_scheduler_count, active_worker_count, avg_load_balance 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 -- Hardware information from SQL Server 2008 (Query 8) (Hardware Info) -- (Cannot distinguish between HT and multi-core) SELECT cpu_count AS [Logical CPU Count], hyperthread_ratio AS [Hyperthread Ratio], cpu_count/hyperthread_ratio AS [Physical CPU Count], physical_memory_in_bytes/1048576 AS [Physical Memory (MB)], sqlserver_start_time FROM sys.dm_os_sys_info WITH (NOLOCK) OPTION (RECOMPILE); -- Gives you some good basic hardware information about your database server -- Get System Manufacturer and model number from (Query 9) (System Manufacturer) -- SQL Server Error log. This query might take a few seconds -- if you have not recycled your error log recently EXEC xp_readerrorlog 0,1,"Manufacturer"; -- This can help you determine the capabilities -- and capacities of your database server -- Get processor description from Windows Registry (Query 10) (Processor Description) EXEC xp_instance_regread N'HKEY_LOCAL_MACHINE', N'HARDWARE\DESCRIPTION\System\CentralProcessor\0', 'ProcessorNameString'; -- Gives you the model number and rated clock speed of your processor(s) -- Your processors may be running at less that the rated clock speed due -- to the Windows Power Plan or hardware power management -- Get the current node name from your cluster nodes (Query 11) (Current Cluster Node) -- (if your database server is in a cluster) SELECT NodeName FROM sys.dm_os_cluster_nodes WITH (NOLOCK) OPTION (RECOMPILE); -- Knowing which node owns the cluster resources is critical -- Especially when you are installing Windows or SQL Server updates -- You will see no results if your instance is not clustered -- Get configuration values for instance (Query 12) (Configuration Values) SELECT name, value, value_in_use, [description] FROM sys.configurations WITH (NOLOCK) ORDER BY name OPTION (RECOMPILE); -- Focus on -- backup compression default -- cost threshold for parallelism -- clr enabled (only enable if it is needed) -- lightweight pooling (should be zero) -- max degree of parallelism (depends on your workload) -- max server memory (MB) (set to an appropriate value) -- optimize for ad hoc workloads (should be 1) -- priority boost (should be zero) -- File Names and Paths for TempDB and all user databases in instance (Query 13) (Database Filenames and Paths) SELECT DB_NAME([database_id])AS [Database Name], [file_id], name, physical_name, type_desc, state_desc, is_percent_growth, growth, CONVERT( bigint, size/128.0) AS [Total Size in MB] FROM sys.master_files WITH (NOLOCK) WHERE [database_id] > 4 AND [database_id] <> 32767 OR [database_id] = 2 ORDER BY DB_NAME([database_id]) OPTION (RECOMPILE); -- Things to look at: -- Are data files and log files on different drives? -- Is everything on the C: drive? -- Is TempDB on dedicated drives? -- Is there only one TempDB data file? -- Are all of the TempDB data files the same size? -- Are there multiple data files for user databases? -- Is percent growth enabled for any files (which is bad)? -- Drive level latency information (Query 14) (Drive Level Latency) -- Based on code from Jimmy May SELECT [Drive], CASE WHEN num_of_reads = 0 THEN 0 ELSE (io_stall_read_ms/num_of_reads) END AS [Read Latency], CASE WHEN io_stall_write_ms = 0 THEN 0 ELSE (io_stall_write_ms/num_of_writes) END AS [Write Latency], CASE WHEN (num_of_reads = 0 AND num_of_writes = 0) THEN 0 ELSE (io_stall/(num_of_reads + num_of_writes)) END AS [Overall Latency], CASE WHEN num_of_reads = 0 THEN 0 ELSE (num_of_bytes_read/num_of_reads) END AS [Avg Bytes/Read], CASE WHEN io_stall_write_ms = 0 THEN 0 ELSE (num_of_bytes_written/num_of_writes) END AS [Avg Bytes/Write], CASE WHEN (num_of_reads = 0 AND num_of_writes = 0) THEN 0 ELSE ((num_of_bytes_read + num_of_bytes_written)/(num_of_reads + num_of_writes)) END AS [Avg Bytes/Transfer] FROM (SELECT LEFT(mf.physical_name, 2) AS Drive, SUM(num_of_reads) AS num_of_reads, SUM(io_stall_read_ms) AS io_stall_read_ms, SUM(num_of_writes) AS num_of_writes, SUM(io_stall_write_ms) AS io_stall_write_ms, SUM(num_of_bytes_read) AS num_of_bytes_read, SUM(num_of_bytes_written) AS num_of_bytes_written, SUM(io_stall) AS io_stall FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS vfs INNER JOIN sys.master_files AS mf WITH (NOLOCK) ON vfs.database_id = mf.database_id AND vfs.file_id = mf.file_id GROUP BY LEFT(mf.physical_name, 2)) AS tab ORDER BY [Overall Latency] OPTION (RECOMPILE); -- Shows you the drive-level latency for reads and writes, in milliseconds -- Latency above 20-25ms is usually a problem -- Recovery model, log reuse wait description, log file size, log usage size (Query 15) (Database Properties) -- and compatibility level for all databases on instance SELECT db.[name] AS [Database Name], db.recovery_model_desc AS [Recovery Model], db.log_reuse_wait_desc AS [Log Reuse Wait Description], ls.cntr_value AS [Log Size (KB)], lu.cntr_value AS [Log Used (KB)], CAST(CAST(lu.cntr_value AS FLOAT) / CAST(ls.cntr_value AS FLOAT)AS DECIMAL(18,2)) * 100 AS [Log Used %], db.[compatibility_level] AS [DB Compatibility Level], 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.is_cdc_enabled FROM sys.databases AS db WITH (NOLOCK) INNER JOIN sys.dm_os_performance_counters AS lu WITH (NOLOCK) ON db.name = lu.instance_name INNER JOIN sys.dm_os_performance_counters AS ls WITH (NOLOCK) ON db.name = ls.instance_name WHERE lu.counter_name LIKE N'Log File(s) Used Size (KB)%' AND ls.counter_name LIKE N'Log File(s) Size (KB)%' AND ls.cntr_value > 0 OPTION (RECOMPILE); -- Things to look at: -- How many databases are on the instance? -- What recovery models are they using? -- What is the log reuse wait description? -- How full are the transaction logs ? -- What compatibility level are they on? -- What is the Page Verify Option? -- Make sure auto_shrink and auto_close are not enabled! -- Missing Indexes for all databases by Index Advantage (Query 16) (Missing Indexes All Databases) SELECT 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 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 ORDER BY index_advantage DESC OPTION (RECOMPILE); -- Getting missing index information for all of the databases on the instance is very useful -- Look at last user seek time, number of user seeks to help determine source and importance -- Also look at avg_user_impact and avg_total_user_cost to help determine importance -- SQL Server is overly eager to add included columns, so beware -- Do not just blindly add indexes that show up from this query!!! -- Get VLF Counts for all databases on the instance (Query 17) (VLF Counts) -- (adapted from Michelle Ufford) CREATE TABLE #VLFInfo (FileID int, FileSize bigint, StartOffset bigint, FSeqNo bigint, [Status] bigint, Parity bigint, CreateLSN numeric(38)); CREATE TABLE #VLFCountResults(DatabaseName sysname, VLFCount int); EXEC sp_MSforeachdb N'Use [?]; INSERT INTO #VLFInfo EXEC sp_executesql N''DBCC LOGINFO([?])''; INSERT INTO #VLFCountResults SELECT DB_NAME(), COUNT(*) FROM #VLFInfo; TRUNCATE TABLE #VLFInfo;' SELECT DatabaseName, VLFCount FROM #VLFCountResults ORDER BY VLFCount DESC; DROP TABLE #VLFInfo; DROP TABLE #VLFCountResults; -- High VLF counts can affect write performance -- and they can make database restores and recovery take much longer -- Try to keep your VLF counts under 200 in most cases -- Calculates average stalls per read, per write, and per total input/output for each database file (Query 18) (IO Stalls by File) SELECT DB_NAME(fs.database_id) AS [Database Name], CONVERT(DECIMAL(18,2), mf.size/128.0) AS [File Size (MB)], mf.physical_name, io_stall_read_ms, num_of_reads, CAST(io_stall_read_ms/(1.0 + num_of_reads) AS NUMERIC(10,1)) AS [avg_read_stall_ms], io_stall_write_ms, num_of_writes,CAST(io_stall_write_ms/(1.0+num_of_writes) AS NUMERIC(10,1)) AS [avg_write_stall_ms], io_stall_read_ms + io_stall_write_ms AS [io_stalls], num_of_reads + num_of_writes AS [total_io], CAST((io_stall_read_ms + io_stall_write_ms)/(1.0 + num_of_reads + num_of_writes) AS NUMERIC(10,1)) AS [avg_io_stall_ms] FROM sys.dm_io_virtual_file_stats(null,null) AS fs INNER JOIN sys.master_files AS mf WITH (NOLOCK) ON fs.database_id = mf.database_id AND fs.[file_id] = mf.[file_id] 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 -- Get CPU utilization by database (Query 19) (CPU Usage by Database) WITH DB_CPU_Stats AS (SELECT DatabaseID, DB_Name(DatabaseID) AS [Database Name], SUM(total_worker_time) AS [CPU_Time_Ms] FROM sys.dm_exec_query_stats AS qs CROSS APPLY (SELECT CONVERT(int, value) AS [DatabaseID] FROM sys.dm_exec_plan_attributes(qs.plan_handle) WHERE attribute = N'dbid') AS F_DB GROUP BY DatabaseID) SELECT ROW_NUMBER() OVER(ORDER BY [CPU_Time_Ms] DESC) AS [CPU Rank], [Database Name], [CPU_Time_Ms] AS [CPU Time (ms)], CAST([CPU_Time_Ms] * 1.0 / SUM([CPU_Time_Ms]) OVER() * 100.0 AS DECIMAL(5, 2)) AS [CPU Percent] FROM DB_CPU_Stats WHERE DatabaseID <> 32767 -- ResourceDB ORDER BY [CPU Rank] OPTION (RECOMPILE); -- Helps determine which database is using the most CPU resources on the instance -- Get I/O utilization by database (Query 20) (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 io_in_mb FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS [DM_IO_STATS] GROUP BY database_id) SELECT ROW_NUMBER() OVER(ORDER BY io_in_mb DESC) AS [I/O Rank], [Database Name], io_in_mb AS [Total I/O (MB)], CAST(io_in_mb/ SUM(io_in_mb) OVER() * 100.0 AS DECIMAL(5,2)) AS [I/O Percent] 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 21) (Total Buffer Usage by Database) WITH AggregateBufferPoolUsage AS (SELECT DB_NAME(database_id) AS [Database Name], CAST(COUNT(*) * 8/1024.0 AS DECIMAL (10,2)) AS [CachedSize] FROM sys.dm_os_buffer_descriptors WITH (NOLOCK) WHERE database_id > 4 -- system databases AND database_id <> 32767 -- ResourceDB GROUP BY DB_NAME(database_id)) SELECT ROW_NUMBER() OVER(ORDER BY CachedSize DESC) AS [Buffer Pool Rank], [Database Name], CachedSize AS [Cached Size (MB)], CAST(CachedSize / SUM(CachedSize) OVER() * 100.0 AS DECIMAL(5,2)) AS [Buffer Pool Percent] 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 -- Clear Wait Stats -- DBCC SQLPERF('sys.dm_os_wait_stats', CLEAR); -- Isolate top waits for server instance since last restart or statistics clear (Query 22) (Top Waits) WITH Waits AS (SELECT wait_type, wait_time_ms / 1000. AS wait_time_s, 100. * wait_time_ms / SUM(wait_time_ms) OVER() AS pct, ROW_NUMBER() OVER(ORDER BY wait_time_ms DESC) AS rn FROM sys.dm_os_wait_stats WITH (NOLOCK) WHERE wait_type NOT IN (N'CLR_SEMAPHORE',N'LAZYWRITER_SLEEP',N'RESOURCE_QUEUE',N'SLEEP_TASK', N'SLEEP_SYSTEMTASK',N'SQLTRACE_BUFFER_FLUSH',N'WAITFOR', N'LOGMGR_QUEUE',N'CHECKPOINT_QUEUE', N'REQUEST_FOR_DEADLOCK_SEARCH',N'XE_TIMER_EVENT',N'BROKER_TO_FLUSH',N'BROKER_TASK_STOP',N'CLR_MANUAL_EVENT', N'CLR_AUTO_EVENT',N'DISPATCHER_QUEUE_SEMAPHORE', N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'XE_DISPATCHER_WAIT', N'XE_DISPATCHER_JOIN', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', N'ONDEMAND_TASK_QUEUE', N'BROKER_EVENTHANDLER', N'SLEEP_BPOOL_FLUSH')) SELECT W1.wait_type, CAST(W1.wait_time_s AS DECIMAL(12, 2)) AS wait_time_s, CAST(W1.pct AS DECIMAL(12, 2)) AS pct, CAST(SUM(W2.pct) AS DECIMAL(12, 2)) AS running_pct FROM Waits AS W1 INNER JOIN Waits AS W2 ON W2.rn <= W1.rn GROUP BY W1.rn, W1.wait_type, W1.wait_time_s, W1.pct HAVING SUM(W2.pct) - W1.pct < 99 OPTION (RECOMPILE); -- percentage threshold -- The SQL Server Wait Type Repository -- http://blogs.msdn.com/b/psssql/archive/2009/11/03/the-sql-server-wait-type-repository.aspx -- Wait statistics, or please tell me where it hurts -- http://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/ -- SQL Server 2005 Performance Tuning using the Waits and Queues -- http://technet.microsoft.com/en-us/library/cc966413.aspx -- sys.dm_os_wait_stats (Transact-SQL) -- http://msdn.microsoft.com/en-us/library/ms179984(v=sql.100).aspx -- Signal Waits for instance (Query 23) (Signal Waits) SELECT CAST(100.0 * SUM(signal_wait_time_ms) / SUM (wait_time_ms) AS NUMERIC(20,2)) AS [% Signal (CPU) Waits], CAST(100.0 * SUM(wait_time_ms - signal_wait_time_ms) / SUM (wait_time_ms) AS NUMERIC(20,2)) AS [% Resource Waits] FROM sys.dm_os_wait_stats WITH (NOLOCK) OPTION (RECOMPILE); -- Signal Waits above 10-15% is usually a sign of CPU pressure -- Resource waits are non-CPU related waits -- Get logins that are connected and how many sessions they have (Query 24) (Connection Counts) SELECT login_name, [program_name], COUNT(session_id) AS [session_count] FROM sys.dm_exec_sessions WITH (NOLOCK) GROUP BY login_name, [program_name] ORDER BY COUNT(session_id) DESC OPTION (RECOMPILE); -- This can help characterize your workload and -- determine whether you are seeing a normal level of activity -- Get Average Task Counts (run multiple times) (Query 25) (Avg Task Counts) SELECT AVG(current_tasks_count) AS [Avg Task 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 -- High Avg Task Counts are often caused by blocking or other resource contention -- High Avg Runnable Task Counts are a good sign of CPU pressure -- High Avg Pending DiskIO Counts are a sign of disk pressure -- Get CPU Utilization History for last 256 minutes (in one minute intervals) (Query 26) (CPU Utilization History) -- This version works with SQL Server 2008 DECLARE @ts_now bigint = (SELECT cpu_ticks/(cpu_ticks/ms_ticks) FROM sys.dm_os_sys_info WITH (NOLOCK)); SELECT TOP(256) SQLProcessUtilization AS [SQL Server Process CPU Utilization], SystemIdle AS [System Idle Process], 100 - SystemIdle - SQLProcessUtilization AS [Other Process CPU Utilization], DATEADD(ms, -1 * (@ts_now - [timestamp]), GETDATE()) AS [Event Time] FROM ( SELECT record.value('(./Record/@id)[1]', 'int') AS record_id, record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int') AS [SystemIdle], record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int') AS [SQLProcessUtilization], [timestamp] FROM ( SELECT [timestamp], CONVERT(xml, record) AS [record] FROM sys.dm_os_ring_buffers WITH (NOLOCK) WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR' AND record LIKE N'%<SystemHealth>%') AS x ) AS y ORDER BY record_id DESC OPTION (RECOMPILE); -- Look at the trend over the entire period. -- Also look at high sustained Other Process CPU Utilization values -- Good basic information about OS memory amounts and state (Query 27) (System Memory) SELECT total_physical_memory_kb/1024 AS [Physical Memory (MB)], available_physical_memory_kb/1024 AS [Available Memory (MB)], total_page_file_kb/1024 AS [Total Page File (MB)], available_page_file_kb/1024 AS [Available Page File (MB)], system_cache_kb/1024 AS [System Cache (MB)], system_memory_state_desc AS [System Memory State] FROM sys.dm_os_sys_memory WITH (NOLOCK) OPTION (RECOMPILE); -- You want to see "Available physical memory is high" -- This indicates that you are not under external memory pressure -- SQL Server Process Address space info (Query 28) (Process Memory) -- (shows whether locked pages is enabled, among other things) SELECT physical_memory_in_use_kb/1024 AS [SQL Server Memory Usage (MB)], large_page_allocations_kb, locked_page_allocations_kb, page_fault_count, memory_utilization_percentage, available_commit_limit_kb, process_physical_memory_low, process_virtual_memory_low FROM sys.dm_os_process_memory WITH (NOLOCK) OPTION (RECOMPILE); -- You want to see 0 for process_physical_memory_low -- You want to see 0 for process_virtual_memory_low -- This indicates that you are not under internal memory pressure -- Page Life Expectancy (PLE) value for each NUMA node in current instance (Query 29) (PLE by NUMA Node) SELECT @@SERVERNAME AS [Server Name], [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 memory pressure. -- Higher PLE is better. Watch the trend, not the absolute value. -- This will only return one row for non-NUMA systems. -- Memory Grants Pending value for current instance (Query 30) (Memory Grants Pending) SELECT @@SERVERNAME AS [Server Name], [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); -- Memory Grants Pending above zero for a sustained period is a very strong indicator of memory pressure -- Memory Clerk Usage for instance (Query 31) (Memory Clerk Usage) -- Look for high value for CACHESTORE_SQLCP (Ad-hoc query plans) SELECT TOP(10) [type] AS [Memory Clerk Type], SUM(single_pages_kb)/1024 AS [SPA Memory Usage (MB)] FROM sys.dm_os_memory_clerks WITH (NOLOCK) GROUP BY [type] ORDER BY SUM(single_pages_kb) DESC OPTION (RECOMPILE); -- 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 -- 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 32) (Ad hoc Queries) SELECT TOP(50) [text] AS [QueryText], cp.cacheobjtype, cp.objtype, cp.size_in_bytes FROM sys.dm_exec_cached_plans AS cp WITH (NOLOCK) CROSS APPLY sys.dm_exec_sql_text(plan_handle) 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 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 'optimize for ad hoc workloads' for the instance can help (SQL Server 2008 and above only) -- Running DBCC FREESYSTEMCACHE ('SQL Plans') periodically may be required to better control this. -- Enabling forced parameterization for the database can help, but test first! -- Database specific queries ***************************************************************** -- **** Switch to a user database ***** USE YourDatabaseName; GO -- Individual File Sizes and space available for current database (Query 33) (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], [file_id], fg.name AS [Filegroup Name] FROM sys.database_files AS f WITH (NOLOCK) LEFT OUTER JOIN sys.data_spaces AS fg WITH (NOLOCK) ON f.data_space_id = fg.data_space_id OPTION (RECOMPILE); -- Look at how large and how full the files are and where they are located -- Make sure the transaction log is not full!! -- I/O Statistics by file for the current database (Query 34) (IO Stats By File) SELECT DB_NAME(DB_ID()) AS [Database Name], df.name AS [Logical Name], vfs.[file_id], df.physical_name AS [Physical Name], 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 -- Top cached queries by Execution Count (SQL Server 2008) (Query 35) (Query Execution Counts) SELECT TOP (100) qs.execution_count, qs.total_worker_time, qs.total_logical_reads, qs.total_elapsed_time, SUBSTRING(qt.TEXT,qs.statement_start_offset/2 +1, (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 ORDER BY qs.execution_count DESC OPTION (RECOMPILE); -- Look at non-stored procedure queries -- Top Cached SPs By Execution Count (SQL 2008) (Query 36) (SP Execution Counts) SELECT TOP(100) p.name AS [SP Name], 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], qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time], qs.cached_time 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] WHERE qs.database_id = DB_ID() 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 (SQL 2008) (Query 37) (SP Avg Elapsed Time) SELECT TOP(25) p.name AS [SP Name], qs.total_elapsed_time/qs.execution_count AS [avg_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], qs.cached_time 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] WHERE qs.database_id = DB_ID() ORDER BY avg_elapsed_time DESC OPTION (RECOMPILE); -- This helps you find long-running cached stored procedures that -- may be easy to optimize with standard query tuning techniques -- Top Cached SPs By Avg Elapsed Time with execution time variability (Query 38) (SP Avg Elapsed Variable Time) SELECT TOP(25) p.name AS [SP Name], qs.execution_count, qs.min_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time], qs.max_elapsed_time, qs.last_elapsed_time, qs.cached_time 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] WHERE qs.database_id = DB_ID() ORDER BY avg_elapsed_time DESC OPTION (RECOMPILE); -- This gives you some interesting information about the variability in the -- execution time of your cached stored procedures, which is useful for tuning -- Top Cached SPs By Total Worker time (SQL 2008). Worker time relates to CPU cost (Query 39) (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], qs.cached_time 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] WHERE qs.database_id = DB_ID() 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 (SQL 2008). Logical reads relate to memory pressure (Query 40) (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], qs.cached_time 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] WHERE qs.database_id = DB_ID() 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 (SQL 2008). Physical reads relate to disk I/O pressure (Query 41) (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], qs.cached_time 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] 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 (SQL 2008) (Query 42) (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], qs.cached_time 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] WHERE qs.database_id = DB_ID() AND qs.total_logical_writes > 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 43) (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 44) (Bad NC Indexes) SELECT 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, user_updates AS [Total Writes], user_seeks + user_scans + user_lookups AS [Total Reads], user_updates - (user_seeks + user_scans + 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 WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1 AND s.database_id = DB_ID() AND user_updates > (user_seeks + user_scans + user_lookups) AND i.index_id > 1 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 45) (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() -- Remove this to see for entire instance ORDER BY index_advantage DESC OPTION (RECOMPILE); -- Look at 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 46) (Missing Index Warnings) -- Note: This query could take some time on a busy instance SELECT TOP(25) OBJECT_NAME(objectid) AS [ObjectName], query_plan, cp.objtype, cp.usecounts 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 -- 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 47) (Buffer Usage) -- Note: This query could take some time on a busy instance SELECT 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 WHERE b.database_id = CONVERT(int,DB_ID()) AND p.[object_id] > 100 GROUP BY 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 48) (Table Sizes) SELECT OBJECT_NAME(object_id) AS [ObjectName], SUM(Rows) AS [RowCount], data_compression_desc AS [CompressionType] FROM sys.partitions WITH (NOLOCK) WHERE index_id < 2 --ignore the partitions from the non-clustered index if any AND OBJECT_NAME(object_id) NOT LIKE N'sys%' AND OBJECT_NAME(object_id) NOT LIKE N'queue_%' AND OBJECT_NAME(object_id) NOT LIKE N'filestream_tombstone%' AND OBJECT_NAME(object_id) NOT LIKE N'fulltext%' AND OBJECT_NAME(object_id) NOT LIKE N'ifts_comp_fragment%' AND OBJECT_NAME(object_id) NOT LIKE N'xml_index_nodes%' GROUP BY object_id, data_compression_desc ORDER BY SUM(Rows) DESC OPTION (RECOMPILE); -- Gives you an idea of table sizes, and possible data compression opportunities -- Get some key table properties (Query 49) (Table Properties) SELECT [name], create_date, lock_on_bulk_load, is_replicated, has_replication_filter, is_tracked_by_cdc, lock_escalation_desc FROM sys.tables WITH (NOLOCK) ORDER BY [name] OPTION (RECOMPILE); -- Gives you some good information about your tables -- When were Statistics last updated on all indexes? (Query 50) (Statistics Update) SELECT o.name, 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, 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] = 'U' ORDER BY STATS_DATE(i.[object_id], i.index_id) ASC OPTION (RECOMPILE); -- Helps discover possible problems with out-of-date statistics -- Also gives you an idea which indexes are the most active -- Get fragmentation info for all indexes above a certain size in the current database (Query 51) (Index Fragmentation) -- Note: This could take some time on a very large database SELECT DB_NAME(ps.database_id) AS [Database 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 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 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 52) (Overall Index Usage - Reads) SELECT OBJECT_NAME(s.[object_id]) AS [ObjectName], i.name AS [IndexName], i.index_id, user_seeks + user_scans + user_lookups AS [Reads], s.user_updates AS [Writes], i.type_desc AS [IndexType], i.fill_factor AS [FillFactor], i.has_filter, i.filter_definition, s.last_user_scan, s.last_user_lookup, s.last_user_seek 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] WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1 AND i.index_id = s.index_id AND s.database_id = DB_ID() ORDER BY user_seeks + user_scans + 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 53) (Overall Index Usage - Writes) SELECT OBJECT_NAME(s.[object_id]) AS [ObjectName], i.name AS [IndexName], i.index_id, s.user_updates AS [Writes], user_seeks + user_scans + user_lookups AS [Reads], i.type_desc AS [IndexType], i.fill_factor AS [FillFactor], i.has_filter, i.filter_definition, s.last_system_update, s.last_user_update 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] WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1 AND i.index_id = s.index_id AND s.database_id = DB_ID() ORDER BY s.user_updates DESC OPTION (RECOMPILE); -- Order by writes -- Show which indexes in the current database are most active for Writes -- Look at recent Full backups for the current database (Query 54) (Recent Full Backups) SELECT TOP (30) bs.machine_name, bs.server_name, bs.database_name AS [Database Name], bs.recovery_model, CONVERT (BIGINT, bs.backup_size / 1048576 ) AS [Uncompressed Backup Size (MB)], CONVERT (BIGINT, bs.compressed_backup_size / 1048576 ) AS [Compressed Backup Size (MB)], CONVERT (NUMERIC (20,2), (CONVERT (FLOAT, bs.backup_size) / CONVERT (FLOAT, bs.compressed_backup_size))) AS [Compression Ratio], DATEDIFF (SECOND, bs.backup_start_date, bs.backup_finish_date) AS [Backup Elapsed Time (sec)], bs.backup_finish_date AS [Backup Finish Date] FROM msdb.dbo.backupset AS bs WITH (NOLOCK) WHERE DATEDIFF (SECOND, bs.backup_start_date, bs.backup_finish_date) > 0 AND bs.backup_size > 0 AND bs.type = 'D' -- Change to L if you want Log backups AND database_name = DB_NAME(DB_ID()) ORDER BY bs.backup_finish_date DESC OPTION (RECOMPILE); -- Are your backup sizes and times changing over time? -- Get the average full backup size by month for the current database (SQL 2008) (Query 55) (Database Size History) -- This helps you understand your database growth over time -- Adapted from Erin Stellato SELECT [database_name] AS [Database], DATEPART(month,[backup_start_date]) AS [Month], CAST(AVG([backup_size]/1024/1024) AS DECIMAL(15,2)) AS [Backup Size (MB)], CAST(AVG([compressed_backup_size]/1024/1024) AS DECIMAL(15,2)) AS [Compressed Backup Size (MB)], CAST(AVG([backup_size]/[compressed_backup_size]) AS DECIMAL(15,2)) AS [Compression Ratio] FROM msdb.dbo.backupset WITH (NOLOCK) WHERE [database_name] = DB_NAME(DB_ID()) AND [type] = 'D' AND backup_start_date >= DATEADD(MONTH, -12, GETDATE()) GROUP BY [database_name],DATEPART(mm,[backup_start_date]) OPTION (RECOMPILE); -- The Backup Size (MB) (without backup compression) shows the true size of your database over time -- This helps you track and plan your data size growth -- It is possible that your data files may be larger on disk due to empty space within those files |
– Helps discover possible problems with out-of-date statistics
– Also gives you an idea which indexes are most active