运维联盟俱乐部

 找回密码
 立即注册
查看: 2460|回复: 0

sqlserver_sheck.sql 微软官方巡检脚本

[复制链接]
  • TA的每日心情
    开心
    2023-8-9 11:05
  • 发表于 2020-1-16 15:16:49 | 显示全部楼层 |阅读模式
    1. -- SQL Server 2012 Diagnostic Information Queries
    2. -- Glenn Berry
    3. -- April 2015
    4. -- Last Modified: April 27, 2015
    5. -- http://sqlserverperformance.wordpress.com/
    6. -- http://sqlskills.com/blogs/glenn/
    7. -- Twitter: GlennAlanBerry

    8. -- Please listen to my Pluralsight courses
    9. -- http://www.pluralsight.com/author/glenn-berry

    10. -- Many of these queries will not work if you have databases in 80 compatibility mode
    11. -- Please make sure you are using the correct version of these diagnostic queries for your version of SQL Server

    12. --******************************************************************************
    13. --*   Copyright (C) 2015 Glenn Berry, SQLskills.com
    14. --*   All rights reserved.
    15. --*
    16. --*   For more scripts and sample code, check out
    17. --*      http://sqlskills.com/blogs/glenn
    18. --*
    19. --*   You may alter this code for your own *non-commercial* purposes. You may
    20. --*   republish altered code as long as you include this copyright and give due credit.
    21. --*
    22. --*
    23. --*   THIS CODE AND INFORMATION ARE PROVIDED "AS IS" WITHOUT WARRANTY OF
    24. --*   ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED
    25. --*   TO THE IMPLIED WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A
    26. --*   PARTICULAR PURPOSE.
    27. --*
    28. --******************************************************************************

    29. -- Check the major product version to see if it is SQL Server 2012
    30. IF NOT EXISTS (SELECT * WHERE CONVERT(varchar(128), SERVERPROPERTY('ProductVersion')) LIKE '11%')
    31.     BEGIN
    32.         DECLARE @ProductVersion varchar(128) = CONVERT(varchar(128), SERVERPROPERTY('ProductVersion'));
    33.         RAISERROR ('Script does not match the ProductVersion [%s] of this instance. Many of these queries may not work on this version.' , 18 , 16 , @ProductVersion);
    34.     END
    35.     ELSE
    36.         PRINT N'You have the correct major version of SQL Server for this diagnostic information script';

    37. -- Instance level queries *******************************

    38. -- SQL and OS Version information for current instance  (Query 1) (Version Info)
    39. SELECT @@SERVERNAME AS [Server Name], @@VERSION AS [SQL Server and OS Version Info];

    40. -- SQL Server 2012 RTM Branch Builds                        SQL Server 2012 SP1 Branch Builds                    SQL Server 2012 SP2 Branch Builds
    41. -- Build            Description            Release Date        Build            Description        Release Date        Build            Description            Release Date
    42. -- 11.0.2100        RTM                      3/6/2012
    43. -- 11.0.2316        RTM CU1                 4/12/2012
    44. -- 11.0.2325        RTM CU2                 6/18/2012 -->        11.0.3000        SP1 RTM            11/7/2012
    45. -- 11.0.2332        RTM CU3                 8/31/2012
    46. -- 11.0.2376        RTM CU3 + QFE         10/9/2012
    47. -- 11.0.2383        RTM CU4                10/15/2012 -->        11.0.3321        SP1 CU1            11/20/2012
    48. -- 11.0.2395        RTM CU5                12/17/2012 -->      11.0.3339        SP1 CU2            1/21/2013
    49. -- 11.0.2401        RTM CU6              2/18/2013 -->      11.0.3349       SP1 CU3            3/18/2013
    50. -- 11.0.2405        RTM CU7              4/15/2013 -->      11.0 3368       SP1 CU4         5/30/2013
    51. -- 11.0.2410        RTM CU8              6/17/2013 -->      11.0.3373       SP1 CU5         7/15/2013
    52. -- 11.0.2419        RTM CU9              8/20/2013 -->      11.0.3381        SP1 CU6            9/16/2013
    53. -- 11.0.2420        RTM CU10            10/21/2013 -->        11.0.3393       SP1 CU7         11/18/2013
    54. -- 11.0.2424        RTM CU11            12/16/2003 -->      11.0.3401       SP1 CU8         1/20/2014
    55. --                                                          11.0.3412       SP1 CU9         3/17/2014 -->        11.0.5058        SP2 RTM                6/10/2014
    56. --                                                          11.0.3431       SP1 CU10        5/19/2014
    57. --                                                          11.0.3449       SP1 CU11        7/21/2014 -->        11.0.5532        SP2 CU1                7/23/2014
    58. --                                                          11.0.3470       SP1 CU12        9/15/2014 -->       11.0.5548       SP2 CU2             9/15/2014
    59. --                                                          11.0.3482        SP1 CU13        11/17/2014-->       11.0.5556        SP2 CU3            11/17/2014
    60. --                                                          11.0.3486       SP1 CU14        1/19/2015 -->       11.0.5569       SP2 CU4             1/19/2015
    61. --                                                                                                              11.0.5571       SP2 CU4 + COD HF     2/4/2015  (this includes the AlwaysOn AG hotfix that is in SP2 CU5)
    62. --                                                          11.0.3487        SP1 CU15        3/16/2015           11.0.5582       SP2 CU5             3/16/2015

    63. -- The SQL Server 2012 builds that were released after SQL Server 2012 was released
    64. -- http://support.microsoft.com/kb/2692828

    65. -- The SQL Server 2012 builds that were released after SQL Server 2012 Service Pack 1 was released
    66. -- http://support.microsoft.com/kb/2772858

    67. -- SQL Server 2012 SP2 build versions (new format for the build list KB article)
    68. -- http://support.microsoft.com/kb/2983249

    69. -- Recommended updates and configuration options for SQL Server 2012 and SQL Server 2014 used with high-performance workloads
    70. -- http://support.microsoft.com/kb/2964518/EN-US

    71. -- Performance and Stability Related Fixes in Post-SQL Server 2012 SP2 Builds
    72. -- http://www.sqlskills.com/blogs/glenn/performance-and-stability-related-fixes-in-post-sql-server-2012-sp2-builds/


    73. -- When was SQL Server installed  (Query 2) (SQL Server Install Date)  
    74. SELECT @@SERVERNAME AS [Server Name], create_date AS [SQL Server Install Date]
    75. FROM sys.server_principals WITH (NOLOCK)
    76. WHERE name = N'NT AUTHORITY\SYSTEM'
    77. OR name = N'NT AUTHORITY\NETWORK SERVICE' OPTION (RECOMPILE);

    78. -- Tells you the date and time that SQL Server was installed
    79. -- It is a good idea to know how old your instance is


    80. -- Get selected server properties (SQL Server 2012)  (Query 3) (Server Properties)
    81. SELECT SERVERPROPERTY('MachineName') AS [MachineName], SERVERPROPERTY('ServerName') AS [ServerName],  
    82. SERVERPROPERTY('InstanceName') AS [Instance], SERVERPROPERTY('IsClustered') AS [IsClustered],
    83. SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS [ComputerNamePhysicalNetBIOS],
    84. SERVERPROPERTY('Edition') AS [Edition], SERVERPROPERTY('ProductLevel') AS [ProductLevel],
    85. SERVERPROPERTY('ProductVersion') AS [ProductVersion], SERVERPROPERTY('ProcessID') AS [ProcessID],
    86. SERVERPROPERTY('Collation') AS [Collation], SERVERPROPERTY('IsFullTextInstalled') AS [IsFullTextInstalled],
    87. SERVERPROPERTY('IsIntegratedSecurityOnly') AS [IsIntegratedSecurityOnly],
    88. SERVERPROPERTY('IsHadrEnabled') AS [IsHadrEnabled], SERVERPROPERTY('HadrManagerStatus') AS [HadrManagerStatus];

    89. -- This gives you a lot of useful information about your instance of SQL Server,
    90. -- such as the ProcessID for SQL Server and your collation
    91. -- The last two columns are new for SQL Server 2012


    92. -- Get SQL Server Agent jobs and Category information (Query 4) (SQL Server Agent Jobs)
    93. SELECT sj.name AS [JobName], sj.[description] AS [JobDescription], SUSER_SNAME(sj.owner_sid) AS [JobOwner],
    94. sj.date_created, sj.[enabled], sj.notify_email_operator_id, sj.notify_level_email, sc.name AS [CategoryName],
    95. js.next_run_date, js.next_run_time
    96. FROM msdb.dbo.sysjobs AS sj WITH (NOLOCK)
    97. INNER JOIN msdb.dbo.syscategories AS sc WITH (NOLOCK)
    98. ON sj.category_id = sc.category_id
    99. LEFT OUTER JOIN msdb.dbo.sysjobschedules AS js WITH (NOLOCK)
    100. ON sj.job_id = js.job_id
    101. ORDER BY sj.name OPTION (RECOMPILE);

    102. -- Gives you some basic information about your SQL Server Agent jobs, who owns them and how they are configured
    103. -- Look for Agent jobs that are not owned by sa
    104. -- Look for jobs that have a notify_email_operator_id set to 0 (meaning no operator)
    105. -- Look for jobs that have a notify_level_email set to 0 (meaning no e-mail is ever sent)
    106. --
    107. -- MSDN sysjobs documentation
    108. -- http://msdn.microsoft.com/en-us/library/ms189817.aspx


    109. -- Get SQL Server Agent Alert Information (Query 5) (SQL Server Agent Alerts)
    110. SELECT name, event_source, message_id, severity, [enabled], has_notification,
    111.        delay_between_responses, occurrence_count, last_occurrence_date, last_occurrence_time
    112. FROM msdb.dbo.sysalerts WITH (NOLOCK)
    113. ORDER BY name OPTION (RECOMPILE);

    114. -- Gives you some basic information about your SQL Server Agent Alerts (which are different from SQL Server Agent jobs)
    115. -- Read more about Agent Alerts here: http://www.sqlskills.com/blogs/glenn/creating-sql-server-agent-alerts-for-critical-errors/


    116. -- Returns a list of all global trace flags that are enabled (Query 6) (Global Trace Flags)
    117. DBCC TRACESTATUS (-1);

    118. -- If no global trace flags are enabled, no results will be returned.
    119. -- It is very useful to know what global trace flags are currently enabled as part of the diagnostic process.

    120. -- Common trace flags that should be enabled in most cases
    121. -- TF 3226 - Supresses logging of successful database backup messages to the SQL Server Error Log
    122. -- TF 1118 - Helps alleviate allocation contention in tempdb, SQL Server allocates full extents to each database object,
    123. --           thereby eliminating the contention on SGAM pages (more important with older versions of SQL Server)
    124. --           Recommendations to reduce allocation contention in SQL Server tempdb database
    125. --           http://support2.microsoft.com/kb/2154845


    126. -- Windows information (SQL Server 2012)  (Query 7) (Windows Info)
    127. SELECT windows_release, windows_service_pack_level,
    128.        windows_sku, os_language_version
    129. FROM sys.dm_os_windows_info WITH (NOLOCK) OPTION (RECOMPILE);

    130. -- Gives you major OS version, Service Pack, Edition, and language info for the operating system
    131. -- 6.3 is either Windows 8.1 or Windows Server 2012 R2
    132. -- 6.2 is either Windows 8 or Windows Server 2012
    133. -- 6.1 is either Windows 7 or Windows Server 2008 R2
    134. -- 6.0 is either Windows Vista or Windows Server 2008

    135. -- Windows SKU codes
    136. -- 4 is Enterprise Edition
    137. -- 7 is Standard Server Edition
    138. -- 8 is Datacenter Server Edition
    139. -- 10 is Enterprise Server Edition
    140. -- 48 is Professional Edition

    141. -- 1033 for os_language_version is US-English

    142. -- SQL Server 2012 requires Windows Server 2008 SP2 or newer

    143. -- Hardware and Software Requirements for Installing SQL Server 2012
    144. -- http://msdn.microsoft.com/en-us/library/ms143506.aspx

    145. -- Using SQL Server in Windows 8, Windows 8.1, Windows Server 2012 and Windows Server 2012 R2 environments
    146. -- http://support.microsoft.com/kb/2681562



    147. -- SQL Server Services information (SQL Server 2012) (Query 8) (SQL Server Services Info)
    148. SELECT servicename, process_id, startup_type_desc, status_desc,
    149. last_startup_time, service_account, is_clustered, cluster_nodename, [filename]
    150. FROM sys.dm_server_services WITH (NOLOCK) OPTION (RECOMPILE);

    151. -- Tells you the account being used for the SQL Server Service and the SQL Agent Service
    152. -- Shows the processid, when they were last started, and their current status
    153. -- Shows whether you are running on a failover cluster instance


    154. -- SQL Server NUMA Node information  (Query 9) (SQL Server NUMA Info)
    155. SELECT node_id, node_state_desc, memory_node_id, processor_group, online_scheduler_count,
    156.        active_worker_count, avg_load_balance, resource_monitor_state
    157. FROM sys.dm_os_nodes WITH (NOLOCK)
    158. WHERE node_state_desc <> N'ONLINE DAC' OPTION (RECOMPILE);

    159. -- Gives you some useful information about the composition and relative load on your NUMA nodes
    160. -- You want to see an equal number of schedulers on each NUMA node


    161. -- Hardware information from SQL Server 2012  (Query 10) (Hardware Info)
    162. -- (Cannot distinguish between HT and multi-core)
    163. SELECT cpu_count AS [Logical CPU Count], scheduler_count, hyperthread_ratio AS [Hyperthread Ratio],
    164. cpu_count/hyperthread_ratio AS [Physical CPU Count],
    165. physical_memory_kb/1024 AS [Physical Memory (MB)], committed_kb/1024 AS [Committed Memory (MB)],
    166. committed_target_kb/1024 AS [Committed Target Memory (MB)],
    167. max_workers_count AS [Max Workers Count], affinity_type_desc AS [Affinity Type],
    168. sqlserver_start_time AS [SQL Server Start Time], virtual_machine_type_desc AS [Virtual Machine Type]  
    169. FROM sys.dm_os_sys_info WITH (NOLOCK) OPTION (RECOMPILE);

    170. -- Gives you some good basic hardware information about your database server
    171. -- Note: virtual_machine_type_desc of HYPERVISOR does not automatically mean you are running SQL Server inside of a VM
    172. -- It merely indicates that you have a hypervisor running on your host


    173. -- Get System Manufacturer and model number from  (Query 11) (System Manufacturer)
    174. -- SQL Server Error log. This query might take a few seconds
    175. -- if you have not recycled your error log recently
    176. EXEC sys.xp_readerrorlog 0, 1, N'Manufacturer';

    177. -- This can help you determine the capabilities
    178. -- and capacities of your database server

    179. -- Get socket, physical core and logical core count from (Query 12) (Core Counts)
    180. -- SQL Server Error log. This query might take a few seconds
    181. -- if you have not recycled your error log recently
    182. EXEC sys.xp_readerrorlog 0, 1, N'detected', N'socket';

    183. -- This can help you determine the exact core counts used by SQL Server and whether HT is enabled or not
    184. -- It can also help you confirm your SQL Server licensing model
    185. -- Be on the lookout for this message "using 20 logical processors based on SQL Server licensing" which means grandfathered Server/CAL licensing
    186. -- Note: If you recycle your error logs frequently and your instance has been running long enough,
    187. -- this query may not return any results, since the original startup information from the first error log
    188. -- when SQL Server was last started will have been overwritten


    189. -- Get processor description from Windows Registry  (Query 13) (Processor Description)
    190. EXEC sys.xp_instance_regread N'HKEY_LOCAL_MACHINE', N'HARDWARE\DESCRIPTION\System\CentralProcessor\0', N'ProcessorNameString';

    191. -- Gives you the model number and rated clock speed of your processor(s)
    192. -- Your processors may be running at less that the rated clock speed due
    193. -- to the Windows Power Plan or hardware power management


    194. -- You can skip the next four queries if you know you don't
    195. -- have a clustered instance

    196. -- Shows you where the SQL Server failover cluster diagnostic log is located and how it is configured  (Query 14) (SQL Server Error Log)
    197. SELECT is_enabled, [path], max_size, max_files
    198. FROM sys.dm_os_server_diagnostics_log_configurations WITH (NOLOCK) OPTION (RECOMPILE);

    199. -- Knowing this information is important for troubleshooting purposes
    200. -- Also shows you the location of other error and diagnostic log files


    201. -- Get information about your OS cluster (if your database server is in a cluster)  (Query 15) (Cluster Properties)
    202. SELECT VerboseLogging, SqlDumperDumpFlags, SqlDumperDumpPath,
    203.        SqlDumperDumpTimeOut, FailureConditionLevel, HealthCheckTimeout
    204. FROM sys.dm_os_cluster_properties WITH (NOLOCK) OPTION (RECOMPILE);

    205. -- You will see no results if your instance is not clustered


    206. -- Get information about your cluster nodes and their status  (Query 16) (Cluster Node Properties)
    207. -- (if your database server is in a failover cluster)
    208. SELECT NodeName, status_description, is_current_owner
    209. FROM sys.dm_os_cluster_nodes WITH (NOLOCK) OPTION (RECOMPILE);

    210. -- Knowing which node owns the cluster resources is critical
    211. -- Especially when you are installing Windows or SQL Server updates
    212. -- You will see no results if your instance is not clustered


    213. -- Get information about any AlwaysOn AG cluster this instance is a part of (Query 17) (AlwaysOn AG Cluster)
    214. SELECT cluster_name, quorum_type_desc, quorum_state_desc
    215. FROM sys.dm_hadr_cluster WITH (NOLOCK) OPTION (RECOMPILE);

    216. -- You will see no results if your instance is not using AlwaysOn AGs

    217. -- Recommended hotfixes and updates for Windows Server 2012 R2-based failover clusters
    218. -- http://support.microsoft.com/kb/2920151


    219. -- Get configuration values for instance  (Query 18) (Configuration Values)
    220. SELECT name, value, value_in_use, minimum, maximum, [description], is_dynamic, is_advanced
    221. FROM sys.configurations WITH (NOLOCK)
    222. ORDER BY name OPTION (RECOMPILE);

    223. -- Focus on these settings:
    224. -- backup compression default (should be 1 in most cases)
    225. -- clr enabled (only enable if it is needed)
    226. -- cost threshold for parallelism (depends on your workload)
    227. -- lightweight pooling (should be zero)
    228. -- max degree of parallelism (depends on your workload)
    229. -- max server memory (MB) (set to an appropriate value, not the default)
    230. -- optimize for ad hoc workloads (should be 1)
    231. -- priority boost (should be zero)
    232. -- remote admin connections (should be 1)



    233. -- Get information about TCP Listener for SQL Server  (Query 19) (TCP Listener States)
    234. SELECT listener_id, ip_address, is_ipv4, port, type_desc, state_desc, start_time
    235. FROM sys.dm_tcp_listener_states WITH (NOLOCK)
    236. ORDER BY listener_id OPTION (RECOMPILE);

    237. -- Helpful for network and connectivity troubleshooting



    238. -- Get information on location, time and size of any memory dumps from SQL Server  (Query 20) (Memory Dump Info)
    239. SELECT [filename], creation_time, size_in_bytes/1048576.0 AS [Size (MB)]
    240. FROM sys.dm_server_memory_dumps WITH (NOLOCK)
    241. ORDER BY creation_time DESC OPTION (RECOMPILE);

    242. -- This will not return any rows if you have
    243. -- not had any memory dumps (which is a good thing)


    244. -- File names and paths for TempDB and all user databases in instance  (Query 21) (Database Filenames and Paths)
    245. SELECT DB_NAME([database_id]) AS [Database Name],
    246.        [file_id], name, physical_name, type_desc, state_desc,
    247.        is_percent_growth, growth,
    248.        CONVERT(bigint, growth/128.0) AS [Growth in MB],
    249.        CONVERT(bigint, size/128.0) AS [Total Size in MB]
    250. FROM sys.master_files WITH (NOLOCK)
    251. WHERE [database_id] > 4
    252. AND [database_id] <> 32767
    253. OR [database_id] = 2
    254. ORDER BY DB_NAME([database_id]) OPTION (RECOMPILE);

    255. -- Things to look at:
    256. -- Are data files and log files on different drives?
    257. -- Is everything on the C: drive?
    258. -- Is TempDB on dedicated drives?
    259. -- Is there only one TempDB data file?
    260. -- Are all of the TempDB data files the same size?
    261. -- Are there multiple data files for user databases?
    262. -- Is percent growth enabled for any files (which is bad)?


    263. -- Volume info for all LUNS that have database files on the current instance (Query 22) (Volume Info)
    264. SELECT DISTINCT vs.volume_mount_point, vs.file_system_type,
    265. vs.logical_volume_name, CONVERT(DECIMAL(18,2),vs.total_bytes/1073741824.0) AS [Total Size (GB)],
    266. CONVERT(DECIMAL(18,2),vs.available_bytes/1073741824.0) AS [Available Size (GB)],  
    267. CAST(CAST(vs.available_bytes AS FLOAT)/ CAST(vs.total_bytes AS FLOAT) AS DECIMAL(18,2)) * 100 AS [Space Free %]
    268. FROM sys.master_files AS f WITH (NOLOCK)
    269. CROSS APPLY sys.dm_os_volume_stats(f.database_id, f.[file_id]) AS vs OPTION (RECOMPILE);

    270. --Shows you the total and free space on the LUNs where you have database files


    271. -- Look for I/O requests taking longer than 15 seconds in the five most recent SQL Server Error Logs (Query 23) (IO Warnings)
    272. CREATE TABLE #IOWarningResults(LogDate datetime, ProcessInfo sysname, LogText nvarchar(1000));

    273.     INSERT INTO #IOWarningResults
    274.     EXEC xp_readerrorlog 0, 1, N'taking longer than 15 seconds';

    275.     INSERT INTO #IOWarningResults
    276.     EXEC xp_readerrorlog 1, 1, N'taking longer than 15 seconds';

    277.     INSERT INTO #IOWarningResults
    278.     EXEC xp_readerrorlog 2, 1, N'taking longer than 15 seconds';

    279.     INSERT INTO #IOWarningResults
    280.     EXEC xp_readerrorlog 3, 1, N'taking longer than 15 seconds';

    281.     INSERT INTO #IOWarningResults
    282.     EXEC xp_readerrorlog 4, 1, N'taking longer than 15 seconds';

    283. SELECT LogDate, ProcessInfo, LogText
    284. FROM #IOWarningResults
    285. ORDER BY LogDate DESC;

    286. DROP TABLE #IOWarningResults;  

    287. -- Finding 15 second I/O warnings in the SQL Server Error Log is useful evidence of
    288. -- poor I/O performance (which might have many different causes)


    289. -- Drive level latency information (Query 24) (Drive Level Latency)
    290. -- Based on code from Jimmy May
    291. SELECT tab.[Drive], tab.volume_mount_point AS [Volume Mount Point],
    292.     CASE
    293.         WHEN num_of_reads = 0 THEN 0
    294.         ELSE (io_stall_read_ms/num_of_reads)
    295.     END AS [Read Latency],
    296.     CASE
    297.         WHEN io_stall_write_ms = 0 THEN 0
    298.         ELSE (io_stall_write_ms/num_of_writes)
    299.     END AS [Write Latency],
    300.     CASE
    301.         WHEN (num_of_reads = 0 AND num_of_writes = 0) THEN 0
    302.         ELSE (io_stall/(num_of_reads + num_of_writes))
    303.     END AS [Overall Latency],
    304.     CASE
    305.         WHEN num_of_reads = 0 THEN 0
    306.         ELSE (num_of_bytes_read/num_of_reads)
    307.     END AS [Avg Bytes/Read],
    308.     CASE
    309.         WHEN io_stall_write_ms = 0 THEN 0
    310.         ELSE (num_of_bytes_written/num_of_writes)
    311.     END AS [Avg Bytes/Write],
    312.     CASE
    313.         WHEN (num_of_reads = 0 AND num_of_writes = 0) THEN 0
    314.         ELSE ((num_of_bytes_read + num_of_bytes_written)/(num_of_reads + num_of_writes))
    315.     END AS [Avg Bytes/Transfer]
    316. FROM (SELECT LEFT(UPPER(mf.physical_name), 2) AS Drive, SUM(num_of_reads) AS num_of_reads,
    317.              SUM(io_stall_read_ms) AS io_stall_read_ms, SUM(num_of_writes) AS num_of_writes,
    318.              SUM(io_stall_write_ms) AS io_stall_write_ms, SUM(num_of_bytes_read) AS num_of_bytes_read,
    319.              SUM(num_of_bytes_written) AS num_of_bytes_written, SUM(io_stall) AS io_stall, vs.volume_mount_point
    320.       FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS vfs
    321.       INNER JOIN sys.master_files AS mf WITH (NOLOCK)
    322.       ON vfs.database_id = mf.database_id AND vfs.file_id = mf.file_id
    323.       CROSS APPLY sys.dm_os_volume_stats(mf.database_id, mf.[file_id]) AS vs
    324.       GROUP BY LEFT(UPPER(mf.physical_name), 2), vs.volume_mount_point) AS tab
    325. ORDER BY [Overall Latency] OPTION (RECOMPILE);

    326. -- Shows you the drive-level latency for reads and writes, in milliseconds
    327. -- Latency above 20-25ms is usually a problem


    328. -- Calculates average stalls per read, per write, and per total input/output for each database file  (Query 25) (IO Stalls by File)
    329. SELECT DB_NAME(fs.database_id) AS [Database Name], CAST(fs.io_stall_read_ms/(1.0 + fs.num_of_reads) AS NUMERIC(10,1)) AS [avg_read_stall_ms],
    330. CAST(fs.io_stall_write_ms/(1.0 + fs.num_of_writes) AS NUMERIC(10,1)) AS [avg_write_stall_ms],
    331. CAST((fs.io_stall_read_ms + fs.io_stall_write_ms)/(1.0 + fs.num_of_reads + fs.num_of_writes) AS NUMERIC(10,1)) AS [avg_io_stall_ms],
    332. CONVERT(DECIMAL(18,2), mf.size/128.0) AS [File Size (MB)], mf.physical_name, mf.type_desc, fs.io_stall_read_ms, fs.num_of_reads,
    333. 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]
    334. FROM sys.dm_io_virtual_file_stats(null,null) AS fs
    335. INNER JOIN sys.master_files AS mf WITH (NOLOCK)
    336. ON fs.database_id = mf.database_id
    337. AND fs.[file_id] = mf.[file_id]
    338. ORDER BY avg_io_stall_ms DESC OPTION (RECOMPILE);

    339. -- Helps determine which database files on the entire instance have the most I/O bottlenecks
    340. -- This can help you decide whether certain LUNs are overloaded and whether you might
    341. -- want to move some files to a different location or perhaps improve your I/O performance


    342. -- Recovery model, log reuse wait description, log file size, log usage size  (Query 26) (Database Properties)
    343. -- and compatibility level for all databases on instance
    344. SELECT db.[name] AS [Database Name], db.recovery_model_desc AS [Recovery Model], db.state_desc,
    345. db.log_reuse_wait_desc AS [Log Reuse Wait Description],
    346. CONVERT(DECIMAL(18,2), ls.cntr_value/1024.0) AS [Log Size (MB)], CONVERT(DECIMAL(18,2), lu.cntr_value/1024.0) AS [Log Used (MB)],
    347. CAST(CAST(lu.cntr_value AS FLOAT) / CAST(ls.cntr_value AS FLOAT)AS DECIMAL(18,2)) * 100 AS [Log Used %],
    348. db.[compatibility_level] AS [DB Compatibility Level],
    349. db.page_verify_option_desc AS [Page Verify Option], db.is_auto_create_stats_on, db.is_auto_update_stats_on,
    350. db.is_auto_update_stats_async_on, db.is_parameterization_forced,
    351. db.snapshot_isolation_state_desc, db.is_read_committed_snapshot_on,
    352. db.is_auto_close_on, db.is_auto_shrink_on, db.target_recovery_time_in_seconds, db.is_cdc_enabled
    353. FROM sys.databases AS db WITH (NOLOCK)
    354. INNER JOIN sys.dm_os_performance_counters AS lu WITH (NOLOCK)
    355. ON db.name = lu.instance_name
    356. INNER JOIN sys.dm_os_performance_counters AS ls WITH (NOLOCK)
    357. ON db.name = ls.instance_name
    358. WHERE lu.counter_name LIKE N'Log File(s) Used Size (KB)%'
    359. AND ls.counter_name LIKE N'Log File(s) Size (KB)%'
    360. AND ls.cntr_value > 0 OPTION (RECOMPILE);

    361. -- Things to look at:
    362. -- How many databases are on the instance?
    363. -- What recovery models are they using?
    364. -- What is the log reuse wait description?
    365. -- How full are the transaction logs ?
    366. -- What compatibility level are the databases on?
    367. -- What is the Page Verify Option? (should be CHECKSUM)
    368. -- Is Auto Update Statistics Asynchronously enabled?
    369. -- Make sure auto_shrink and auto_close are not enabled!



    370. -- Missing Indexes for all databases by Index Advantage  (Query 27) (Missing Indexes All Databases)
    371. SELECT CONVERT(decimal(18,2), user_seeks * avg_total_user_cost * (avg_user_impact * 0.01)) AS [index_advantage],
    372. migs.last_user_seek, mid.[statement] AS [Database.Schema.Table],
    373. mid.equality_columns, mid.inequality_columns, mid.included_columns,
    374. migs.unique_compiles, migs.user_seeks, migs.avg_total_user_cost, migs.avg_user_impact
    375. FROM sys.dm_db_missing_index_group_stats AS migs WITH (NOLOCK)
    376. INNER JOIN sys.dm_db_missing_index_groups AS mig WITH (NOLOCK)
    377. ON migs.group_handle = mig.index_group_handle
    378. INNER JOIN sys.dm_db_missing_index_details AS mid WITH (NOLOCK)
    379. ON mig.index_handle = mid.index_handle
    380. ORDER BY index_advantage DESC OPTION (RECOMPILE);

    381. -- Getting missing index information for all of the databases on the instance is very useful
    382. -- Look at last user seek time, number of user seeks to help determine source and importance
    383. -- Also look at avg_user_impact and avg_total_user_cost to help determine importance
    384. -- SQL Server is overly eager to add included columns, so beware
    385. -- Do not just blindly add indexes that show up from this query!!!



    386. -- Get VLF Counts for all databases on the instance (Query 28) (VLF Counts)
    387. -- (adapted from Michelle Ufford)
    388. CREATE TABLE #VLFInfo (RecoveryUnitID int, FileID  int,
    389.                        FileSize bigint, StartOffset bigint,
    390.                        FSeqNo      bigint, [Status]    bigint,
    391.                        Parity      bigint, CreateLSN   numeric(38));
    392.      
    393. CREATE TABLE #VLFCountResults(DatabaseName sysname, VLFCount int);
    394.      
    395. EXEC sp_MSforeachdb N'Use [?];

    396.                 INSERT INTO #VLFInfo
    397.                 EXEC sp_executesql N''DBCC LOGINFO([?])'';
    398.      
    399.                 INSERT INTO #VLFCountResults
    400.                 SELECT DB_NAME(), COUNT(*)
    401.                 FROM #VLFInfo;

    402.                 TRUNCATE TABLE #VLFInfo;'
    403.      
    404. SELECT DatabaseName, VLFCount  
    405. FROM #VLFCountResults
    406. ORDER BY VLFCount DESC;
    407.      
    408. DROP TABLE #VLFInfo;
    409. DROP TABLE #VLFCountResults;

    410. -- High VLF counts can affect write performance
    411. -- and they can make database restores and recovery take much longer
    412. -- Try to keep your VLF counts under 200 in most cases



    413. -- Get CPU utilization by database (Query 29) (CPU Usage by Database)
    414. WITH DB_CPU_Stats
    415. AS
    416. (SELECT pa.DatabaseID, DB_Name(pa.DatabaseID) AS [Database Name], SUM(qs.total_worker_time/1000) AS [CPU_Time_Ms]
    417. FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK)
    418. CROSS APPLY (SELECT CONVERT(int, value) AS [DatabaseID]
    419.               FROM sys.dm_exec_plan_attributes(qs.plan_handle)
    420.               WHERE attribute = N'dbid') AS pa
    421. GROUP BY DatabaseID)
    422. SELECT ROW_NUMBER() OVER(ORDER BY [CPU_Time_Ms] DESC) AS [CPU Rank],
    423.        [Database Name], [CPU_Time_Ms] AS [CPU Time (ms)],
    424.        CAST([CPU_Time_Ms] * 1.0 / SUM([CPU_Time_Ms]) OVER() * 100.0 AS DECIMAL(5, 2)) AS [CPU Percent]
    425. FROM DB_CPU_Stats
    426. WHERE DatabaseID <> 32767 -- ResourceDB
    427. ORDER BY [CPU Rank] OPTION (RECOMPILE);

    428. -- Helps determine which database is using the most CPU resources on the instance


    429. -- Get I/O utilization by database (Query 30) (IO Usage By Database)
    430. WITH Aggregate_IO_Statistics
    431. AS
    432. (SELECT DB_NAME(database_id) AS [Database Name],
    433. CAST(SUM(num_of_bytes_read + num_of_bytes_written)/1048576 AS DECIMAL(12, 2)) AS io_in_mb
    434. FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS [DM_IO_STATS]
    435. GROUP BY database_id)
    436. SELECT ROW_NUMBER() OVER(ORDER BY io_in_mb DESC) AS [I/O Rank], [Database Name], io_in_mb AS [Total I/O (MB)],
    437.        CAST(io_in_mb/ SUM(io_in_mb) OVER() * 100.0 AS DECIMAL(5,2)) AS [I/O Percent]
    438. FROM Aggregate_IO_Statistics
    439. ORDER BY [I/O Rank] OPTION (RECOMPILE);

    440. -- Helps determine which database is using the most I/O resources on the instance


    441. -- Get total buffer usage by database for current instance  (Query 31) (Total Buffer Usage by Database)
    442. -- This make take some time to run on a busy instance
    443. WITH AggregateBufferPoolUsage
    444. AS
    445. (SELECT DB_NAME(database_id) AS [Database Name],
    446. CAST(COUNT(*) * 8/1024.0 AS DECIMAL (10,2))  AS [CachedSize]
    447. FROM sys.dm_os_buffer_descriptors WITH (NOLOCK)
    448. WHERE database_id <> 32767 -- ResourceDB
    449. GROUP BY DB_NAME(database_id))
    450. SELECT ROW_NUMBER() OVER(ORDER BY CachedSize DESC) AS [Buffer Pool Rank], [Database Name], CachedSize AS [Cached Size (MB)],
    451.        CAST(CachedSize / SUM(CachedSize) OVER() * 100.0 AS DECIMAL(5,2)) AS [Buffer Pool Percent]
    452. FROM AggregateBufferPoolUsage
    453. ORDER BY [Buffer Pool Rank] OPTION (RECOMPILE);

    454. -- Tells you how much memory (in the buffer pool)
    455. -- is being used by each database on the instance


    456. -- Clear Wait Stats with this command
    457. -- DBCC SQLPERF('sys.dm_os_wait_stats', CLEAR);

    458. -- Isolate top waits for server instance since last restart or wait statistics clear  (Query 32) (Top Waits)
    459. WITH [Waits]
    460. AS (SELECT wait_type, wait_time_ms/ 1000.0 AS [WaitS],
    461.           (wait_time_ms - signal_wait_time_ms) / 1000.0 AS [ResourceS],
    462.            signal_wait_time_ms / 1000.0 AS [SignalS],
    463.            waiting_tasks_count AS [WaitCount],
    464.            100.0 *  wait_time_ms / SUM (wait_time_ms) OVER() AS [Percentage],
    465.            ROW_NUMBER() OVER(ORDER BY wait_time_ms DESC) AS [RowNum]
    466.     FROM sys.dm_os_wait_stats WITH (NOLOCK)
    467.     WHERE [wait_type] NOT IN (
    468.         N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', N'BROKER_TASK_STOP',
    469.         N'BROKER_TO_FLUSH', N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE',
    470.         N'CHKPT', N'CLR_AUTO_EVENT', N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE',
    471.         N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', N'DBMIRROR_WORKER_QUEUE',
    472.         N'DBMIRRORING_CMD', N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE',
    473.         N'EXECSYNC', N'FSAGENT', N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX',
    474.         N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', N'HADR_LOGCAPTURE_WAIT',
    475.         N'HADR_NOTIFICATION_DEQUEUE', N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE',
    476.         N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', N'LOGMGR_QUEUE', N'ONDEMAND_TASK_QUEUE',
    477.         N'PWAIT_ALL_COMPONENTS_INITIALIZED', N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP',
    478.         N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', N'REQUEST_FOR_DEADLOCK_SEARCH',
    479.         N'RESOURCE_QUEUE', N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', N'SLEEP_DBSTARTUP',
    480.         N'SLEEP_DCOMSTARTUP', N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY',
    481.         N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', N'SLEEP_SYSTEMTASK', N'SLEEP_TASK',
    482.         N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', N'SP_SERVER_DIAGNOSTICS_SLEEP',
    483.         N'SQLTRACE_BUFFER_FLUSH', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', N'SQLTRACE_WAIT_ENTRIES',
    484.         N'WAIT_FOR_RESULTS', N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', N'WAIT_XTP_HOST_WAIT',
    485.         N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN',
    486.         N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT')
    487.     AND waiting_tasks_count > 0)
    488. SELECT
    489.     MAX (W1.wait_type) AS [WaitType],
    490.     CAST (MAX (W1.WaitS) AS DECIMAL (16,2)) AS [Wait_Sec],
    491.     CAST (MAX (W1.ResourceS) AS DECIMAL (16,2)) AS [Resource_Sec],
    492.     CAST (MAX (W1.SignalS) AS DECIMAL (16,2)) AS [Signal_Sec],
    493.     MAX (W1.WaitCount) AS [Wait Count],
    494.     CAST (MAX (W1.Percentage) AS DECIMAL (5,2)) AS [Wait Percentage],
    495.     CAST ((MAX (W1.WaitS) / MAX (W1.WaitCount)) AS DECIMAL (16,4)) AS [AvgWait_Sec],
    496.     CAST ((MAX (W1.ResourceS) / MAX (W1.WaitCount)) AS DECIMAL (16,4)) AS [AvgRes_Sec],
    497.     CAST ((MAX (W1.SignalS) / MAX (W1.WaitCount)) AS DECIMAL (16,4)) AS [AvgSig_Sec]
    498. FROM Waits AS W1
    499. INNER JOIN Waits AS W2
    500. ON W2.RowNum <= W1.RowNum
    501. GROUP BY W1.RowNum
    502. HAVING SUM (W2.Percentage) - MAX (W1.Percentage) < 99 -- percentage threshold
    503. OPTION (RECOMPILE);

    504. -- Cumulative wait stats are not as useful on an idle instance that is not under load or performance pressure

    505. -- The SQL Server Wait Type Repository
    506. -- http://blogs.msdn.com/b/psssql/archive/2009/11/03/the-sql-server-wait-type-repository.aspx

    507. -- Wait statistics, or please tell me where it hurts
    508. -- http://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/

    509. -- SQL Server 2005 Performance Tuning using the Waits and Queues
    510. -- http://technet.microsoft.com/en-us/library/cc966413.aspx

    511. -- sys.dm_os_wait_stats (Transact-SQL)
    512. -- http://msdn.microsoft.com/en-us/library/ms179984(v=sql.120).aspx



    513. -- Signal Waits for instance  (Query 33) (Signal Waits)
    514. SELECT CAST(100.0 * SUM(signal_wait_time_ms) / SUM (wait_time_ms) AS NUMERIC(20,2)) AS [% Signal (CPU) Waits],
    515. CAST(100.0 * SUM(wait_time_ms - signal_wait_time_ms) / SUM (wait_time_ms) AS NUMERIC(20,2)) AS [% Resource Waits]
    516. FROM sys.dm_os_wait_stats WITH (NOLOCK)
    517. WHERE wait_type NOT IN (
    518.         N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', N'BROKER_TASK_STOP',
    519.         N'BROKER_TO_FLUSH', N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE',
    520.         N'CHKPT', N'CLR_AUTO_EVENT', N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE',
    521.         N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', N'DBMIRROR_WORKER_QUEUE',
    522.         N'DBMIRRORING_CMD', N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE',
    523.         N'EXECSYNC', N'FSAGENT', N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX',
    524.         N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', N'HADR_LOGCAPTURE_WAIT',
    525.         N'HADR_NOTIFICATION_DEQUEUE', N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE',
    526.         N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', N'LOGMGR_QUEUE', N'ONDEMAND_TASK_QUEUE',
    527.         N'PWAIT_ALL_COMPONENTS_INITIALIZED', N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP',
    528.         N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', N'REQUEST_FOR_DEADLOCK_SEARCH',
    529.         N'RESOURCE_QUEUE', N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', N'SLEEP_DBSTARTUP',
    530.         N'SLEEP_DCOMSTARTUP', N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY',
    531.         N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', N'SLEEP_SYSTEMTASK', N'SLEEP_TASK',
    532.         N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', N'SP_SERVER_DIAGNOSTICS_SLEEP',
    533.         N'SQLTRACE_BUFFER_FLUSH', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', N'SQLTRACE_WAIT_ENTRIES',
    534.         N'WAIT_FOR_RESULTS', N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', N'WAIT_XTP_HOST_WAIT',
    535.         N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN',
    536.         N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT') OPTION (RECOMPILE);

    537. -- Signal Waits above 10-15% is usually a confirming sign of CPU pressure
    538. -- Cumulative wait stats are not as useful on an idle instance that is not under load or performance pressure
    539. -- Resource waits are non-CPU related waits


    540. --  Get logins that are connected and how many sessions they have (Query 34) (Connection Counts)
    541. SELECT login_name, [program_name], COUNT(session_id) AS [session_count]
    542. FROM sys.dm_exec_sessions WITH (NOLOCK)
    543. GROUP BY login_name, [program_name]
    544. ORDER BY COUNT(session_id) DESC OPTION (RECOMPILE);

    545. -- This can help characterize your workload and
    546. -- determine whether you are seeing a normal level of activity


    547. -- Get a count of SQL connections by IP address (Query 35) (Connection Counts by IP Address)
    548. SELECT ec.client_net_address, es.[program_name], es.[host_name], es.login_name,
    549. COUNT(ec.session_id) AS [connection count]
    550. FROM sys.dm_exec_sessions AS es WITH (NOLOCK)
    551. INNER JOIN sys.dm_exec_connections AS ec WITH (NOLOCK)
    552. ON es.session_id = ec.session_id
    553. GROUP BY ec.client_net_address, es.[program_name], es.[host_name], es.login_name  
    554. ORDER BY ec.client_net_address, es.[program_name] OPTION (RECOMPILE);

    555. -- This helps you figure where your database load is coming from
    556. -- and verifies connectivity from other machines


    557. -- Get Average Task Counts (run multiple times)  (Query 36) (Avg Task Counts)
    558. SELECT AVG(current_tasks_count) AS [Avg Task Count],
    559. AVG(runnable_tasks_count) AS [Avg Runnable Task Count],
    560. AVG(pending_disk_io_count) AS [Avg Pending DiskIO Count]
    561. FROM sys.dm_os_schedulers WITH (NOLOCK)
    562. WHERE scheduler_id < 255 OPTION (RECOMPILE);

    563. -- Sustained values above 10 suggest further investigation in that area
    564. -- High Avg Task Counts are often caused by blocking/deadlocking or other resource contention

    565. -- Sustained values above 1 suggest further investigation in that area
    566. -- High Avg Runnable Task Counts are a good sign of CPU pressure
    567. -- High Avg Pending DiskIO Counts are a sign of disk pressure


    568. -- Get CPU Utilization History for last 256 minutes (in one minute intervals)  (Query 37) (CPU Utilization History)
    569. -- This version works with SQL Server 2012
    570. DECLARE @ts_now bigint = (SELECT cpu_ticks/(cpu_ticks/ms_ticks) FROM sys.dm_os_sys_info WITH (NOLOCK));

    571. SELECT TOP(256) SQLProcessUtilization AS [SQL Server Process CPU Utilization],
    572.                SystemIdle AS [System Idle Process],
    573.                100 - SystemIdle - SQLProcessUtilization AS [Other Process CPU Utilization],
    574.                DATEADD(ms, -1 * (@ts_now - [timestamp]), GETDATE()) AS [Event Time]
    575. FROM (SELECT record.value('(./Record/@id)[1]', 'int') AS record_id,
    576.             record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int')
    577.             AS [SystemIdle],
    578.             record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int')
    579.             AS [SQLProcessUtilization], [timestamp]
    580.       FROM (SELECT [timestamp], CONVERT(xml, record) AS [record]
    581.             FROM sys.dm_os_ring_buffers WITH (NOLOCK)
    582.             WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR'
    583.             AND record LIKE N'%<SystemHealth>%') AS x) AS y
    584. ORDER BY record_id DESC OPTION (RECOMPILE);

    585. -- Look at the trend over the entire period.
    586. -- Also look at high sustained Other Process CPU Utilization values



    587. -- Get top total worker time queries for entire instance (Query 38) (Top Worker Time Queries)
    588. SELECT TOP(50) DB_NAME(t.[dbid]) AS [Database Name], LEFT(t.[text], 255) AS [Short Query Text],  
    589. qs.total_worker_time AS [Total Worker Time], qs.min_worker_time AS [Min Worker Time],
    590. qs.total_worker_time/qs.execution_count AS [Avg Worker Time],
    591. qs.max_worker_time AS [Max Worker Time], qs.execution_count AS [Execution Count],
    592. qs.total_elapsed_time/qs.execution_count AS [Avg Elapsed Time],
    593. qs.total_logical_reads/qs.execution_count AS [Avg Logical Reads],
    594. qs.total_physical_reads/qs.execution_count AS [Avg Physical Reads], qs.creation_time AS [Creation Time]
    595. --, t.[text] AS [Query Text], qp.query_plan AS [Query Plan] -- uncomment out these columns if not copying results to Excel
    596. FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK)
    597. CROSS APPLY sys.dm_exec_sql_text(plan_handle) AS t
    598. CROSS APPLY sys.dm_exec_query_plan(plan_handle) AS qp
    599. ORDER BY qs.total_worker_time DESC OPTION (RECOMPILE);


    600. -- Helps you find the most expensive queries from a CPU perspective across the entire instance


    601. -- Good basic information about OS memory amounts and state  (Query 39) (System Memory)
    602. SELECT total_physical_memory_kb/1024 AS [Physical Memory (MB)],
    603.        available_physical_memory_kb/1024 AS [Available Memory (MB)],
    604.        total_page_file_kb/1024 AS [Total Page File (MB)],
    605.        available_page_file_kb/1024 AS [Available Page File (MB)],
    606.        system_cache_kb/1024 AS [System Cache (MB)],
    607.        system_memory_state_desc AS [System Memory State]
    608. FROM sys.dm_os_sys_memory WITH (NOLOCK) OPTION (RECOMPILE);

    609. -- You want to see "Available physical memory is high"
    610. -- This indicates that you are not under external memory pressure


    611. -- SQL Server Process Address space info  (Query 40) (Process Memory)
    612. -- (shows whether locked pages is enabled, among other things)
    613. SELECT physical_memory_in_use_kb/1024 AS [SQL Server Memory Usage (MB)],
    614.        large_page_allocations_kb, locked_page_allocations_kb, page_fault_count,
    615.        memory_utilization_percentage, available_commit_limit_kb,
    616.        process_physical_memory_low, process_virtual_memory_low
    617. FROM sys.dm_os_process_memory WITH (NOLOCK) OPTION (RECOMPILE);

    618. -- You want to see 0 for process_physical_memory_low
    619. -- You want to see 0 for process_virtual_memory_low
    620. -- This indicates that you are not under internal memory pressure


    621. -- Page Life Expectancy (PLE) value for each NUMA node in current instance  (Query 41) (PLE by NUMA Node)
    622. SELECT @@SERVERNAME AS [Server Name], [object_name], instance_name, cntr_value AS [Page Life Expectancy]
    623. FROM sys.dm_os_performance_counters WITH (NOLOCK)
    624. WHERE [object_name] LIKE N'%Buffer Node%' -- Handles named instances
    625. AND counter_name = N'Page life expectancy' OPTION (RECOMPILE);

    626. -- PLE is a good measurement of memory pressure.
    627. -- Higher PLE is better. Watch the trend over time, not the absolute value.
    628. -- This will only return one row for non-NUMA systems.


    629. -- Memory Grants Pending value for current instance  (Query 42) (Memory Grants Pending)
    630. SELECT @@SERVERNAME AS [Server Name], [object_name], cntr_value AS [Memory Grants Pending]                                                                                                      
    631. FROM sys.dm_os_performance_counters WITH (NOLOCK)
    632. WHERE [object_name] LIKE N'%Memory Manager%' -- Handles named instances
    633. AND counter_name = N'Memory Grants Pending' OPTION (RECOMPILE);

    634. -- Memory Grants Pending above zero for a sustained period is a very strong indicator of memory pressure


    635. -- Memory Clerk Usage for instance  (Query 43) (Memory Clerk Usage)
    636. -- Look for high value for CACHESTORE_SQLCP (Ad-hoc query plans)
    637. SELECT TOP(10) mc.[type] AS [Memory Clerk Type],
    638.        CAST((SUM(mc.pages_kb)/1024.0) AS DECIMAL (15,2)) AS [Memory Usage (MB)]
    639. FROM sys.dm_os_memory_clerks AS mc WITH (NOLOCK)
    640. GROUP BY mc.[type]  
    641. ORDER BY SUM(mc.pages_kb) DESC OPTION (RECOMPILE);

    642. -- MEMORYCLERK_SQLBUFFERPOOL is new for SQL Server 2012. It should be your highest consumer of memory

    643. -- CACHESTORE_SQLCP  SQL Plans         
    644. -- These are cached SQL statements or batches that aren't in stored procedures, functions and triggers
    645. -- Watch out for high values for CACHESTORE_SQLCP

    646. -- CACHESTORE_OBJCP  Object Plans      
    647. -- These are compiled plans for stored procedures, functions and triggers



    648. -- Find single-use, ad-hoc and prepared queries that are bloating the plan cache  (Query 44) (Ad hoc Queries)
    649. SELECT TOP(50) [text] AS [QueryText], cp.cacheobjtype, cp.objtype, cp.size_in_bytes/1024 AS [Plan Size in KB]
    650. FROM sys.dm_exec_cached_plans AS cp WITH (NOLOCK)
    651. CROSS APPLY sys.dm_exec_sql_text(plan_handle)
    652. WHERE cp.cacheobjtype = N'Compiled Plan'
    653. AND cp.objtype IN (N'Adhoc', N'Prepared')
    654. AND cp.usecounts = 1
    655. ORDER BY cp.size_in_bytes DESC OPTION (RECOMPILE);

    656. -- Gives you the text, type and size of single-use ad-hoc and prepared queries that waste space in the plan cache
    657. -- Enabling 'optimize for ad hoc workloads' for the instance can help (SQL Server 2008 and above only)
    658. -- Running DBCC FREESYSTEMCACHE ('SQL Plans') periodically may be required to better control this.
    659. -- Enabling forced parameterization for the database can help, but test first!


    660. -- Database specific queries *****************************************************************

    661. -- **** Switch to a user database *****
    662. USE YourDatabaseName; -- make sure to change to an actual database on your instance
    663. GO

    664. -- Individual File Sizes and space available for current database  (Query 45) (File Sizes and Space)
    665. SELECT f.name AS [File Name] , f.physical_name AS [Physical Name],
    666. CAST((f.size/128.0) AS DECIMAL(15,2)) AS [Total Size in MB],
    667. CAST(f.size/128.0 - CAST(FILEPROPERTY(f.name, 'SpaceUsed') AS int)/128.0 AS DECIMAL(15,2))
    668. AS [Available Space In MB], [file_id], fg.name AS [Filegroup Name]
    669. FROM sys.database_files AS f WITH (NOLOCK)
    670. LEFT OUTER JOIN sys.data_spaces AS fg WITH (NOLOCK)
    671. ON f.data_space_id = fg.data_space_id OPTION (RECOMPILE);

    672. -- Look at how large and how full the files are and where they are located
    673. -- Make sure the transaction log is not full!!



    674. -- I/O Statistics by file for the current database  (Query 46) (IO Stats By File)
    675. SELECT DB_NAME(DB_ID()) AS [Database Name], df.name AS [Logical Name], vfs.[file_id],
    676. df.physical_name AS [Physical Name], vfs.num_of_reads, vfs.num_of_writes, vfs.io_stall_read_ms, vfs.io_stall_write_ms,
    677. 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],
    678. 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],
    679. (vfs.num_of_reads + vfs.num_of_writes) AS [Writes + Reads],
    680. CAST(vfs.num_of_bytes_read/1048576.0 AS DECIMAL(10, 2)) AS [MB Read],
    681. CAST(vfs.num_of_bytes_written/1048576.0 AS DECIMAL(10, 2)) AS [MB Written],
    682. CAST(100. * vfs.num_of_reads/(vfs.num_of_reads + vfs.num_of_writes) AS DECIMAL(10,1)) AS [# Reads Pct],
    683. CAST(100. * vfs.num_of_writes/(vfs.num_of_reads + vfs.num_of_writes) AS DECIMAL(10,1)) AS [# Write Pct],
    684. 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],
    685. 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]
    686. FROM sys.dm_io_virtual_file_stats(DB_ID(), NULL) AS vfs
    687. INNER JOIN sys.database_files AS df WITH (NOLOCK)
    688. ON vfs.[file_id]= df.[file_id] OPTION (RECOMPILE);

    689. -- This helps you characterize your workload better from an I/O perspective for this database
    690. -- It helps you determine whether you has an OLTP or DW/DSS type of workload



    691. -- Top cached queries by Execution Count (SQL Server 2012)  (Query 47) (Query Execution Counts)
    692. SELECT TOP (100) qs.execution_count, qs.total_rows, qs.last_rows, qs.min_rows, qs.max_rows,
    693. qs.last_elapsed_time, qs.min_elapsed_time, qs.max_elapsed_time,
    694. total_worker_time, total_logical_reads,
    695. SUBSTRING(qt.TEXT,qs.statement_start_offset/2 +1,
    696. (CASE WHEN qs.statement_end_offset = -1
    697.             THEN LEN(CONVERT(NVARCHAR(MAX), qt.TEXT)) * 2
    698.       ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS query_text
    699. FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK)
    700. CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS qt
    701. WHERE qt.dbid = DB_ID()
    702. ORDER BY qs.execution_count DESC OPTION (RECOMPILE);

    703. -- Uses several new rows returned columns to help troubleshoot performance problems


    704. -- Top Cached SPs By Execution Count (SQL Server 2012)  (Query 48) (SP Execution Counts)
    705. SELECT TOP(100) p.name AS [SP Name], qs.execution_count,
    706. ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute],
    707. qs.total_worker_time/qs.execution_count AS [AvgWorkerTime], qs.total_worker_time AS [TotalWorkerTime],  
    708. qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time],
    709. qs.cached_time
    710. FROM sys.procedures AS p WITH (NOLOCK)
    711. INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK)
    712. ON p.[object_id] = qs.[object_id]
    713. WHERE qs.database_id = DB_ID()
    714. ORDER BY qs.execution_count DESC OPTION (RECOMPILE);

    715. -- Tells you which cached stored procedures are called the most often
    716. -- This helps you characterize and baseline your workload


    717. -- Top Cached SPs By Avg Elapsed Time (SQL Server 2012)  (Query 49) (SP Avg Elapsed Time)
    718. SELECT TOP(25) p.name AS [SP Name], qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time],
    719. qs.total_elapsed_time, qs.execution_count, ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time,
    720. GETDATE()), 0) AS [Calls/Minute], qs.total_worker_time/qs.execution_count AS [AvgWorkerTime],
    721. qs.total_worker_time AS [TotalWorkerTime], qs.cached_time
    722. FROM sys.procedures AS p WITH (NOLOCK)
    723. INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK)
    724. ON p.[object_id] = qs.[object_id]
    725. WHERE qs.database_id = DB_ID()
    726. ORDER BY avg_elapsed_time DESC OPTION (RECOMPILE);

    727. -- This helps you find long-running cached stored procedures that
    728. -- may be easy to optimize with standard query tuning techniques


    729. -- Top Cached SPs By Avg Elapsed Time with execution time variability (SQL Server 2012)  (Query 50) (SP Avg Elapsed Variable Time)
    730. SELECT TOP(25) p.name AS [SP Name], qs.execution_count, qs.min_elapsed_time,
    731. qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time],
    732. qs.max_elapsed_time, qs.last_elapsed_time,  qs.cached_time
    733. FROM sys.procedures AS p WITH (NOLOCK)
    734. INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK)
    735. ON p.[object_id] = qs.[object_id]
    736. WHERE qs.database_id = DB_ID()
    737. ORDER BY avg_elapsed_time DESC OPTION (RECOMPILE);

    738. -- This gives you some interesting information about the variability in the
    739. -- execution time of your cached stored procedures, which is useful for tuning


    740. -- Top Cached SPs By Total Worker time (SQL Server 2012). Worker time relates to CPU cost  (Query 51) (SP Worker Time)
    741. SELECT TOP(25) p.name AS [SP Name], qs.total_worker_time AS [TotalWorkerTime],
    742. qs.total_worker_time/qs.execution_count AS [AvgWorkerTime], qs.execution_count,
    743. ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute],
    744. qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count
    745. AS [avg_elapsed_time], qs.cached_time
    746. FROM sys.procedures AS p WITH (NOLOCK)
    747. INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK)
    748. ON p.[object_id] = qs.[object_id]
    749. WHERE qs.database_id = DB_ID()
    750. ORDER BY qs.total_worker_time DESC OPTION (RECOMPILE);

    751. -- This helps you find the most expensive cached stored procedures from a CPU perspective
    752. -- You should look at this if you see signs of CPU pressure


    753. -- Top Cached SPs By Total Logical Reads (SQL Server 2012). Logical reads relate to memory pressure  (Query 52) (SP Logical Reads)
    754. SELECT TOP(25) p.name AS [SP Name], qs.total_logical_reads AS [TotalLogicalReads],
    755. qs.total_logical_reads/qs.execution_count AS [AvgLogicalReads],qs.execution_count,
    756. ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute],
    757. qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count
    758. AS [avg_elapsed_time], qs.cached_time
    759. FROM sys.procedures AS p WITH (NOLOCK)
    760. INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK)
    761. ON p.[object_id] = qs.[object_id]
    762. WHERE qs.database_id = DB_ID()
    763. ORDER BY qs.total_logical_reads DESC OPTION (RECOMPILE);

    764. -- This helps you find the most expensive cached stored procedures from a memory perspective
    765. -- You should look at this if you see signs of memory pressure


    766. -- Top Cached SPs By Total Physical Reads (SQL Server 2012). Physical reads relate to disk I/O pressure  (Query 53) (SP Physical Reads)
    767. SELECT TOP(25) p.name AS [SP Name],qs.total_physical_reads AS [TotalPhysicalReads],
    768. qs.total_physical_reads/qs.execution_count AS [AvgPhysicalReads], qs.execution_count,
    769. qs.total_logical_reads,qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count
    770. AS [avg_elapsed_time], qs.cached_time
    771. FROM sys.procedures AS p WITH (NOLOCK)
    772. INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK)
    773. ON p.[object_id] = qs.[object_id]
    774. WHERE qs.database_id = DB_ID()
    775. AND qs.total_physical_reads > 0
    776. ORDER BY qs.total_physical_reads DESC, qs.total_logical_reads DESC OPTION (RECOMPILE);

    777. -- This helps you find the most expensive cached stored procedures from a read I/O perspective
    778. -- You should look at this if you see signs of I/O pressure or of memory pressure
    779.       
    780. -- Top Cached SPs By Total Logical Writes (SQL Server 2012)  (Query 54) (SP Logical Writes)
    781. -- Logical writes relate to both memory and disk I/O pressure
    782. SELECT TOP(25) p.name AS [SP Name], qs.total_logical_writes AS [TotalLogicalWrites],
    783. qs.total_logical_writes/qs.execution_count AS [AvgLogicalWrites], qs.execution_count,
    784. ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute],
    785. qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time],
    786. qs.cached_time
    787. FROM sys.procedures AS p WITH (NOLOCK)
    788. INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK)
    789. ON p.[object_id] = qs.[object_id]
    790. WHERE qs.database_id = DB_ID()
    791. AND qs.total_logical_writes > 0
    792. ORDER BY qs.total_logical_writes DESC OPTION (RECOMPILE);

    793. -- This helps you find the most expensive cached stored procedures from a write I/O perspective
    794. -- You should look at this if you see signs of I/O pressure or of memory pressure


    795. -- Lists the top statements by average input/output usage for the current database  (Query 55) (Top IO Statements)
    796. SELECT TOP(50) OBJECT_NAME(qt.objectid, dbid) AS [SP Name],
    797. (qs.total_logical_reads + qs.total_logical_writes) /qs.execution_count AS [Avg IO], qs.execution_count AS [Execution Count],
    798. SUBSTRING(qt.[text],qs.statement_start_offset/2,
    799.     (CASE
    800.         WHEN qs.statement_end_offset = -1
    801.      THEN LEN(CONVERT(nvarchar(max), qt.[text])) * 2
    802.         ELSE qs.statement_end_offset
    803.      END - qs.statement_start_offset)/2) AS [Query Text]   
    804. FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK)
    805. CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS qt
    806. WHERE qt.[dbid] = DB_ID()
    807. ORDER BY [Avg IO] DESC OPTION (RECOMPILE);

    808. -- Helps you find the most expensive statements for I/O by SP



    809. -- Possible Bad NC Indexes (writes > reads)  (Query 56) (Bad NC Indexes)
    810. SELECT OBJECT_NAME(s.[object_id]) AS [Table Name], i.name AS [Index Name], i.index_id,
    811. i.is_disabled, i.is_hypothetical, i.has_filter, i.fill_factor,
    812. user_updates AS [Total Writes], user_seeks + user_scans + user_lookups AS [Total Reads],
    813. user_updates - (user_seeks + user_scans + user_lookups) AS [Difference]
    814. FROM sys.dm_db_index_usage_stats AS s WITH (NOLOCK)
    815. INNER JOIN sys.indexes AS i WITH (NOLOCK)
    816. ON s.[object_id] = i.[object_id]
    817. AND i.index_id = s.index_id
    818. WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1
    819. AND s.database_id = DB_ID()
    820. AND user_updates > (user_seeks + user_scans + user_lookups)
    821. AND i.index_id > 1
    822. ORDER BY [Difference] DESC, [Total Writes] DESC, [Total Reads] ASC OPTION (RECOMPILE);

    823. -- Look for indexes with high numbers of writes and zero or very low numbers of reads
    824. -- Consider your complete workload, and how long your instance has been running
    825. -- Investigate further before dropping an index!


    826. -- Missing Indexes for current database by Index Advantage  (Query 57) (Missing Indexes)
    827. SELECT DISTINCT CONVERT(decimal(18,2), user_seeks * avg_total_user_cost * (avg_user_impact * 0.01)) AS [index_advantage],
    828. migs.last_user_seek, mid.[statement] AS [Database.Schema.Table],
    829. mid.equality_columns, mid.inequality_columns, mid.included_columns,
    830. migs.unique_compiles, migs.user_seeks, migs.avg_total_user_cost, migs.avg_user_impact,
    831. OBJECT_NAME(mid.[object_id]) AS [Table Name], p.rows AS [Table Rows]
    832. FROM sys.dm_db_missing_index_group_stats AS migs WITH (NOLOCK)
    833. INNER JOIN sys.dm_db_missing_index_groups AS mig WITH (NOLOCK)
    834. ON migs.group_handle = mig.index_group_handle
    835. INNER JOIN sys.dm_db_missing_index_details AS mid WITH (NOLOCK)
    836. ON mig.index_handle = mid.index_handle
    837. INNER JOIN sys.partitions AS p WITH (NOLOCK)
    838. ON p.[object_id] = mid.[object_id]
    839. WHERE mid.database_id = DB_ID()
    840. ORDER BY index_advantage DESC OPTION (RECOMPILE);

    841. -- Look at index advantage, last user seek time, number of user seeks to help determine source and importance
    842. -- SQL Server is overly eager to add included columns, so beware
    843. -- Do not just blindly add indexes that show up from this query!!!


    844. -- Find missing index warnings for cached plans in the current database  (Query 58) (Missing Index Warnings)
    845. -- Note: This query could take some time on a busy instance
    846. SELECT TOP(25) OBJECT_NAME(objectid) AS [ObjectName],
    847.                query_plan, cp.objtype, cp.usecounts
    848. FROM sys.dm_exec_cached_plans AS cp WITH (NOLOCK)
    849. CROSS APPLY sys.dm_exec_query_plan(cp.plan_handle) AS qp
    850. WHERE CAST(query_plan AS NVARCHAR(MAX)) LIKE N'%MissingIndex%'
    851. AND dbid = DB_ID()
    852. ORDER BY cp.usecounts DESC OPTION (RECOMPILE);

    853. -- Helps you connect missing indexes to specific stored procedures or queries
    854. -- This can help you decide whether to add them or not


    855. -- Breaks down buffers used by current database by object (table, index) in the buffer cache  (Query 59) (Buffer Usage)
    856. -- Note: This query could take some time on a busy instance
    857. SELECT OBJECT_NAME(p.[object_id]) AS [Object Name], p.index_id,
    858. CAST(COUNT(*)/128.0 AS DECIMAL(10, 2)) AS [Buffer size(MB)],  
    859. COUNT(*) AS [BufferCount], p.Rows AS [Row Count],
    860. p.data_compression_desc AS [Compression Type]
    861. FROM sys.allocation_units AS a WITH (NOLOCK)
    862. INNER JOIN sys.dm_os_buffer_descriptors AS b WITH (NOLOCK)
    863. ON a.allocation_unit_id = b.allocation_unit_id
    864. INNER JOIN sys.partitions AS p WITH (NOLOCK)
    865. ON a.container_id = p.hobt_id
    866. WHERE b.database_id = CONVERT(int,DB_ID())
    867. AND p.[object_id] > 100
    868. GROUP BY p.[object_id], p.index_id, p.data_compression_desc, p.[Rows]
    869. ORDER BY [BufferCount] DESC OPTION (RECOMPILE);

    870. -- Tells you what tables and indexes are using the most memory in the buffer cache
    871. -- It can help identify possible candidates for data compression


    872. -- Get Table names, row counts, and compression status for clustered index or heap  (Query 60) (Table Sizes)
    873. SELECT OBJECT_NAME(object_id) AS [ObjectName],
    874. SUM(Rows) AS [RowCount], data_compression_desc AS [CompressionType]
    875. FROM sys.partitions WITH (NOLOCK)
    876. WHERE index_id < 2 --ignore the partitions from the non-clustered index if any
    877. AND OBJECT_NAME(object_id) NOT LIKE N'sys%'
    878. AND OBJECT_NAME(object_id) NOT LIKE N'queue_%'
    879. AND OBJECT_NAME(object_id) NOT LIKE N'filestream_tombstone%'
    880. AND OBJECT_NAME(object_id) NOT LIKE N'fulltext%'
    881. AND OBJECT_NAME(object_id) NOT LIKE N'ifts_comp_fragment%'
    882. AND OBJECT_NAME(object_id) NOT LIKE N'filetable_updates%'
    883. AND OBJECT_NAME(object_id) NOT LIKE N'xml_index_nodes%'
    884. GROUP BY object_id, data_compression_desc
    885. ORDER BY SUM(Rows) DESC OPTION (RECOMPILE);

    886. -- Gives you an idea of table sizes, and possible data compression opportunities



    887. -- Get some key table properties (Query 61) (Table Properties)
    888. SELECT [name], create_date, lock_on_bulk_load, is_replicated, has_replication_filter,
    889.        is_tracked_by_cdc, lock_escalation_desc
    890. FROM sys.tables WITH (NOLOCK)
    891. ORDER BY [name] OPTION (RECOMPILE);

    892. -- Gives you some good information about your tables


    893. -- Detect blocking (run multiple times)  (Query 62) (Detect Blocking)
    894. SELECT t1.resource_type AS [lock type], DB_NAME(resource_database_id) AS [database],
    895. t1.resource_associated_entity_id AS [blk object],t1.request_mode AS [lock req],  --- lock requested
    896. t1.request_session_id AS [waiter sid], t2.wait_duration_ms AS [wait time],       -- spid of waiter  
    897. (SELECT [text] FROM sys.dm_exec_requests AS r WITH (NOLOCK)                      -- get sql for waiter
    898. CROSS APPLY sys.dm_exec_sql_text(r.[sql_handle])
    899. WHERE r.session_id = t1.request_session_id) AS [waiter_batch],
    900. (SELECT SUBSTRING(qt.[text],r.statement_start_offset/2,
    901.     (CASE WHEN r.statement_end_offset = -1
    902.     THEN LEN(CONVERT(nvarchar(max), qt.[text])) * 2
    903.     ELSE r.statement_end_offset END - r.statement_start_offset)/2)
    904. FROM sys.dm_exec_requests AS r WITH (NOLOCK)
    905. CROSS APPLY sys.dm_exec_sql_text(r.[sql_handle]) AS qt
    906. WHERE r.session_id = t1.request_session_id) AS [waiter_stmt],                    -- statement blocked
    907. t2.blocking_session_id AS [blocker sid],                                        -- spid of blocker
    908. (SELECT [text] FROM sys.sysprocesses AS p                                        -- get sql for blocker
    909. CROSS APPLY sys.dm_exec_sql_text(p.[sql_handle])
    910. WHERE p.spid = t2.blocking_session_id) AS [blocker_stmt]
    911. FROM sys.dm_tran_locks AS t1 WITH (NOLOCK)
    912. INNER JOIN sys.dm_os_waiting_tasks AS t2 WITH (NOLOCK)
    913. ON t1.lock_owner_address = t2.resource_address OPTION (RECOMPILE);

    914. -- Helps troubleshoot blocking and deadlocking issues
    915. -- The results will change from second to second on a busy system
    916. -- You should run this query multiple times when you see signs of blocking



    917. -- When were Statistics last updated on all indexes?  (Query 63) (Statistics Update)
    918. SELECT SCHEMA_NAME(o.Schema_ID) + N'.' + o.NAME AS [Object Name], o.type_desc AS [Object Type],
    919.       i.name AS [Index Name], STATS_DATE(i.[object_id], i.index_id) AS [Statistics Date],
    920.       s.auto_created, s.no_recompute, s.user_created, s.is_temporary,
    921.       st.row_count, st.used_page_count
    922. FROM sys.objects AS o WITH (NOLOCK)
    923. INNER JOIN sys.indexes AS i WITH (NOLOCK)
    924. ON o.[object_id] = i.[object_id]
    925. INNER JOIN sys.stats AS s WITH (NOLOCK)
    926. ON i.[object_id] = s.[object_id]
    927. AND i.index_id = s.stats_id
    928. INNER JOIN sys.dm_db_partition_stats AS st WITH (NOLOCK)
    929. ON o.[object_id] = st.[object_id]
    930. AND i.[index_id] = st.[index_id]
    931. WHERE o.[type] IN ('U', 'V')
    932. AND st.row_count > 0
    933. ORDER BY STATS_DATE(i.[object_id], i.index_id) DESC OPTION (RECOMPILE);  

    934. -- Helps discover possible problems with out-of-date statistics
    935. -- Also gives you an idea which indexes are the most active


    936. -- Look at most frequently modified indexes and statistics (Query 64) (Volatile Indexes)
    937. SELECT o.name AS [Object Name], o.[object_id], o.type_desc, s.name AS [Statistics Name],
    938.        s.stats_id, s.no_recompute, s.auto_created,
    939.        sp.modification_counter, sp.rows, sp.rows_sampled, sp.last_updated
    940. FROM sys.objects AS o WITH (NOLOCK)
    941. INNER JOIN sys.stats AS s WITH (NOLOCK)
    942. ON s.object_id = o.object_id
    943. CROSS APPLY sys.dm_db_stats_properties(s.object_id, s.stats_id) AS sp
    944. WHERE o.type_desc NOT IN (N'SYSTEM_TABLE', N'INTERNAL_TABLE')
    945. AND sp.modification_counter > 0
    946. ORDER BY sp.modification_counter DESC, o.name OPTION (RECOMPILE);



    947. -- Get fragmentation info for all indexes above a certain size in the current database  (Query 65) (Index Fragmentation)
    948. -- Note: This query could take some time on a very large database
    949. SELECT DB_NAME(ps.database_id) AS [Database Name], OBJECT_NAME(ps.OBJECT_ID) AS [Object Name],
    950. i.name AS [Index Name], ps.index_id, ps.index_type_desc, ps.avg_fragmentation_in_percent,
    951. ps.fragment_count, ps.page_count, i.fill_factor, i.has_filter, i.filter_definition
    952. FROM sys.dm_db_index_physical_stats(DB_ID(),NULL, NULL, NULL , N'LIMITED') AS ps
    953. INNER JOIN sys.indexes AS i WITH (NOLOCK)
    954. ON ps.[object_id] = i.[object_id]
    955. AND ps.index_id = i.index_id
    956. WHERE ps.database_id = DB_ID()
    957. AND ps.page_count > 2500
    958. ORDER BY ps.avg_fragmentation_in_percent DESC OPTION (RECOMPILE);

    959. -- Helps determine whether you have framentation in your relational indexes
    960. -- and how effective your index maintenance strategy is


    961. --- Index Read/Write stats (all tables in current DB) ordered by Reads  (Query 66) (Overall Index Usage - Reads)
    962. SELECT OBJECT_NAME(s.[object_id]) AS [ObjectName], i.name AS [IndexName], i.index_id,
    963.        user_seeks + user_scans + user_lookups AS [Reads], s.user_updates AS [Writes],  
    964.        i.type_desc AS [IndexType], i.fill_factor AS [FillFactor], i.has_filter, i.filter_definition,
    965.        s.last_user_scan, s.last_user_lookup, s.last_user_seek
    966. FROM sys.dm_db_index_usage_stats AS s WITH (NOLOCK)
    967. INNER JOIN sys.indexes AS i WITH (NOLOCK)
    968. ON s.[object_id] = i.[object_id]
    969. WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1
    970. AND i.index_id = s.index_id
    971. AND s.database_id = DB_ID()
    972. ORDER BY user_seeks + user_scans + user_lookups DESC OPTION (RECOMPILE); -- Order by reads


    973. -- Show which indexes in the current database are most active for Reads


    974. --- Index Read/Write stats (all tables in current DB) ordered by Writes  (Query 67) (Overall Index Usage - Writes)
    975. SELECT OBJECT_NAME(s.[object_id]) AS [ObjectName], i.name AS [IndexName], i.index_id,
    976.        s.user_updates AS [Writes], user_seeks + user_scans + user_lookups AS [Reads],
    977.        i.type_desc AS [IndexType], i.fill_factor AS [FillFactor], i.has_filter, i.filter_definition,
    978.        s.last_system_update, s.last_user_update
    979. FROM sys.dm_db_index_usage_stats AS s WITH (NOLOCK)
    980. INNER JOIN sys.indexes AS i WITH (NOLOCK)
    981. ON s.[object_id] = i.[object_id]
    982. WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1
    983. AND i.index_id = s.index_id
    984. AND s.database_id = DB_ID()
    985. ORDER BY s.user_updates DESC OPTION (RECOMPILE);                         -- Order by writes

    986. -- Show which indexes in the current database are most active for Writes


    987. -- Get lock waits for current database (Query 68) (Lock Waits)
    988. SELECT o.name AS [table_name], i.name AS [index_name], ios.index_id, ios.partition_number,
    989.         SUM(ios.row_lock_wait_count) AS [total_row_lock_waits],
    990.         SUM(ios.row_lock_wait_in_ms) AS [total_row_lock_wait_in_ms],
    991.         SUM(ios.page_lock_wait_count) AS [total_page_lock_waits],
    992.         SUM(ios.page_lock_wait_in_ms) AS [total_page_lock_wait_in_ms],
    993.         SUM(ios.page_lock_wait_in_ms)+ SUM(row_lock_wait_in_ms) AS [total_lock_wait_in_ms]
    994. FROM sys.dm_db_index_operational_stats(DB_ID(), NULL, NULL, NULL) AS ios
    995. INNER JOIN sys.objects AS o WITH (NOLOCK)
    996. ON ios.[object_id] = o.[object_id]
    997. INNER JOIN sys.indexes AS i WITH (NOLOCK)
    998. ON ios.[object_id] = i.[object_id]
    999. AND ios.index_id = i.index_id
    1000. WHERE o.[object_id] > 100
    1001. GROUP BY o.name, i.name, ios.index_id, ios.partition_number
    1002. HAVING SUM(ios.page_lock_wait_in_ms)+ SUM(row_lock_wait_in_ms) > 0
    1003. ORDER BY total_lock_wait_in_ms DESC OPTION (RECOMPILE);

    1004. -- This query is helpful for troubleshooting blocking and deadlocking issues


    1005. -- Look at recent Full backups for the current database (Query 69) (Recent Full Backups)
    1006. SELECT TOP (30) bs.machine_name, bs.server_name, bs.database_name AS [Database Name], bs.recovery_model,
    1007. CONVERT (BIGINT, bs.backup_size / 1048576 ) AS [Uncompressed Backup Size (MB)],
    1008. CONVERT (BIGINT, bs.compressed_backup_size / 1048576 ) AS [Compressed Backup Size (MB)],
    1009. CONVERT (NUMERIC (20,2), (CONVERT (FLOAT, bs.backup_size) /
    1010. CONVERT (FLOAT, bs.compressed_backup_size))) AS [Compression Ratio],
    1011. DATEDIFF (SECOND, bs.backup_start_date, bs.backup_finish_date) AS [Backup Elapsed Time (sec)],
    1012. bs.backup_finish_date AS [Backup Finish Date]
    1013. FROM msdb.dbo.backupset AS bs WITH (NOLOCK)
    1014. WHERE DATEDIFF (SECOND, bs.backup_start_date, bs.backup_finish_date) > 0
    1015. AND bs.backup_size > 0
    1016. AND bs.[type] = 'D' -- Change to L if you want Log backups
    1017. AND database_name = DB_NAME(DB_ID())
    1018. ORDER BY bs.backup_finish_date DESC OPTION (RECOMPILE);

    1019. -- Are your backup sizes and times changing over time?
    1020. -- Are you using backup compression?


    1021. -- These three Pluralsight Courses go into more detail about how to run these queries and interpret the results

    1022. -- SQL Server 2014 DMV Diagnostic Queries Part 1
    1023. -- http://www.pluralsight.com/courses/sql-server-2014-dmv-diagnostic-queries-part1

    1024. -- SQL Server 2014 DMV Diagnostic Queries Part 2
    1025. -- http://www.pluralsight.com/courses/sql-server-2014-dmv-diagnostic-queries-part2

    1026. -- SQL Server 2014 DMV Diagnostic Queries Part 3
    1027. -- http://www.pluralsight.com/courses/sql-server-2014-dmv-diagnostic-queries-part3
    复制代码


    回复

    使用道具 举报

    您需要登录后才可以回帖 登录 | 立即注册

    本版积分规则

    运维联盟俱乐部 ( 冀ICP备19036648号 )

    GMT+8, 2024-4-29 18:12 , Processed in 0.071529 second(s), 21 queries , Gzip On.

    Powered by Discuz! X3.4

    © 2001-2023 Discuz! Team.

    快速回复 返回顶部 返回列表