├── .gitignore ├── Databases └── Overall Database Resource Usage.sql ├── IO Subsystem ├── Disk Usage.sql └── File IO Usage.sql ├── Indexes ├── How Are Indexes Being Used.sql ├── Index Defragmentation Suggestions.sql └── Missing Indexes.sql ├── Plan Cache ├── Clearing Plan Cache.sql ├── Most Used Plans.sql ├── Object Type Plan Cache Usage.sql └── Worst Performing Queries.sql ├── README.md ├── Server Configuration └── Settings Overview.sql ├── Statistics ├── Index Statistics That Havent Been Updated Recently.sql ├── Statistics Overview.sql └── Updating Statistics.sql ├── Third Party Scripts ├── sp_blitz.txt └── sp_whoisactive_v11.11.txt └── Wait Statistics ├── Clear Wait Stats.sql └── Wait Statistics Overview.sql /.gitignore: -------------------------------------------------------------------------------- 1 | _Work in progress/ -------------------------------------------------------------------------------- /Databases/Overall Database Resource Usage.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Title: Overall Database Resource Usage 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | Attribution: Inspired by Glenn Berry's DMV scripts 6 | (http://sqlserverperformance.wordpress.com/tag/dmv-queries/) 7 | Requirements: 2005+ 8 | 9 | Usage: 10 | Outputs an overview of how many resources each database has spent since the last 11 | DBCC FREEPROCCACHE / DROPCLEANBUFFERS / restart. 12 | */ 13 | 14 | WITH DatabaseUsage AS 15 | ( 16 | -- Fetches IO & CPU stats 17 | SELECT 18 | PA.DatabaseID, 19 | SUM(total_worker_time) AS [CPU Time (ms)], 20 | (SUM(IO.num_of_bytes_read + IO.num_of_bytes_written)) / 1024 / 1024 AS [IO (mb)] 21 | FROM 22 | sys.dm_exec_query_stats AS QS 23 | CROSS APPLY 24 | (SELECT CAST(value AS int) AS DatabaseID FROM sys.dm_exec_plan_attributes(qs.plan_handle) WHERE attribute = 'dbid') AS PA 25 | LEFT JOIN 26 | sys.dm_io_virtual_file_stats(NULL, NULL) AS IO ON IO.database_id = PA.DatabaseID 27 | WHERE 28 | PA.DatabaseID < 32767 29 | GROUP BY 30 | DatabaseID 31 | ), 32 | PlanUsage AS 33 | ( 34 | SELECT 35 | PA.DatabaseID, 36 | SUM(P.size_in_bytes) / 1024 / 1024 AS [Plan Cache (mb)] 37 | FROM 38 | sys.dm_exec_cached_plans P 39 | CROSS APPLY 40 | (SELECT CAST(value AS int) AS DatabaseID FROM sys.dm_exec_plan_attributes(p.plan_handle) WHERE attribute = 'dbid') AS PA 41 | WHERE 42 | PA.DatabaseID < 32767 43 | GROUP BY 44 | PA.DatabaseID 45 | ), 46 | BPUsage AS 47 | ( 48 | SELECT 49 | database_id AS DatabaseID, 50 | CAST(COUNT(*) * 8/1024.0 AS DECIMAL (10,2)) AS [Buffer Pool (mb)] 51 | FROM 52 | sys.dm_os_buffer_descriptors WITH (NOLOCK) 53 | WHERE 54 | database_id < 32767 55 | GROUP BY 56 | database_id 57 | ) 58 | SELECT 59 | D.name, 60 | CAST([CPU Time (ms)] * 1.0 / SUM([CPU Time (ms)]) OVER() * 100.0 AS DECIMAL(5, 2)) AS [CPU (%)], 61 | CAST([IO (mb)] * 1.0 / SUM([IO (mb)]) OVER() * 100.0 AS DECIMAL(5, 2)) AS [IO (%)], 62 | CAST([Buffer Pool (mb)] * 1.0 / SUM([Buffer Pool (mb)]) OVER() * 100.0 AS DECIMAL(5, 2)) AS [Buffer Pool (%)], 63 | CAST([Plan Cache (mb)] * 1.0 / SUM([Plan Cache (mb)]) OVER() * 100.0 AS DECIMAL(5, 2)) AS [Plan Cache (%)], 64 | [CPU Time (ms)], 65 | [IO (mb)], 66 | [Buffer Pool (mb)], 67 | [Plan Cache (mb)] 68 | FROM 69 | sys.databases D 70 | LEFT JOIN 71 | DatabaseUsage U ON U.DatabaseID = D.database_id 72 | LEFT JOIN 73 | BPUsage BP ON BP.DatabaseID = D.database_id 74 | LEFT JOIN 75 | PlanUsage PU ON PU.DatabaseID = D.database_id 76 | ORDER BY 77 | [CPU Time (ms)] DESC 78 | OPTION 79 | (RECOMPILE) -------------------------------------------------------------------------------- /IO Subsystem/Disk Usage.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Disk Usage 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | List of all disks on which there are files, including overall usage statistics. 8 | ********************************************************************************/ 9 | 10 | WITH TMP AS 11 | ( 12 | SELECT 13 | f.type_desc AS [Type], 14 | SUBSTRING(f.physical_name, 1, 1) AS [Drive Letter], 15 | s.size_on_disk_bytes / 1024 / 1024 AS [Size in MB], 16 | CAST(CAST(s.io_stall_read_ms AS FLOAT) / CAST(s.num_of_reads AS FLOAT) AS DECIMAL(10, 2)) AS [Read Latency in MS], 17 | CAST(CAST(s.io_stall_write_ms AS FLOAT) / CAST(s.num_of_writes AS FLOAT) AS DECIMAL(10, 2)) AS [Write Latency in MS], 18 | s.num_of_reads AS [Num Reads], 19 | s.num_of_bytes_read / s.num_of_reads AS [Avg Bytes Per Read], 20 | s.num_of_bytes_read / 1024 / 1024 AS [Total Reads in MB], 21 | s.num_of_writes AS [Num Writes], 22 | s.num_of_bytes_written / s.num_of_writes AS [Avg Bytes Per Write], 23 | s.num_of_bytes_written / 1024 / 1024 AS [Total Writes in MB] 24 | FROM 25 | sys.dm_io_virtual_file_stats(NULL, NULL) s 26 | INNER JOIN 27 | sys.master_files f ON f.database_id = s.database_id AND f.file_id = s.file_id 28 | ) 29 | SELECT 30 | [Drive Letter], 31 | [Type], 32 | SUM([Size in MB]) / 1024 AS [Total Size in GB], 33 | AVG([Read Latency in MS]) AS [Avg Read Latency in MS], 34 | AVG([Write Latency in MS]) AS [Avg Write Latency in MS], 35 | SUM([Num Reads]) AS [Num Reads], 36 | SUM([Num Writes]) AS [Num Writes], 37 | SUM([Total Reads in MB]) / 1024 AS [Total Reads in GB], 38 | SUM([Total Writes in MB]) / 1024 AS [Total Writes in GB] 39 | FROM 40 | TMP 41 | GROUP BY 42 | [Type], 43 | [Drive Letter] -------------------------------------------------------------------------------- /IO Subsystem/File IO Usage.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: File IO Usage 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | Requirements: 2005+ 6 | 7 | Usage: 8 | List of all files in use and their IO usage. 9 | ********************************************************************************/ 10 | 11 | SELECT 12 | DB_NAME(s.database_id) AS [Database], 13 | s.file_id AS [File ID], 14 | f.type_desc AS [Type], 15 | f.physical_name AS [Path], 16 | f.is_percent_growth, 17 | s.size_on_disk_bytes / 1024 / 1024 AS [Size in MB], 18 | CAST(CAST(s.io_stall_read_ms AS FLOAT) / CAST(s.num_of_reads AS FLOAT) AS DECIMAL(10, 2)) AS [Read Latency in MS], 19 | CAST(CAST(s.io_stall_write_ms AS FLOAT) / CAST(s.num_of_writes AS FLOAT) AS DECIMAL(10, 2)) AS [Write Latency in MS], 20 | s.num_of_reads AS [Num Reads], 21 | s.num_of_bytes_read / s.num_of_reads AS [Avg Bytes Per Read], 22 | s.num_of_bytes_read / 1024 / 1024 AS [Total Reads in MB], 23 | s.num_of_writes AS [Num Writes], 24 | s.num_of_bytes_written / s.num_of_writes AS [Avg Bytes Per Write], 25 | s.num_of_bytes_written / 1024 / 1024 AS [Total Writes in MB] 26 | FROM 27 | sys.dm_io_virtual_file_stats(NULL, NULL) s 28 | INNER JOIN 29 | sys.master_files f ON f.database_id = s.database_id AND f.file_id = s.file_id 30 | ORDER BY 31 | -- Overall most IOPS expensive 32 | s.num_of_reads + s.num_of_writes DESC 33 | -------------------------------------------------------------------------------- /Indexes/How Are Indexes Being Used.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Title: How are indexes being used 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | */ 6 | 7 | WITH TMP AS ( 8 | SELECT 9 | d.name, 10 | OBJECT_NAME(s.object_id) AS object_name, 11 | ISNULL(i.name, '(Heap)') AS index_name, 12 | user_seeks, 13 | user_scans, 14 | user_lookups, 15 | user_seeks + user_scans + user_lookups as total_reads, 16 | user_updates, 17 | CASE 18 | WHEN (user_seeks + user_scans + user_lookups = 0) THEN 19 | 'UNUSED' 20 | WHEN (user_seeks + user_scans < user_updates) THEN 21 | 'UPDATES > READS' 22 | WHEN (user_seeks < user_scans) THEN 23 | 'SCANS > SEEKS' 24 | ELSE 25 | ' ' 26 | END AS Warning 27 | FROM 28 | sys.dm_db_index_usage_stats s 29 | INNER JOIN 30 | sys.indexes i ON 31 | i.object_id = s.object_id AND 32 | i.index_id = s.index_id 33 | INNER JOIN 34 | sys.databases d ON 35 | d.database_id = s.database_id 36 | WHERE 37 | d.name = DB_NAME() AND 38 | OBJECTPROPERTY(s.object_id, 'IsUserTable') = 1 39 | ) 40 | SELECT * FROM TMP 41 | 42 | -- Top scanned indexes 43 | ORDER BY 44 | user_scans DESC 45 | 46 | -- Bookmark lookups 47 | ORDER BY 48 | user_lookups DESC 49 | 50 | -- Write-only indexes 51 | WHERE 52 | total_reads = 0 53 | -------------------------------------------------------------------------------- /Indexes/Index Defragmentation Suggestions.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Created by: Mark S. Rasmussen 3 | License: CC BY 3.0 4 | */ 5 | 6 | WITH TMP AS 7 | ( 8 | SELECT 9 | DB_NAME(database_id) AS database_name, 10 | OBJECT_NAME(object_id) AS table_name, 11 | (SELECT Name FROM sys.indexes WHERE index_id = ps.index_id AND object_id = ps.object_id) AS index_name, 12 | index_type_desc, 13 | alloc_unit_type_desc, 14 | avg_fragmentation_in_percent, 15 | fragment_count, 16 | avg_fragment_size_in_pages, 17 | page_count, 18 | page_count * 8 / 1024 AS 'disk size MB', 19 | avg_page_space_used_in_percent, 20 | record_count, 21 | min_record_size_in_bytes, 22 | avg_record_size_in_bytes, 23 | CASE 24 | WHEN avg_fragmentation_in_percent BETWEEN 0 AND 30 THEN 25 | 'REORGANIZE' 26 | ELSE 27 | 'REBUILD' 28 | END AS recommendation 29 | FROM 30 | sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL, NULL, 'SAMPLED') ps 31 | WHERE 32 | avg_fragmentation_in_percent > 5 AND 33 | page_count >= 2560 -- We don't care about objects less than 20MB 34 | ), 35 | TMP2 AS 36 | ( 37 | SELECT 38 | *, 39 | 'ALTER INDEX [' + index_name + '] ON dbo.[' + table_name + '] REORGANIZE' AS sql_reorganize, 40 | 'ALTER INDEX [' + index_name + '] ON dbo.[' + table_name + '] REBUILD' AS sql_rebuild 41 | FROM 42 | TMP 43 | ) 44 | SELECT 45 | *, 46 | CASE recommendation 47 | WHEN 'REBUILD' THEN 48 | sql_rebuild 49 | ELSE 50 | sql_reorganize 51 | END AS sql_recommended 52 | FROM 53 | TMP2 54 | ORDER BY 55 | avg_fragmentation_in_percent DESC 56 | -------------------------------------------------------------------------------- /Indexes/Missing Indexes.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Created by: Mark S. Rasmussen 3 | License: CC BY 3.0 4 | 5 | Warning - these suggestions should be taken with a ton of salt! 6 | */ 7 | 8 | SELECT DISTINCT TOP 50 9 | d.index_handle, 10 | d.statement AS table_name, 11 | s.unique_compiles, 12 | s.user_seeks, 13 | s.last_user_seek, 14 | s.avg_total_user_cost, 15 | s.avg_user_impact, 16 | d.equality_columns, 17 | d.inequality_columns, 18 | d.included_columns, 19 | s.avg_total_user_cost + s.avg_user_impact + (s.user_seeks + s.user_scans) AS score 20 | FROM 21 | sys.dm_db_missing_index_details d 22 | CROSS APPLY 23 | sys.dm_db_missing_index_columns (d.index_handle) 24 | INNER JOIN 25 | sys.dm_db_missing_index_groups g ON 26 | g.index_handle = d.index_handle 27 | INNER JOIN 28 | sys.dm_db_missing_index_group_stats s ON 29 | s.group_handle = g.index_group_handle 30 | WHERE 31 | DB_NAME(d.database_id) = DB_NAME() 32 | ORDER BY 33 | s.avg_total_user_cost + s.avg_user_impact + (s.user_seeks + s.user_scans) DESC 34 | -------------------------------------------------------------------------------- /Plan Cache/Clearing Plan Cache.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Clearing Plan Cache 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | These commands can be used to either wipe the whole cache or to just clear 8 | a specific plan from the cache. 9 | ********************************************************************************/ 10 | 11 | /* 12 | This will clear all plans in the cache. Beware that this will cause recompiles 13 | of all queries on the server. This will increase CPU usage so beware before 14 | running this on a production system. 15 | */ 16 | DBCC FREEPROCCACHE 17 | 18 | 19 | 20 | /* 21 | This clears just a single plan by referencing it's plan handle 22 | */ 23 | DBCC FREEPROCCACHE (0x06009800B81B733A40C1D0C1030000000000000000000000) -------------------------------------------------------------------------------- /Plan Cache/Most Used Plans.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Most Used Plans 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | This script can be used to get a list of the most used plans in the plan cache. 8 | These plans are generally the most important ones to make sure are optimized. 9 | If you sort by CP.usecounts ASC rather than DESC, then you'll get a list of the 10 | least used plans which may indicate lack of plan reuse. 11 | ********************************************************************************/ 12 | 13 | SELECT TOP 100 14 | cp.refcounts AS [Reference Count], 15 | cp.usecounts AS [Use Count], 16 | cp.size_in_bytes / 1024 AS [Size in KB], 17 | cp.cacheobjtype AS [Cache Object Type], 18 | cp.objtype AS [Object Type], 19 | st.text AS [Query], 20 | qp.query_plan AS [Plan], 21 | cp.plan_handle AS [Plan Handle] 22 | FROM 23 | sys.dm_exec_cached_plans cp 24 | OUTER APPLY 25 | sys.dm_exec_sql_text(plan_handle) AS st 26 | OUTER APPLY 27 | sys.dm_exec_query_plan(plan_handle) AS qp 28 | ORDER BY 29 | CP.usecounts DESC -------------------------------------------------------------------------------- /Plan Cache/Object Type Plan Cache Usage.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Title: Object Type Plan Cache Usage 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | This script gives an overview of what kind of plans are stored in the plan cache. 8 | A large amount of 'Adhoc' object types indicates a lack of parameterization of 9 | the queries, causing a bloated plan cache. 10 | */ 11 | 12 | SELECT 13 | CASE p.objtype 14 | WHEN 'Prepared' THEN 'Prepared statement' 15 | WHEN 'Adhoc' THEN 'Ad hoc query' 16 | WHEN 'Proc' THEN 'Stored procedure' 17 | WHEN 'UsrTab' THEN 'User table' 18 | WHEN 'SysTab' THEN 'System table' 19 | WHEN 'Check' THEN 'Check constraint' 20 | ELSE p.objtype 21 | END AS [Object Type], 22 | COUNT(*) AS [Number of Plans], 23 | SUM(CASE p.usecounts WHEN 1 THEN 1 ELSE 0 END) AS [Number of Plans (Usecount = 1)], 24 | CAST(SUM(CAST(p.size_in_bytes AS FLOAT)) / 1024 / 1024 AS DECIMAL(10, 2)) AS [Size in MB], 25 | CAST(CAST(SUM(CASE p.usecounts WHEN 1 THEN p.size_in_bytes ELSE 0 END) AS FLOAT) / 1024 / 1024 AS DECIMAL(10, 2)) AS [Size in MB (Usecount = 1)] 26 | FROM 27 | sys.dm_exec_cached_plans p 28 | GROUP BY 29 | p.objtype 30 | ORDER BY 31 | SUM(CAST(p.size_in_bytes AS bigint)) DESC 32 | -------------------------------------------------------------------------------- /Plan Cache/Worst Performing Queries.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Worst Performing Queries 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | Returns a list of the most time consuming queries, server wide. Depending on what 8 | kind of queries you're looking for, you can uncomment the relevant predicates. 9 | ********************************************************************************/ 10 | 11 | WITH TMP AS 12 | ( 13 | SELECT TOP 100 14 | CAST(SUM(s.total_elapsed_time) / 1000000.0 AS DECIMAL(10, 2)) AS [Total Elapsed Time in S], 15 | SUM(s.execution_count) AS [Total Execution Count], 16 | CAST(SUM(s.total_worker_time) / 1000000.0 AS DECIMAL(10, 2)) AS [Total CPU Time in S], 17 | CAST(SUM(s.total_worker_time) / SUM(s.execution_count) / 1000.0 AS DECIMAL(10, 2)) AS [Avg CPU Time in MS], 18 | SUM(s.total_logical_reads) AS [Total Logical Reads], 19 | CAST(CAST(SUM(s.total_logical_reads) AS FLOAT) / CAST(SUM(s.execution_count) AS FLOAT) AS DECIMAL(10, 2)) AS [Avg Logical Reads], 20 | SUM(s.total_logical_writes) AS [Total Logical Writes], 21 | CAST(CAST(SUM(s.total_logical_writes) AS FLOAT) / CAST(SUM(s.execution_count) AS FLOAT) AS DECIMAL(10, 2)) AS [Avg Logical Writes], 22 | SUM(s.total_clr_time) AS [Total CLR Time], 23 | CAST(SUM(s.total_clr_time) / SUM(s.execution_count) / 1000.0 AS DECIMAL(10, 2)) AS [Avg CLR Time in MS], 24 | CAST(SUM(s.min_worker_time) / 1000.0 AS DECIMAL(10, 2)) AS [Min CPU Time in MS], 25 | CAST(SUM(s.max_worker_time) / 1000.0 AS DECIMAL(10, 2)) AS [Max CPU Time in MS], 26 | SUM(s.min_logical_reads) AS [Min Logical Reads], 27 | SUM(s.max_logical_reads) AS [Max Logical Reads], 28 | SUM(s.min_logical_writes) AS [Min Logical Writes], 29 | SUM(s.max_logical_writes) AS [Max Logical Writes], 30 | CAST(SUM(s.min_clr_time) / 1000.0 AS DECIMAL(10, 2)) AS [Min CLR Time in MS], 31 | CAST(SUM(s.max_clr_time) / 1000.0 AS DECIMAL(10, 2)) AS [Max CLR Time in MS], 32 | COUNT(1) AS [Number of Statements], 33 | MAX(s.last_execution_time) AS [Last Execution Time], 34 | s.plan_handle AS [Plan Handle] 35 | FROM 36 | sys.dm_exec_query_stats s 37 | 38 | -- Most CPU consuming 39 | --GROUP BY s.plan_handle ORDER BY SUM(s.total_worker_time) DESC 40 | 41 | -- Most read+write IO consuming 42 | --GROUP BY s.plan_handle ORDER BY SUM(s.total_logical_reads + s.total_logical_writes) DESC 43 | 44 | -- Most write IO consuming 45 | --GROUP BY s.plan_handle ORDER BY SUM(s.total_logical_writes) DESC 46 | 47 | -- Most CLR consuming 48 | --WHERE s.total_clr_time > 0 GROUP BY s.plan_handle ORDER BY SUM(s.total_clr_time) DESC 49 | ) 50 | SELECT 51 | TMP.*, 52 | st.text AS [Query], 53 | qp.query_plan AS [Plan] 54 | FROM 55 | TMP 56 | OUTER APPLY 57 | sys.dm_exec_query_plan(TMP.[Plan Handle]) AS qp 58 | OUTER APPLY 59 | sys.dm_exec_sql_text(TMP.[Plan Handle]) AS st -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Useful-SQL-Server-Queries 2 | ========================= 3 | 4 | This is a collection of queries that I use when dealing with SQL Server, whether I'm looking to improve performance, diagnose IO issues or setup the server. 5 | 6 | Some scripts are made wholly by me, while some are inspired by others - in which case they're properly attributed. If you see anything you don't think belongs here, please let me know at mark@improve.dk. 7 | 8 | 9 | Contribution 10 | ============ 11 | 12 | If you have an awesome script you think belongs here, please either send me a pull request or get in touch with me at mark@improve.dk. 13 | -------------------------------------------------------------------------------- /Server Configuration/Settings Overview.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Settings Overview 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | Requirements: 2005+ 6 | 7 | Usage: 8 | This query is meant to give you an overview of the server level settings as well 9 | as common recommendations. 10 | ********************************************************************************/ 11 | 12 | SELECT 13 | name, 14 | value, 15 | value_in_use, 16 | minimum, 17 | maximum, 18 | description, 19 | is_dynamic, 20 | is_advanced, 21 | CASE 22 | WHEN name = 'backup compression default' AND value = 0 THEN 23 | 'It is generally recommended to enable backup compression unless you'' bound by CPU during backups.' 24 | WHEN name = 'clr enabled' AND value = 1 THEN 25 | 'CLR should only be enabled if it''s needed, otherwise it''s better to leave it disabled.' 26 | WHEN name = 'max server memory (MB)' AND value = 2147483647 THEN 27 | 'You should always specify a max value for the ''max server memory'' setting to avoid SQL Server starving the OS and/or other instances.' 28 | WHEN name = 'optimize for ad hoc workloads' AND value = 0 THEN 29 | 'You should generally always enable the ''optimize for adhoc workloads'' setting.' 30 | ELSE 31 | NULL 32 | END AS Recommendation 33 | FROM 34 | sys.configurations 35 | ORDER BY 36 | name 37 | -------------------------------------------------------------------------------- /Statistics/Index Statistics That Havent Been Updated Recently.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Index Statistics That Haven't Been Updated Recently 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | Running this returns a list of all statistics on indexes, including the last 8 | update date. Use this to find statistics that need to be updated, either by 9 | filtering on the object/index name or by the updated date directly. 10 | ********************************************************************************/ 11 | 12 | SELECT 13 | SCHEMA_NAME(o.schema_id) + '.' + o.name AS [Object Name], 14 | i.name AS [Index Name], 15 | i.type_desc AS [Index Type], 16 | STATS_DATE(i.object_id, i.index_id) AS [Last Updated] 17 | FROM 18 | sys.indexes i 19 | INNER JOIN 20 | sys.objects o ON o.object_id = i.object_id 21 | WHERE 22 | o.type = 'U' 23 | ORDER BY 24 | [Last Updated] -------------------------------------------------------------------------------- /Statistics/Statistics Overview.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Statistics Overview 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | This query is meant to give you an overview of the statistics created in the 8 | database. Each table is listed with each of its statistics, as well as the 9 | statistic properties. 10 | ********************************************************************************/ 11 | 12 | SELECT 13 | SCHEMA_NAME(o.schema_id) + '.' + o.name AS [Object Name], 14 | STATS_DATE(s.object_id, s.stats_id) AS [Last Updated], 15 | s.name AS [Stats Name], 16 | s.stats_id AS [Stats ID], 17 | s.auto_created AS [Stats Auto Created], 18 | s.user_created AS [Stats User Created], 19 | s.no_recompute AS [Stats Auto Update], 20 | s.has_filter AS [Stats Filtered], 21 | s.filter_definition AS [Stats Filter Definition] 22 | FROM 23 | sys.stats s 24 | INNER JOIN 25 | sys.objects o ON o.object_id = s.object_id 26 | WHERE 27 | o.type = 'U' 28 | ORDER BY 29 | [Object Name], 30 | [Stats Name] -------------------------------------------------------------------------------- /Statistics/Updating Statistics.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Updating Statistics 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | Here's a number of different ways to update statistics, depending on what you 8 | need to accomplish. 9 | ********************************************************************************/ 10 | 11 | -- Updates all stats on the table/indexes by using a full table scan 12 | UPDATE STATISTICS [Table] WITH FULLSCAN 13 | 14 | -- Updates all stats on the table/indexes by sampling 10 percent of the data 15 | UPDATE STATISTICS [Table] WITH SAMPLE 10 PERCENT 16 | 17 | -- Updates all stats on the table/indexes by sampling the first 1000 rows 18 | UPDATE STATISTICS [Table] WITH SAMPLE 1000 ROWS 19 | 20 | -- Updates all statistics for the specified index/table combo 21 | UPDATE STATISTICS [Table] [Index] 22 | 23 | -- Updates the specified statistics on the specified table 24 | UPDATE STATISTICS [Table]([Statistics Name]) -------------------------------------------------------------------------------- /Third Party Scripts/sp_blitz.txt: -------------------------------------------------------------------------------- 1 | http://www.brentozar.com/blitz/ -------------------------------------------------------------------------------- /Third Party Scripts/sp_whoisactive_v11.11.txt: -------------------------------------------------------------------------------- 1 | http://sqlblog.com/blogs/adam_machanic/archive/2012/03/22/released-who-is-active-v11-11.aspx -------------------------------------------------------------------------------- /Wait Statistics/Clear Wait Stats.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Clear Wait Stats 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | 6 | Usage: 7 | Running this clears all wait statistics for the server as a whole. This does not 8 | impact performance in any way. 9 | ********************************************************************************/ 10 | 11 | DBCC SQLPERF('sys.dm_os_wait_stats', CLEAR) -------------------------------------------------------------------------------- /Wait Statistics/Wait Statistics Overview.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************** 2 | Title: Wait Statistics Overview 3 | Created by: Mark S. Rasmussen 4 | License: CC BY 3.0 5 | Attribution: Inspired by Paul Randals script here (which is based on scripts by Glenn Berry) 6 | http://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/ 7 | 8 | Usage: 9 | Run this script to get an overview of the most important waits going on on the 10 | server. Waits types that take up less than 1% are not included in the output. 11 | ********************************************************************************/ 12 | 13 | ;WITH TMP AS 14 | ( 15 | SELECT 16 | wait_type AS [Wait Type], 17 | waiting_tasks_count AS [Count], 18 | CAST(wait_time_ms / 1000.0 AS DECIMAL(14, 2)) AS [Wait Time in S], 19 | CAST(signal_wait_time_ms / 1000.0 AS DECIMAL(14, 2)) AS [Signal Wait Time in S], 20 | wait_time_ms / waiting_tasks_count AS [Wait Per Task in MS], 21 | max_wait_time_ms AS [Max Wait Time in S], 22 | CAST((wait_time_ms - signal_wait_time_ms) / 1000.0 AS DECIMAL(14, 2)) AS [Resource Wait Time in S] 23 | FROM 24 | sys.dm_os_wait_stats 25 | WHERE 26 | wait_time_ms - signal_wait_time_ms > 0 AND 27 | wait_type NOT IN ( 28 | 'CLR_SEMAPHORE', 'LAZYWRITER_SLEEP', 'RESOURCE_QUEUE', 'SLEEP_TASK', 29 | 'SLEEP_SYSTEMTASK', 'SQLTRACE_BUFFER_FLUSH', 'WAITFOR', 'LOGMGR_QUEUE', 30 | 'CHECKPOINT_QUEUE', 'REQUEST_FOR_DEADLOCK_SEARCH', 'XE_TIMER_EVENT', 'BROKER_TO_FLUSH', 31 | 'BROKER_TASK_STOP', 'CLR_MANUAL_EVENT', 'CLR_AUTO_EVENT', 'DISPATCHER_QUEUE_SEMAPHORE', 32 | 'FT_IFTS_SCHEDULER_IDLE_WAIT', 'XE_DISPATCHER_WAIT', 'XE_DISPATCHER_JOIN', 'BROKER_EVENTHANDLER', 33 | 'TRACEWRITE', 'FT_IFTSHC_MUTEX', 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', 34 | 'BROKER_RECEIVE_WAITFOR', 'ONDEMAND_TASK_QUEUE', 'DBMIRROR_EVENTS_QUEUE', 35 | 'DBMIRRORING_CMD', 'BROKER_TRANSMITTER', 'SQLTRACE_WAIT_ENTRIES', 36 | 'SLEEP_BPOOL_FLUSH', 'SQLTRACE_LOCK', 'HADR_FILESTREAM_IOMGR_IOCOMPLETION', 'DIRTY_PAGE_POLL', 37 | 'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', 'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP' 38 | ) 39 | ), TMP2 AS ( 40 | SELECT 41 | [Wait Type], 42 | CAST([Wait Time in S] / SUM([Wait Time in S]) OVER() * 100 AS DECIMAL(14, 2)) AS [Percentage], 43 | [Wait Time in S], 44 | [Wait Time in S] - [Signal Wait Time in S] AS [Resource Wait Time in S], 45 | [Signal Wait Time in S], 46 | CAST([Wait Time in S] / [Count] * 1000 AS DECIMAL(14, 2)) AS [Avg Wait in MS], 47 | CAST([Resource Wait Time in S] / [Count] * 1000 AS DECIMAL(14, 2)) AS [Avg Resource Waint in MS], 48 | CAST([Signal Wait Time in S] / [Count] * 1000 AS DECIMAL(14, 2)) AS [Avg Signal Wait in MS], 49 | [Count] 50 | FROM 51 | TMP 52 | ) 53 | SELECT 54 | * 55 | FROM 56 | TMP2 57 | WHERE 58 | Percentage >= 1 -- Percentage threshold 59 | ORDER BY 60 | Percentage DESC 61 | --------------------------------------------------------------------------------