├── LICENSE.md ├── README.md ├── sp_IndexAnalysis-AzureSQLDatabase.sql ├── sp_IndexAnalysis-SQLServer2005.sql ├── sp_IndexAnalysis-SQLServer2008.sql ├── sp_IndexAnalysis-SQLServer2012.sql ├── sp_IndexAnalysis-SQLServer2014.sql └── sp_IndexAnalysis-SQLServer2016.sql /LICENSE.md: -------------------------------------------------------------------------------- 1 | # License for Index Analysis Script 2 | 3 | **Copyright © 2016, Jason Strate** 4 | 5 | --- 6 | 7 | ## Feedback and Contact 8 | If you have any questions, feedback, or suggestions, please feel free to reach out: 9 | - **Email**: [jasonstrate@gmail.com](mailto:jasonstrate@gmail.com) 10 | - **Website**: [www.jasonstrate.com](http://www.jasonstrate.com) 11 | 12 | --- 13 | 14 | ## Terms of Use 15 | This script is free to download and use under the following conditions: 16 | 1. **Permitted Uses**: 17 | - Personal projects 18 | - Educational purposes 19 | - Internal corporate use 20 | 2. **Preservation**: 21 | - This license header must remain intact in all copies of the script. 22 | 3. **Prohibited Uses**: 23 | - Redistribution or sale of this script, either in whole or in part, without prior written consent from the author. 24 | 25 | --- 26 | 27 | By using this script, you agree to abide by the terms outlined above. Unauthorized redistribution or commercialization is strictly prohibited. 28 | 29 | **Thank you for using the Index Analysis Script!** 30 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL Server Index Analysis 2 | 3 | This repository provides a stored procedure for analyzing SQL Server indexes, offering insights into potential optimizations, such as creating, modifying, or dropping indexes. The recommendations are intended as guidelines and should be adapted based on your knowledge and experience with the database. 4 | 5 | --- 6 | 7 | ## ⚠️ Important Notes 8 | - Recommendations in the **Index Action** column are not definitive but serve as starting points for further analysis. Always apply your expertise and knowledge of the database before making changes. 9 | - DMV (Dynamic Management Views) data is reset: 10 | - When the SQL Server service restarts. 11 | - When the database is brought online. 12 | - When index metadata is updated, such as during reindex operations. 13 | - Index statistics in `sys.dm_db_index_operational_stats` and `sys.dm_db_index_usage_stats` are cleared when an index is rebuilt. 14 | - Missing index statistics in the `sys.dm_db_missing_index_*` DMVs are reset whenever a new index is created on a table. 15 | - Names in the **Index Name** column for non-existent indexes are placeholders, not recommended names. 16 | 17 | --- 18 | 19 | ## 📊 Parameters 20 | | Parameter | Type | Description | 21 | |-------------------------------|-------------------|-----------------------------------------------------------------------------| 22 | | `@TableName` | `NVARCHAR(256)` | (Optional) Specifies the table to analyze. | 23 | | `@IncludeMissingIndexes` | `BIT` | Include missing indexes in the output. | 24 | | `@IncludeMissingFKIndexes` | `BIT` | Include missing foreign key indexes in the output. | 25 | | `@Output` | `VARCHAR(20)` | Determines the output format: `DETAILED`, `DUPLICATE`, or `OVERLAPPING`. | 26 | 27 | --- 28 | 29 | ## 📖 Output Columns 30 | | Column Name | Description | 31 | |------------------------------|----------------------------------------------------------------------------------------------------------------| 32 | | **index_action** | Recommended action for the index (e.g., `CREATE`, `DROP-DUP`, `DROP-USAGE`, `REALIGN`, `BLEND`). | 33 | | **index_pros** | Benefits of the index (e.g., foreign key (`FK`), unique constraint (`UQ`), read-to-write ratio). | 34 | | **index_cons** | Drawbacks of the index (e.g., low seeks-to-scans ratio, duplicate, overlapping, or high write costs). | 35 | | **filegroup** | Filegroup where the index resides. | 36 | | **table_name** | Name of the table. | 37 | | **index_name** | Name of the index. | 38 | | **is_unique** | Indicates if the index is unique. | 39 | | **size_in_mb** | Disk space (in MB) used by the index. | 40 | | **pct_in_buffer** | Percentage of the index currently in the SQL Server buffer. | 41 | | **row_count** | Number of rows in the index. | 42 | | **missing_index_impact** | Calculated impact of a potential index (based on seeks, scans, and average improvement). | 43 | | **user_total** | Total seek, scan, and lookup operations for the index. | 44 | | **read_to_update_ratio** | Ratio of read operations to update operations. | 45 | | **row_lock_count** | Cumulative number of row locks requested. | 46 | | **leaf_page_allocations** | Number of page splits at the leaf level. | 47 | | **indexed_columns** | List of columns in the index, missing index, or foreign key. | 48 | | **duplicate_indexes** | List of duplicate indexes on the table. | 49 | | **related_foreign_keys** | Related foreign keys associated with the index. | 50 | 51 | For a detailed description of all columns, see the source code or documentation. 52 | 53 | --- 54 | 55 | ## 💡 Index Action Recommendations 56 | - **CREATE**: Add a new index to improve performance. 57 | - **DROP-DUP**: Remove duplicate indexes. 58 | - **DROP-USAGE**: Remove indexes with low usage or high cost. 59 | - **BLEND**: Merge missing index details into an existing index. 60 | - **REALIGN**: Adjust clustered indexes or include additional columns. 61 | 62 | --- 63 | 64 | ## 📜 Example Usage 65 | ```sql 66 | EXEC dbo.IndexAnalysis 67 | @TableName = 'MyTable', 68 | @IncludeMissingIndexes = 1, 69 | @Output = 'DETAILED'; 70 | -------------------------------------------------------------------------------- /sp_IndexAnalysis-AzureSQLDatabase.sql: -------------------------------------------------------------------------------- 1 | IF OBJECT_ID('dbo.sp_IndexAnalysis') IS NOT NULL 2 | DROP PROCEDURE [dbo].[sp_IndexAnalysis]; 3 | GO 4 | 5 | /********************************************************************************************* 6 | Index Analysis Script - SQL Server 2008 7 | (C) 2013, Jason Strate 8 | 9 | Feedback: 10 | mailto:jasonstrate@gmail.com 11 | http://www.jasonstrate.com 12 | 13 | License: 14 | This query is free to download and use for personal, educational, and internal 15 | corporate purposes, provided that this header is preserved. Redistribution or sale 16 | of this query, in whole or in part, is prohibited without the author's express 17 | written consent. 18 | 19 | More details: 20 | https://github.com/StrateSQL/sqlserver_indexanalysis 21 | 22 | *********************************************************************************************/ 23 | CREATE PROCEDURE [dbo].[sp_IndexAnalysis] 24 | ( 25 | @TableName NVARCHAR(256) = NULL , 26 | @IncludeMemoryDetails BIT = 1 , 27 | @IncludeMissingIndexes BIT = 1 , 28 | @IncludeMissingFKIndexes BIT = 1 , 29 | @ConsolidatePartitionStats BIT = 1 , 30 | @Output VARCHAR(20) = 'DUMP' , 31 | @PageCompressionThreshold INT = 1000 , 32 | @RowCompressionThreshold DECIMAL(4, 2) = 1 , 33 | @CheckCompression BIT = 1 , 34 | @ReadOnlyDatabase BIT = 0 , 35 | @MaxMissingIndexCount TINYINT = 5 , 36 | @MinLookupThreshold INT = 1000 , 37 | @MinScanThreshold INT = 100 , 38 | @Scan2SeekRatio INT = 1000 , 39 | @ProcessingMessages BIT = 0 40 | ) 41 | WITH RECOMPILE 42 | AS 43 | BEGIN 44 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 45 | SET NOCOUNT ON; 46 | 47 | DECLARE @ERROR_MESSAGE NVARCHAR(2048) , 48 | @ERROR_SEVERITY INT , 49 | @ERROR_STATE INT , 50 | @PROCESSING_START DATETIME; 51 | 52 | DECLARE @SQL NVARCHAR(MAX) , 53 | @DB_ID INT , 54 | @ObjectID INT , 55 | @DatabaseName NVARCHAR(MAX); 56 | 57 | BEGIN TRY 58 | --================================================================================================ 59 | -- Remove temporary tables 60 | --================================================================================================ 61 | IF OBJECT_ID('tempdb..#MemoryBuffer') IS NOT NULL 62 | DROP TABLE [#MemoryBuffer]; 63 | 64 | IF OBJECT_ID('tempdb..#TableMeta') IS NOT NULL 65 | DROP TABLE [#TableMeta]; 66 | 67 | IF OBJECT_ID('tempdb..#IndexMeta') IS NOT NULL 68 | DROP TABLE [#IndexMeta]; 69 | 70 | IF OBJECT_ID('tempdb..#IndexStatistics') IS NOT NULL 71 | DROP TABLE [#IndexStatistics]; 72 | 73 | IF OBJECT_ID('tempdb..#ForeignKeys') IS NOT NULL 74 | DROP TABLE [#ForeignKeys]; 75 | 76 | IF @Output NOT IN ('DUMP', 'DETAILED', 'DUPLICATE', 'OVERLAPPING', 'REALIGN') 77 | RAISERROR('The value "%s" provided for the @Output parameter is not valid',16,1,@Output); 78 | 79 | SELECT @DB_ID = DB_ID() , 80 | @ObjectID = OBJECT_ID(QUOTENAME(DB_NAME(DB_ID())) + '.' + COALESCE(QUOTENAME(PARSENAME(@TableName, 2)), '') + '.' 81 | + QUOTENAME(PARSENAME(@TableName, 1))) , 82 | @DatabaseName = QUOTENAME(DB_NAME(DB_ID())); 83 | 84 | IF @TableName IS NOT NULL 85 | AND @ObjectID IS NULL 86 | RAISERROR('The object "%s" could not be found. Execution cancelled.',16,1,@TableName); 87 | 88 | -- Obtain memory buffer information on database objects 89 | CREATE TABLE [#MemoryBuffer] 90 | ( 91 | [database_id] INT , 92 | [object_id] INT , 93 | [index_id] INT , 94 | [partition_number] INT , 95 | [buffered_page_count] INT , 96 | [buffered_mb] DECIMAL(12, 2) 97 | ); 98 | 99 | IF @IncludeMemoryDetails = 1 100 | BEGIN 101 | SET @PROCESSING_START = GETDATE(); 102 | SET @SQL = 'WITH AllocationUnits 103 | AS ( 104 | SELECT p.object_id 105 | ,p.index_id 106 | ,CASE WHEN @ConsolidatePartitionStats = 0 THEN p.partition_number ELSE -1 END AS partition_number 107 | ,au.allocation_unit_id 108 | FROM ' + @DatabaseName + '.sys.allocation_units AS au 109 | INNER JOIN ' + @DatabaseName + '.sys.partitions AS p ON au.container_id = p.hobt_id AND (au.type = 1 OR au.type = 3) 110 | UNION ALL 111 | SELECT p.object_id 112 | ,p.index_id 113 | ,CASE WHEN @ConsolidatePartitionStats = 0 THEN p.partition_number ELSE -1 END AS partition_number 114 | ,au.allocation_unit_id 115 | FROM ' + @DatabaseName + '.sys.allocation_units AS au 116 | INNER JOIN ' + @DatabaseName + '.sys.partitions AS p ON au.container_id = p.partition_id AND au.type = 2 117 | ) 118 | SELECT DB_ID() 119 | ,au.object_id 120 | ,au.index_id 121 | ,au.partition_number 122 | ,COUNT(*) AS buffered_page_count 123 | ,CONVERT(DECIMAL(12,2), CAST(COUNT(*) as bigint)*CAST(8 as float)/1024) as buffer_mb 124 | FROM ' + @DatabaseName + '.sys.dm_os_buffer_descriptors AS bd 125 | INNER JOIN AllocationUnits au ON bd.allocation_unit_id = au.allocation_unit_id 126 | WHERE bd.database_id = db_id() 127 | GROUP BY au.object_id, au.index_id, au.partition_number 128 | '; 129 | 130 | BEGIN TRY 131 | IF @ConsolidatePartitionStats = 1 132 | BEGIN 133 | RAISERROR('Strate''s Warning: Buffered memory totals are an aggregate for all partitions on the table. This behaviour is controlled by the @ConsolidatePartitionStats parameter',10,1) WITH NOWAIT; 134 | PRINT ''; 135 | END; 136 | 137 | INSERT INTO [#MemoryBuffer] 138 | EXEC [sys].[sp_executesql] @SQL, N'@ConsolidatePartitionStats BIT', @ConsolidatePartitionStats = @ConsolidatePartitionStats; 139 | 140 | IF @ProcessingMessages = 1 141 | PRINT 'Processing #MemoryBuffer... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 142 | END TRY 143 | BEGIN CATCH 144 | SELECT @ERROR_MESSAGE = 'Populate #MemoryBuffer (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 145 | @ERROR_SEVERITY = ERROR_SEVERITY() , 146 | @ERROR_STATE = ERROR_STATE(); 147 | 148 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 149 | END CATCH; 150 | END; 151 | 152 | -- Obtain index meta data information 153 | BEGIN 154 | SET @PROCESSING_START = GETDATE(); 155 | 156 | CREATE TABLE [#TableMeta] 157 | ( 158 | [database_id] SMALLINT , 159 | [schema_id] INT , 160 | [schema_name] NVARCHAR(128) , 161 | [object_id] INT , 162 | [table_name] NVARCHAR(128) , 163 | [object_name] NVARCHAR(260) , 164 | [table_column_count] SMALLINT , 165 | [table_row_count] BIGINT , 166 | [has_unique] BIT 167 | ); 168 | 169 | SET @SQL = N'SELECT 170 | DB_ID() 171 | , s.schema_id 172 | , s.name 173 | , t.object_id 174 | , t.name 175 | , QUOTENAME(s.name)+''.''+QUOTENAME(t.name) 176 | , c2.table_column_count 177 | , ps2.row_count 178 | , CASE WHEN i2.is_unique > 0 THEN 1 ELSE 0 END 179 | FROM ' + @DatabaseName + '.sys.tables t 180 | INNER JOIN ' + @DatabaseName + '.sys.schemas s ON t.schema_id = s.schema_id 181 | CROSS APPLY (SELECT SUM(row_count) AS row_count FROM ' + @DatabaseName 182 | + '.sys.dm_db_partition_stats ps WHERE t.object_id = ps.object_id AND ps.index_id IN (0,1)) ps2 183 | CROSS APPLY (SELECT COUNT(*) AS table_column_count FROM ' + @DatabaseName + '.sys.columns c1 WHERE t.object_id = c1.object_id) c2 184 | CROSS APPLY (SELECT COUNT(*) AS is_unique FROM ' + @DatabaseName + '.sys.indexes i1 WHERE t.object_id = i1.object_id AND is_unique = 1) i2'; 185 | 186 | IF @ObjectID IS NOT NULL 187 | SET @SQL = @SQL + CHAR(13) + 'WHERE t.object_id = @ObjectID '; 188 | 189 | BEGIN TRY 190 | INSERT INTO [#TableMeta] 191 | EXEC [sys].[sp_executesql] @SQL, N'@DB_ID INT, @ObjectID INT', @DB_ID = @DB_ID, @ObjectID = @ObjectID; 192 | 193 | IF @ProcessingMessages = 1 194 | PRINT 'Processing #TableMeta... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 195 | END TRY 196 | BEGIN CATCH 197 | SELECT @ERROR_MESSAGE = 'Populate #TableMeta (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 198 | @ERROR_SEVERITY = ERROR_SEVERITY() , 199 | @ERROR_STATE = ERROR_STATE(); 200 | 201 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 202 | END CATCH; 203 | END; 204 | 205 | BEGIN 206 | SET @PROCESSING_START = GETDATE(); 207 | 208 | CREATE TABLE [#IndexMeta] 209 | ( 210 | [database_id] SMALLINT , 211 | [object_id] INT , 212 | [filegroup_name] NVARCHAR(128) , 213 | [compression_type] NVARCHAR(128) , 214 | [index_id] INT , 215 | [index_name] NVARCHAR(128) , 216 | [partition_count] SMALLINT , 217 | [partition_number] INT , 218 | [is_primary_key] BIT , 219 | [is_unique] BIT , 220 | [is_disabled] BIT , 221 | [type_desc] NVARCHAR(128) , 222 | [fill_factor] TINYINT , 223 | [is_padded] BIT , 224 | [reserved_page_count] BIGINT , 225 | [used_page_count] BIGINT , 226 | [size_in_mb] DECIMAL(12, 2) , 227 | [index_row_count] BIGINT , 228 | [filter_definition] NVARCHAR(MAX) , 229 | [indexed_columns] NVARCHAR(MAX) , 230 | [indexed_column_count] SMALLINT , 231 | [included_columns] NVARCHAR(MAX) , 232 | [included_column_count] SMALLINT , 233 | [key_columns] NVARCHAR(MAX) , 234 | [data_columns] NVARCHAR(MAX) , 235 | [indexed_columns_ids] NVARCHAR(1024) , 236 | [included_column_ids] NVARCHAR(1024) , 237 | [distinct_indexed_columns_ids] NVARCHAR(1024) 238 | ); 239 | 240 | 241 | SET @SQL = N'SELECT 242 | database_id = DB_ID() 243 | , object_id = t.object_id 244 | , filegroup = ds.name 245 | , x.data_compression_desc 246 | , i.index_id 247 | , index_name = COALESCE(i.name, ''N/A'') 248 | , x.partition_count 249 | , x.partition_number 250 | , i.is_primary_key 251 | , i.is_unique 252 | , i.is_disabled 253 | , type_desc = CASE WHEN i.is_unique = 1 THEN ''UNIQUE '' ELSE '''' END + i.type_desc 254 | , i.fill_factor 255 | , i.is_padded 256 | , x.reserved_page_count 257 | , x.used_page_count 258 | , size_in_mb = CAST(reserved_page_count * CAST(8 as float) / 1024 as DECIMAL(12,2)) 259 | , row_count 260 | , i.filter_definition 261 | , indexed_columns = STUFF(( 262 | SELECT '', '' + QUOTENAME(c.name) 263 | FROM ' + @DatabaseName + '.sys.index_columns ic 264 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 265 | WHERE i.object_id = ic.object_id 266 | AND i.index_id = ic.index_id 267 | AND is_included_column = 0 268 | ORDER BY key_ordinal ASC 269 | FOR XML PATH('''')), 1, 2, '''') 270 | , indexed_column_count = ( 271 | SELECT COUNT(*) 272 | FROM ' + @DatabaseName + '.sys.index_columns ic 273 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 274 | WHERE i.object_id = ic.object_id 275 | AND i.index_id = ic.index_id 276 | AND is_included_column = 0) 277 | , included_columns = STUFF(( 278 | SELECT '', '' + QUOTENAME(c.name) 279 | FROM ' + @DatabaseName + '.sys.index_columns ic 280 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 281 | WHERE i.object_id = ic.object_id 282 | AND i.index_id = ic.index_id 283 | AND is_included_column = 1 284 | ORDER BY key_ordinal ASC 285 | FOR XML PATH('''')), 1, 2, '''') 286 | , included_column_count = ( 287 | SELECT COUNT(*) 288 | FROM ' + @DatabaseName + '.sys.index_columns ic 289 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 290 | WHERE i.object_id = ic.object_id 291 | AND i.index_id = ic.index_id 292 | AND is_included_column = 1) 293 | , key_columns = STUFF(( 294 | SELECT '', '' + QUOTENAME(c.name) 295 | FROM ' + @DatabaseName + '.sys.index_columns ic 296 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 297 | WHERE i.object_id = ic.object_id 298 | AND i.index_id = ic.index_id 299 | AND is_included_column = 0 300 | ORDER BY key_ordinal ASC 301 | FOR XML PATH('''')) 302 | + COALESCE((SELECT '', '' + QUOTENAME(c.name) 303 | FROM ' + @DatabaseName + '.sys.index_columns ic 304 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 305 | LEFT OUTER JOIN ' + @DatabaseName + '.sys.index_columns ic_key ON c.object_id = ic_key.object_id 306 | AND c.column_id = ic_key.column_id 307 | AND i.index_id = ic_key.index_id 308 | AND ic_key.is_included_column = 0 309 | WHERE i.object_id = ic.object_id 310 | AND ic.index_id = 1 311 | AND ic.is_included_column = 0 312 | AND ic_key.index_id IS NULL 313 | ORDER BY ic.key_ordinal ASC 314 | FOR XML PATH('''')),''''), 1, 2, '''') 315 | , data_columns = CASE WHEN i.index_id IN (0,1) THEN ''ALL-COLUMNS'' ELSE STUFF(( 316 | SELECT '', '' + QUOTENAME(c.name) 317 | FROM ' + @DatabaseName + '.sys.index_columns ic 318 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 319 | LEFT OUTER JOIN ' + @DatabaseName 320 | + '.sys.index_columns ic_key ON c.object_id = ic_key.object_id AND c.column_id = ic_key.column_id AND ic_key.index_id = 1 321 | WHERE i.object_id = ic.object_id 322 | AND i.index_id = ic.index_id 323 | AND ic.is_included_column = 1 324 | AND ic_key.index_id IS NULL 325 | ORDER BY ic.key_ordinal ASC 326 | FOR XML PATH('''')), 1, 2, '''') END 327 | , indexed_column_ids = (SELECT QUOTENAME(CAST(ic.column_id AS VARCHAR(10)) 328 | + CASE WHEN ic.is_descending_key = 0 THEN ''+'' ELSE ''-'' END,''('') 329 | FROM ' + @DatabaseName + '.sys.index_columns ic 330 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 331 | WHERE i.object_id = ic.object_id 332 | AND i.index_id = ic.index_id 333 | AND is_included_column = 0 334 | ORDER BY key_ordinal ASC 335 | FOR XML PATH('''')) 336 | + ''|'' + COALESCE((SELECT QUOTENAME(CAST(ic.column_id AS VARCHAR(10)) 337 | + CASE WHEN ic.is_descending_key = 0 THEN ''+'' ELSE ''-'' END, ''('') 338 | FROM ' + @DatabaseName + '.sys.index_columns ic 339 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 340 | LEFT OUTER JOIN ' + @DatabaseName + '.sys.index_columns ic_key ON c.object_id = ic_key.object_id 341 | AND c.column_id = ic_key.column_id 342 | AND i.index_id = ic_key.index_id 343 | AND ic_key.is_included_column = 0 344 | WHERE i.object_id = ic.object_id 345 | AND ic.index_id = 1 346 | AND ic.is_included_column = 0 347 | AND ic_key.index_id IS NULL 348 | ORDER BY ic.key_ordinal ASC 349 | FOR XML PATH('''')),'''') 350 | + CASE WHEN i.is_unique = 1 THEN ''U'' ELSE '''' END 351 | , included_column_ids = CASE WHEN i.index_id IN (0,1) THEN ''ALL-COLUMNS'' ELSE 352 | COALESCE((SELECT QUOTENAME(ic.column_id,''('') 353 | FROM ' + @DatabaseName + '.sys.index_columns ic 354 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 355 | LEFT OUTER JOIN ' + @DatabaseName 356 | + '.sys.index_columns ic_key ON c.object_id = ic_key.object_id AND c.column_id = ic_key.column_id AND ic_key.index_id = 1 357 | WHERE i.object_id = ic.object_id 358 | AND i.index_id = ic.index_id 359 | AND ic.is_included_column = 1 360 | AND ic_key.index_id IS NULL 361 | ORDER BY ic.key_ordinal ASC 362 | FOR XML PATH('''')), SPACE(0)) END 363 | , distinct_indexed_columns_ids = (SELECT QUOTENAME(ic.column_id) 364 | FROM ' + @DatabaseName + '.sys.index_columns ic 365 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON c.object_id = ic.object_id AND c.column_id = ic.column_id 366 | WHERE ic.object_id = i.object_id 367 | AND (ic.index_id = i.index_id OR ic.index_id = 1) 368 | AND is_included_column = 0 369 | GROUP BY ic.column_id 370 | ORDER BY ic.column_id 371 | FOR XML PATH('''')) 372 | FROM ' + @DatabaseName + '.sys.tables t 373 | INNER JOIN ' + @DatabaseName + '.sys.schemas s ON t.schema_id = s.schema_id 374 | INNER JOIN ' + @DatabaseName + '.sys.indexes i ON t.object_id = i.object_id 375 | INNER JOIN ' + @DatabaseName + '.sys.data_spaces ds ON i.data_space_id = ds.data_space_id 376 | CROSS APPLY (SELECT p.object_id , 377 | p.index_id , 378 | CASE WHEN @ConsolidatePartitionStats = 0 THEN p.partition_number ELSE -1 END AS partition_number, 379 | COUNT(*) AS partition_count, 380 | SUM(ps.row_count) AS row_count, 381 | CASE 1.*SUM(p.data_compression)/NULLIF(COUNT(*),0) 382 | WHEN 0 THEN ''NONE'' 383 | WHEN 1 THEN ''ROW'' 384 | WHEN 2 THEN ''PAGE'' 385 | ELSE ''MIXED'' END AS data_compression_desc, 386 | SUM(ps.in_row_data_page_count) AS in_row_data_page_count, 387 | SUM(ps.in_row_used_page_count) AS in_row_used_page_count , 388 | SUM(ps.in_row_reserved_page_count) AS in_row_reserved_page_count, 389 | SUM(ps.lob_used_page_count) AS lob_used_page_count, 390 | SUM(ps.lob_reserved_page_count) AS lob_reserved_page_count, 391 | SUM(ps.row_overflow_used_page_count) AS row_overflow_used_page_count, 392 | SUM(ps.row_overflow_reserved_page_count) AS row_overflow_reserved_page_count, 393 | SUM(ps.used_page_count) AS used_page_count , 394 | SUM(ps.reserved_page_count) AS reserved_page_count 395 | FROM ' + @DatabaseName + '.sys.partitions p 396 | INNER JOIN ' + @DatabaseName 397 | + '.sys.dm_db_partition_stats ps ON ps.object_id = p.object_id AND ps.index_id = p.index_id AND ps.partition_id = p.partition_id 398 | WHERE i.object_id = p.object_id AND i.index_id = p.index_id 399 | GROUP BY p.object_id, p.index_id, CASE WHEN @ConsolidatePartitionStats = 0 THEN p.partition_number ELSE -1 END) x 400 | '; 401 | 402 | IF @ObjectID IS NOT NULL 403 | SET @SQL = @SQL + CHAR(13) + 'WHERE t.object_id = @ObjectID '; 404 | 405 | BEGIN TRY 406 | IF @ConsolidatePartitionStats = 1 407 | BEGIN 408 | RAISERROR('Strate''s Warning: Page count totals are a summary of all partitions. This behaviour is controlled by the @ConsolidatePartitionStats parameter',10,1) WITH NOWAIT; 409 | PRINT ''; 410 | END; 411 | 412 | INSERT INTO [#IndexMeta] 413 | EXEC [sys].[sp_executesql] @SQL, N'@DB_ID INT, @ObjectID INT, @ConsolidatePartitionStats INT', @DB_ID = @DB_ID, @ObjectID = @ObjectID, 414 | @ConsolidatePartitionStats = @ConsolidatePartitionStats; 415 | 416 | IF @ProcessingMessages = 1 417 | PRINT 'Processing #IndexMeta... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 418 | END TRY 419 | BEGIN CATCH 420 | SELECT @ERROR_MESSAGE = 'Populate #IndexMeta (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 421 | @ERROR_SEVERITY = ERROR_SEVERITY() , 422 | @ERROR_STATE = ERROR_STATE(); 423 | 424 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 425 | END CATCH; 426 | END; 427 | 428 | BEGIN 429 | SET @PROCESSING_START = GETDATE(); 430 | 431 | IF @ConsolidatePartitionStats = 1 432 | BEGIN 433 | RAISERROR('Strate''s Warning: Index operational stats (locking, blocking, latching, etc.) are summarized from all partitions. This behaviour is controlled by the @ConsolidatePartitionStats parameter',10,1) WITH NOWAIT; 434 | PRINT ''; 435 | END; 436 | ELSE 437 | BEGIN 438 | RAISERROR('Strate''s Warning: Index usage stats are summarized at the index level, per partition data is not available.',10,1) WITH NOWAIT; 439 | PRINT ''; 440 | END; 441 | 442 | SELECT IDENTITY( INT,1,1 ) AS [row_id] , 443 | CAST('' AS VARCHAR(10)) AS [index_action] , 444 | CAST('' AS VARCHAR(50)) AS [index_pros] , 445 | CAST('' AS VARCHAR(50)) AS [index_cons] , 446 | [tm].[database_id] , 447 | [im].[filegroup_name] , 448 | [im].[compression_type] , 449 | [tm].[schema_name] , 450 | [im].[object_id] , 451 | [tm].[table_name] , 452 | [tm].[object_name] , 453 | [im].[index_id] , 454 | [im].[index_name] , 455 | [im].[is_primary_key] , 456 | [im].[is_unique] , 457 | [im].[is_disabled] , 458 | [tm].[has_unique] , 459 | [im].[type_desc] , 460 | [im].[partition_count] , 461 | [im].[partition_number] , 462 | [im].[fill_factor] , 463 | [im].[is_padded] , 464 | [im].[reserved_page_count] , 465 | [im].[used_page_count] , 466 | [im].[index_row_count] / NULLIF([im].[used_page_count], 0) AS [average_rows_per_page] , 467 | [im].[size_in_mb] , 468 | COALESCE([mb].[buffered_page_count], 0) AS [buffered_page_count] , 469 | COALESCE([mb].[buffered_mb], 0) AS [buffered_mb] , 470 | CAST(0 AS INT) AS [table_buffered_mb] , 471 | COALESCE(CAST(100. * [mb].[buffered_page_count] / NULLIF([im].[reserved_page_count], 0) AS DECIMAL(12, 2)), 0) AS [buffered_percent] , 472 | [tm].[table_row_count] , 473 | [im].[index_row_count] , 474 | ROW_NUMBER() OVER (PARTITION BY [im].[object_id] ORDER BY [im].[is_primary_key] DESC, [ius].[user_seeks] + [ius].[user_scans] 475 | + [ius].[user_lookups] DESC) AS [index_rank] , 476 | CAST(0 AS INT) AS [full_index_rank] , 477 | [ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups] AS [user_total] , 478 | COALESCE(CAST(100 * ([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups]) 479 | / (NULLIF(SUM([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups]) OVER (PARTITION BY [im].[object_id]), 0) * 1.) AS DECIMAL(6, 480 | 2)), 0) AS [user_total_pct] , 481 | CAST(0 AS DECIMAL(6, 2)) AS [estimated_user_total_pct] , 482 | CAST(0 AS FLOAT) AS [missing_index_impact] -- Dick Baker 201303 (INT range not big enough and is f.p. anyway) 483 | , 484 | [ius].[user_seeks] , 485 | [ius].[user_scans] , 486 | [ius].[user_lookups] , 487 | [ius].[user_updates] , 488 | (1. * ([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups])) / NULLIF([ius].[user_updates], 0) AS [read_to_update_ratio] , 489 | ([ios].[leaf_insert_count] + [ios].[leaf_delete_count] + [ios].[leaf_update_count] + [ios].[leaf_ghost_count]) / NULLIF([ius].[user_updates], 490 | 0) AS [average_rows_per_update] , 491 | CASE WHEN [ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups] >= [ius].[user_updates] 492 | THEN CEILING(1. * ([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups]) / COALESCE(NULLIF([ius].[user_seeks], 0), 1)) 493 | ELSE 0 494 | END AS [read_to_update] , 495 | CASE WHEN [ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups] <= [ius].[user_updates] 496 | THEN CEILING(1. * ([ius].[user_updates]) / COALESCE(NULLIF([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups], 0), 1)) 497 | ELSE 0 498 | END AS [update_to_read] , 499 | [ios].[row_lock_count] , 500 | [ios].[row_lock_wait_count] , 501 | [ios].[row_lock_wait_in_ms] , 502 | CAST(100.0 * [ios].[row_lock_wait_count] / NULLIF([ios].[row_lock_count], 0) AS DECIMAL(12, 2)) AS [row_block_pct] , 503 | CAST(1. * [ios].[row_lock_wait_in_ms] / NULLIF([ios].[row_lock_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_row_lock_waits_ms] , 504 | [ios].[page_latch_wait_count] , 505 | CAST(1. * [ios].[page_latch_wait_in_ms] / NULLIF([ios].[page_io_latch_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_page_latch_wait_ms] , 506 | [ios].[page_io_latch_wait_count] , 507 | CAST(1. * [ios].[page_io_latch_wait_in_ms] / NULLIF([ios].[page_io_latch_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_page_io_latch_wait_ms] , 508 | [ios].[tree_page_latch_wait_count] AS [tree_page_latch_wait_count] , 509 | CAST(1. * [ios].[tree_page_latch_wait_in_ms] / NULLIF([ios].[tree_page_io_latch_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_tree_page_latch_wait_ms] , 510 | [ios].[tree_page_io_latch_wait_count] , 511 | CAST(1. * [ios].[tree_page_io_latch_wait_in_ms] / NULLIF([ios].[tree_page_io_latch_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_tree_page_io_latch_wait_ms] , 512 | [ios].[range_scan_count] + [ios].[singleton_lookup_count] AS [read_operations] , 513 | [ios].[leaf_insert_count] + [ios].[leaf_update_count] + [ios].[leaf_delete_count] + [ios].[leaf_ghost_count] AS [leaf_writes] , 514 | [ios].[leaf_allocation_count] AS [leaf_page_allocations] , 515 | [ios].[leaf_page_merge_count] AS [leaf_page_merges] , 516 | [ios].[nonleaf_insert_count] + [ios].[nonleaf_update_count] + [ios].[nonleaf_delete_count] AS [nonleaf_writes] , 517 | [ios].[nonleaf_allocation_count] AS [nonleaf_page_allocations] , 518 | [ios].[nonleaf_page_merge_count] AS [nonleaf_page_merges] , 519 | [ios].[page_compression_attempt_count] , 520 | [ios].[page_compression_success_count] , 521 | CAST(100. * [ios].[page_compression_success_count] / NULLIF([ios].[page_compression_attempt_count], 0) AS DECIMAL(6, 2)) AS [page_compression_success_rate] , 522 | [tm].[table_column_count] , 523 | [im].[indexed_columns] , 524 | [im].[indexed_column_count] , 525 | [im].[included_columns] , 526 | [im].[included_column_count] , 527 | [im].[filter_definition] , 528 | [im].[key_columns] , 529 | [im].[data_columns] , 530 | [im].[indexed_columns_ids] , 531 | [im].[included_column_ids] , 532 | [im].[distinct_indexed_columns_ids] , 533 | CAST('' AS VARCHAR(MAX)) AS [duplicate_indexes] , 534 | CAST('' AS SMALLINT) AS [first_dup_index_id] , 535 | CAST('' AS VARCHAR(MAX)) AS [overlapping_indexes] , 536 | CAST('' AS VARCHAR(MAX)) AS [sibling_indexes] , 537 | CAST('' AS VARCHAR(MAX)) AS [related_foreign_keys] , 538 | CAST('' AS XML) AS [related_foreign_keys_xml] 539 | INTO [#IndexStatistics] 540 | FROM [#TableMeta] [tm] 541 | INNER JOIN [#IndexMeta] [im] ON [im].[database_id] = [tm].[database_id] 542 | AND [im].[object_id] = [tm].[object_id] 543 | LEFT OUTER JOIN [sys].[dm_db_index_usage_stats] [ius] ON [im].[object_id] = [ius].[object_id] 544 | AND [im].[index_id] = [ius].[index_id] 545 | AND [im].[database_id] = [ius].[database_id] 546 | LEFT OUTER JOIN [#MemoryBuffer] [mb] ON [im].[object_id] = [mb].[object_id] 547 | AND [im].[index_id] = [mb].[index_id] 548 | AND [im].[partition_number] = [mb].[partition_number] 549 | LEFT OUTER JOIN (SELECT [database_id] , 550 | [object_id] , 551 | [index_id] , 552 | CASE WHEN @ConsolidatePartitionStats = 0 THEN [partition_number] 553 | ELSE -1 554 | END AS [partition_number] , 555 | SUM([leaf_insert_count]) AS [leaf_insert_count] , 556 | SUM([leaf_delete_count]) AS [leaf_delete_count] , 557 | SUM([leaf_update_count]) AS [leaf_update_count] , 558 | SUM([leaf_ghost_count]) AS [leaf_ghost_count] , 559 | SUM([nonleaf_insert_count]) AS [nonleaf_insert_count] , 560 | SUM([nonleaf_delete_count]) AS [nonleaf_delete_count] , 561 | SUM([nonleaf_update_count]) AS [nonleaf_update_count] , 562 | SUM([leaf_allocation_count]) AS [leaf_allocation_count] , 563 | SUM([nonleaf_allocation_count]) AS [nonleaf_allocation_count] , 564 | SUM([leaf_page_merge_count]) AS [leaf_page_merge_count] , 565 | SUM([nonleaf_page_merge_count]) AS [nonleaf_page_merge_count] , 566 | SUM([range_scan_count]) AS [range_scan_count] , 567 | SUM([singleton_lookup_count]) AS [singleton_lookup_count] , 568 | SUM([forwarded_fetch_count]) AS [forwarded_fetch_count] , 569 | SUM([lob_fetch_in_pages]) AS [lob_fetch_in_pages] , 570 | SUM([lob_fetch_in_bytes]) AS [lob_fetch_in_bytes] , 571 | SUM([lob_orphan_create_count]) AS [lob_orphan_create_count] , 572 | SUM([lob_orphan_insert_count]) AS [lob_orphan_insert_count] , 573 | SUM([row_overflow_fetch_in_pages]) AS [row_overflow_fetch_in_pages] , 574 | SUM([row_overflow_fetch_in_bytes]) AS [row_overflow_fetch_in_bytes] , 575 | SUM([column_value_push_off_row_count]) AS [column_value_push_off_row_count] , 576 | SUM([column_value_pull_in_row_count]) AS [column_value_pull_in_row_count] , 577 | SUM([row_lock_count]) AS [row_lock_count] , 578 | SUM([row_lock_wait_count]) AS [row_lock_wait_count] , 579 | SUM([row_lock_wait_in_ms]) AS [row_lock_wait_in_ms] , 580 | SUM([page_lock_count]) AS [page_lock_count] , 581 | SUM([page_lock_wait_count]) AS [page_lock_wait_count] , 582 | SUM([page_lock_wait_in_ms]) AS [page_lock_wait_in_ms] , 583 | SUM([index_lock_promotion_attempt_count]) AS [index_lock_promotion_attempt_count] , 584 | SUM([index_lock_promotion_count]) AS [index_lock_promotion_count] , 585 | SUM([page_latch_wait_count]) AS [page_latch_wait_count] , 586 | SUM([page_latch_wait_in_ms]) AS [page_latch_wait_in_ms] , 587 | SUM([page_io_latch_wait_count]) AS [page_io_latch_wait_count] , 588 | SUM([page_io_latch_wait_in_ms]) AS [page_io_latch_wait_in_ms] , 589 | SUM([tree_page_latch_wait_count]) AS [tree_page_latch_wait_count] , 590 | SUM([tree_page_latch_wait_in_ms]) AS [tree_page_latch_wait_in_ms] , 591 | SUM([tree_page_io_latch_wait_count]) AS [tree_page_io_latch_wait_count] , 592 | SUM([tree_page_io_latch_wait_in_ms]) AS [tree_page_io_latch_wait_in_ms] , 593 | SUM([page_compression_attempt_count]) AS [page_compression_attempt_count] , 594 | SUM([page_compression_success_count]) AS [page_compression_success_count] 595 | FROM [sys].[dm_db_index_operational_stats](DB_ID(), NULL, NULL, NULL) 596 | GROUP BY [database_id] , 597 | [object_id] , 598 | [index_id] , 599 | CASE WHEN @ConsolidatePartitionStats = 0 THEN [partition_number] 600 | ELSE -1 601 | END 602 | ) [ios] ON [im].[object_id] = [ios].[object_id] 603 | AND [im].[index_id] = [ios].[index_id] 604 | AND [im].[partition_number] = [ios].[partition_number]; 605 | 606 | IF @ProcessingMessages = 1 607 | PRINT 'Processing #IndexStatistics... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 608 | END; 609 | 610 | -- Collect missing index information. 611 | IF @IncludeMissingIndexes = 1 612 | BEGIN 613 | SET @PROCESSING_START = GETDATE(); 614 | 615 | INSERT INTO [#IndexStatistics] 616 | ([index_action] , 617 | [index_pros] , 618 | [index_cons] , 619 | [database_id] , 620 | [has_unique] , 621 | [is_primary_key] , 622 | [is_disabled] , 623 | [user_total_pct] , 624 | [table_column_count] , 625 | [filegroup_name] , 626 | [schema_name] , 627 | [object_id] , 628 | [table_name] , 629 | [object_name] , 630 | [index_name] , 631 | [type_desc] , 632 | [missing_index_impact] , 633 | [index_rank] , 634 | [user_total] , 635 | [user_seeks] , 636 | [user_scans] , 637 | [user_lookups] , 638 | [indexed_columns] , 639 | [included_columns] , 640 | [compression_type] , 641 | [indexed_column_count] , 642 | [included_column_count] 643 | ) 644 | SELECT '' AS [index_action] , 645 | '' AS [index_pros] , 646 | '' AS [index_cons] , 647 | [tm].[database_id] , 648 | [tm].[has_unique] , 649 | 0 [is_primary_key] , 650 | 0 [is_disabled] , 651 | 0 [user_total_pct] , 652 | [tm].[table_column_count] , 653 | '--TBD--' AS [filegroup_name] , 654 | [tm].[schema_name] , 655 | [mid].[object_id] , 656 | [tm].[table_name] , 657 | [tm].[object_name] , 658 | '--MISSING INDEX--' AS [index_name] , 659 | '--NONCLUSTERED--' AS [type_desc] , 660 | ([migs].[user_seeks] + [migs].[user_scans]) * [migs].[avg_user_impact] AS [impact] , 661 | 0 AS [index_rank] , 662 | [migs].[user_seeks] + [migs].[user_scans] AS [user_total] , 663 | [migs].[user_seeks] , 664 | [migs].[user_scans] , 665 | 0 AS [user_lookups] , 666 | COALESCE([mid].[equality_columns] + CASE WHEN [mid].[inequality_columns] IS NOT NULL THEN ', ' 667 | ELSE SPACE(0) 668 | END, SPACE(0)) + COALESCE([mid].[inequality_columns], SPACE(0)) AS [indexed_columns] , 669 | [mid].[included_columns] , 670 | '--TBD--' , 671 | [mic].[indexed_column_count] , 672 | [mic].[included_column_count] 673 | FROM [#TableMeta] [tm] 674 | INNER JOIN [sys].[dm_db_missing_index_details] [mid] ON [mid].[database_id] = [tm].[database_id] 675 | AND [mid].[object_id] = [tm].[object_id] 676 | INNER JOIN [sys].[dm_db_missing_index_groups] [mig] ON [mid].[index_handle] = [mig].[index_handle] 677 | INNER JOIN [sys].[dm_db_missing_index_group_stats] [migs] ON [mig].[index_group_handle] = [migs].[group_handle] 678 | CROSS APPLY (SELECT SUM(CASE WHEN [column_usage] != 'INCLUDE' THEN 1 679 | ELSE 0 680 | END) AS [indexed_column_count] , 681 | SUM(CASE WHEN [column_usage] = 'INCLUDE' THEN 1 682 | ELSE 0 683 | END) AS [included_column_count] 684 | FROM [sys].[dm_db_missing_index_columns]([mid].[index_handle]) 685 | ) [mic]; 686 | IF @ProcessingMessages = 1 687 | PRINT 'Add missing indexes to #IndexStatistics... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 688 | END; 689 | 690 | -- Collect foreign key information. 691 | BEGIN 692 | SET @PROCESSING_START = GETDATE(); 693 | 694 | CREATE TABLE [#ForeignKeys] 695 | ( 696 | [foreign_key_name] NVARCHAR(256) , 697 | [object_id] INT , 698 | [fk_columns] NVARCHAR(MAX) , 699 | [fk_columns_ids] NVARCHAR(1024) , 700 | [related_object_id] INT , 701 | [distinct_column_ids] NVARCHAR(1024) , 702 | [indexed_column_count] INT 703 | ); 704 | 705 | SET @SQL = N'SELECT fk.name + ''|CHILD'' AS foreign_key_name 706 | ,fkc.parent_object_id AS object_id 707 | ,STUFF((SELECT '', '' + QUOTENAME(c.name) 708 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 709 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ifkc.parent_object_id = c.object_id AND ifkc.parent_column_id = c.column_id 710 | WHERE fk.object_id = ifkc.constraint_object_id 711 | ORDER BY ifkc.constraint_column_id 712 | FOR XML PATH('''')), 1, 2, '''') AS fk_columns 713 | ,(SELECT QUOTENAME(CAST(ifkc.parent_column_id AS VARCHAR(10))+''+'',''('') 714 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 715 | WHERE fk.object_id = ifkc.constraint_object_id 716 | ORDER BY ifkc.constraint_column_id 717 | FOR XML PATH('''')) AS fk_columns_compare 718 | ,fkc.referenced_object_id AS related_object_id 719 | 720 | ,(SELECT QUOTENAME(CAST(ifkc.parent_column_id AS VARCHAR(10))) 721 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 722 | WHERE fk.object_id = ifkc.constraint_object_id 723 | ORDER BY ifkc.parent_column_id 724 | FOR XML PATH('''')) AS distinct_column_ids 725 | ,(SELECT COUNT(*) 726 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 727 | WHERE fk.object_id = ifkc.constraint_object_id) AS indexed_column_count 728 | 729 | FROM #TableMeta tm 730 | INNER JOIN ' + @DatabaseName + '.sys.foreign_keys fk ON tm.object_id = fk.parent_object_id 731 | INNER JOIN ' + @DatabaseName + '.sys.foreign_key_columns fkc ON fk.object_id = fkc.constraint_object_id 732 | WHERE fkc.constraint_column_id = 1 733 | AND (@ObjectID IS NULL OR (fk.parent_object_id = @ObjectID OR fk.referenced_object_id = @ObjectID)) 734 | UNION ALL 735 | SELECT fk.name + ''|PARENT'' as foreign_key_name 736 | ,fkc.referenced_object_id AS object_id 737 | ,STUFF((SELECT '', '' + QUOTENAME(c.name) 738 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 739 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ifkc.referenced_object_id = c.object_id AND ifkc.referenced_column_id = c.column_id 740 | WHERE fk.object_id = ifkc.constraint_object_id 741 | ORDER BY ifkc.constraint_column_id 742 | FOR XML PATH('''')), 1, 2, '''') AS fk_columns 743 | ,(SELECT QUOTENAME(CAST(ifkc.referenced_column_id AS VARCHAR(10))+''+'',''('') 744 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 745 | WHERE fk.object_id = ifkc.constraint_object_id 746 | ORDER BY ifkc.constraint_column_id 747 | FOR XML PATH('''')) AS fk_columns_compare 748 | ,fkc.parent_object_id AS related_object_id 749 | ,(SELECT QUOTENAME(CAST(ifkc.referenced_column_id AS VARCHAR(10))) 750 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 751 | WHERE fk.object_id = ifkc.constraint_object_id 752 | ORDER BY ifkc.parent_column_id 753 | FOR XML PATH('''')) AS fk_columns_compare 754 | ,(SELECT COUNT(*) 755 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 756 | WHERE fk.object_id = ifkc.constraint_object_id) AS indexed_column_count 757 | FROM #TableMeta tm 758 | INNER JOIN ' + @DatabaseName + '.sys.foreign_keys fk ON tm.object_id = fk.referenced_object_id 759 | INNER JOIN ' + @DatabaseName + '.sys.foreign_key_columns fkc ON fk.object_id = fkc.constraint_object_id 760 | WHERE fkc.constraint_column_id = 1 761 | AND (@ObjectID IS NULL OR (fk.parent_object_id = @ObjectID OR fk.referenced_object_id = @ObjectID)) 762 | '; 763 | 764 | BEGIN TRY 765 | INSERT INTO [#ForeignKeys] 766 | ([foreign_key_name] , 767 | [object_id] , 768 | [fk_columns] , 769 | [fk_columns_ids] , 770 | [related_object_id] , 771 | [distinct_column_ids] , 772 | [indexed_column_count] 773 | ) 774 | EXEC [sys].[sp_executesql] @SQL, N'@DB_ID INT, @ObjectID INT', @DB_ID = @DB_ID, @ObjectID = @ObjectID; 775 | END TRY 776 | BEGIN CATCH 777 | SELECT @ERROR_MESSAGE = 'Populate #ForeignKeys (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 778 | @ERROR_SEVERITY = ERROR_SEVERITY() , 779 | @ERROR_STATE = ERROR_STATE(); 780 | 781 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 782 | END CATCH; 783 | 784 | IF @ProcessingMessages = 1 785 | PRINT 'Processing #ForeignKeys... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 786 | END; 787 | 788 | -- Determine duplicate, overlapping, and foreign key index information 789 | UPDATE [i] 790 | SET [i].[duplicate_indexes] = STUFF((SELECT ', ' + [iibl].[index_name] AS [data()] 791 | FROM [#IndexStatistics] [iibl] 792 | WHERE [i].[object_id] = [iibl].[object_id] 793 | AND [i].[is_primary_key] = [iibl].[is_primary_key] 794 | AND [i].[is_unique] = [iibl].[is_unique] 795 | AND ISNULL([i].[filter_definition], '') = ISNULL([iibl].[filter_definition], '') 796 | AND [i].[index_id] <> [iibl].[index_id] 797 | AND REPLACE([i].[indexed_columns_ids], '|', '') = REPLACE([iibl].[indexed_columns_ids], '|', '') 798 | AND [i].[included_column_ids] = [iibl].[included_column_ids] 799 | FOR 800 | XML PATH('') 801 | ), 1, 2, '') , 802 | [i].[first_dup_index_id] = (SELECT MIN([iibl].[index_id]) 803 | FROM [#IndexStatistics] [iibl] 804 | WHERE [i].[object_id] = [iibl].[object_id] 805 | AND [i].[is_primary_key] = [iibl].[is_primary_key] 806 | AND [i].[is_unique] = [iibl].[is_unique] 807 | AND ISNULL([i].[filter_definition], '') = ISNULL([iibl].[filter_definition], '') 808 | AND [i].[index_id] > [iibl].[index_id] 809 | AND REPLACE([i].[indexed_columns_ids], '|', '') = REPLACE([iibl].[indexed_columns_ids], '|', '') 810 | AND [i].[included_column_ids] = [iibl].[included_column_ids] 811 | ) , 812 | [i].[overlapping_indexes] = STUFF((SELECT ', ' + [iibl].[index_name] AS [data()] 813 | FROM [#IndexStatistics] [iibl] 814 | WHERE [i].[object_id] = [iibl].[object_id] 815 | AND ISNULL([i].[filter_definition], '') = ISNULL([iibl].[filter_definition], '') 816 | AND [i].[index_id] <> [iibl].[index_id] 817 | AND LEFT([iibl].[indexed_columns_ids], CHARINDEX('|', [iibl].[indexed_columns_ids], 1) - 1) LIKE LEFT([i].[indexed_columns_ids], 818 | CHARINDEX('|', 819 | [i].[indexed_columns_ids], 820 | 1) - 1) + '%' 821 | FOR 822 | XML PATH('') 823 | ), 1, 2, '') , 824 | [i].[sibling_indexes] = STUFF((SELECT ', ' + [iibl].[index_name] AS [data()] 825 | FROM [#IndexStatistics] [iibl] 826 | WHERE [i].[object_id] = [iibl].[object_id] 827 | AND [i].[index_id] <> [iibl].[index_id] 828 | AND [i].[distinct_indexed_columns_ids] = [iibl].[distinct_indexed_columns_ids] 829 | FOR 830 | XML PATH('') 831 | ), 1, 2, '') , 832 | [i].[related_foreign_keys] = STUFF((SELECT ', ' + [ifk].[foreign_key_name] AS [data()] 833 | FROM [#ForeignKeys] [ifk] 834 | WHERE [ifk].[object_id] = [i].[object_id] 835 | AND [i].[indexed_columns_ids] LIKE [ifk].[fk_columns_ids] + '%' 836 | FOR 837 | XML PATH('') 838 | ), 1, 2, '') , 839 | [i].[related_foreign_keys_xml] = CAST((SELECT [fk].[foreign_key_name] 840 | FROM [#ForeignKeys] [fk] 841 | WHERE [fk].[object_id] = [i].[object_id] 842 | AND [i].[indexed_columns_ids] LIKE [fk].[fk_columns_ids] + '%' 843 | FOR 844 | XML AUTO 845 | ) AS XML) 846 | FROM [#IndexStatistics] [i]; 847 | 848 | IF @IncludeMissingFKIndexes = 1 849 | BEGIN 850 | INSERT INTO [#IndexStatistics] 851 | ([database_id] , 852 | [filegroup_name] , 853 | [schema_name] , 854 | [object_id] , 855 | [table_name] , 856 | [object_name] , 857 | [index_name] , 858 | [type_desc] , 859 | [has_unique] , 860 | [is_primary_key] , 861 | [is_disabled] , 862 | [user_total_pct] , 863 | [table_column_count] , 864 | [index_rank] , 865 | [indexed_columns] , 866 | [indexed_column_count] , 867 | [indexed_columns_ids] , 868 | [distinct_indexed_columns_ids] , 869 | [included_column_count] , 870 | [key_columns] , 871 | [related_foreign_keys] , 872 | [compression_type] 873 | ) 874 | SELECT [tm].[database_id] , 875 | '--TBD--' AS [filegroup_name] , 876 | OBJECT_SCHEMA_NAME([fk].[object_id]) AS [schema_name] , 877 | [fk].[object_id] , 878 | OBJECT_NAME([fk].[object_id]) AS [table_name] , 879 | [tm].[object_name] , 880 | '--MISSING FOREIGN KEY INDEX--' AS [index_name] , 881 | 'NONCLUSTERED' AS [type_desc] , 882 | [tm].[has_unique] , 883 | 0 AS [is_primary_key] , 884 | 0 AS [is_disabled] , 885 | 0 AS [user_total_pct] , 886 | [tm].[table_column_count] , 887 | 9999 AS [index_rank] , 888 | [fk].[fk_columns] , 889 | [fk].[indexed_column_count] , 890 | [fk].[fk_columns_ids] , 891 | [fk].[distinct_column_ids] , 892 | 0 AS [included_column_count] , 893 | [fk].[fk_columns] , 894 | [fk].[foreign_key_name] , 895 | '--TBD--' 896 | FROM [#TableMeta] AS [tm] 897 | INNER JOIN [#ForeignKeys] [fk] ON [fk].[object_id] = [tm].[object_id] 898 | LEFT OUTER JOIN [#IndexStatistics] [i] ON [fk].[object_id] = [i].[object_id] 899 | AND [i].[indexed_columns_ids] LIKE [fk].[fk_columns_ids] + '%' 900 | WHERE [i].[index_name] IS NULL; 901 | END; 902 | 903 | --================================================================================================ 904 | -- Calculate estimated user total for each index. 905 | --================================================================================================ 906 | WITH [StatAggregation1] 907 | AS (SELECT [row_id] , 908 | [object_id] , 909 | [user_seeks] , 910 | [user_scans] , 911 | [user_lookups] , 912 | [user_total_pct] , 913 | CONVERT(INT, SUM(CASE WHEN [index_id] IS NULL THEN [user_seeks] 914 | END) OVER (PARTITION BY [object_id]) * 1. * [user_scans] 915 | / NULLIF(SUM(CASE WHEN [index_id] IS NOT NULL THEN [user_scans] 916 | END) OVER (PARTITION BY [object_id]), 0)) AS [weighted_scans] , 917 | SUM([buffered_mb]) OVER (PARTITION BY [schema_name], [table_name]) AS [table_buffered_mb] 918 | FROM [#IndexStatistics] 919 | ), 920 | [StatAggregation2] 921 | AS (SELECT * , 922 | CONVERT(DECIMAL(6, 2), 100. * ([StatAggregation1].[user_seeks] + [StatAggregation1].[user_scans] 923 | - [StatAggregation1].[weighted_scans] + [StatAggregation1].[user_lookups]) 924 | / SUM([StatAggregation1].[user_seeks] + [StatAggregation1].[user_scans] - [StatAggregation1].[weighted_scans] 925 | + [StatAggregation1].[user_lookups]) OVER (PARTITION BY [StatAggregation1].[object_id])) AS [estimated_user_total_pct] 926 | FROM [StatAggregation1] 927 | ), 928 | [StatAggregation3] 929 | AS (SELECT * , 930 | ROW_NUMBER() OVER (PARTITION BY [StatAggregation2].[object_id] ORDER BY [StatAggregation2].[estimated_user_total_pct] DESC, [StatAggregation2].[user_total_pct] DESC) AS [full_index_rank] 931 | FROM [StatAggregation2] 932 | ) 933 | UPDATE [ibl] 934 | SET [ibl].[estimated_user_total_pct] = COALESCE([a].[estimated_user_total_pct], 0) , 935 | [ibl].[table_buffered_mb] = [a].[table_buffered_mb] , 936 | [ibl].[full_index_rank] = [a].[full_index_rank] 937 | FROM [#IndexStatistics] [ibl] 938 | INNER JOIN [StatAggregation3] [a] ON [ibl].[row_id] = [a].[row_id]; 939 | 940 | --================================================================================================ 941 | -- Update Pro/Con statuses 942 | --================================================================================================ 943 | UPDATE [#IndexStatistics] 944 | SET [index_pros] = COALESCE(STUFF(CASE WHEN [index_name] = '--MISSING INDEX--' 945 | AND [related_foreign_keys] IS NOT NULL THEN ', MIFK' 946 | WHEN [related_foreign_keys] IS NOT NULL THEN ', FK' 947 | ELSE '' 948 | END + CASE WHEN [is_unique] = 1 THEN ', UQ' 949 | ELSE '' 950 | END + CASE WHEN [full_index_rank] <= 5 951 | AND [index_name] = '--MISSING INDEX--' THEN ', TM5' 952 | ELSE '' 953 | END + COALESCE(', ' + CASE WHEN [read_to_update] BETWEEN 1 AND 9 THEN '$' 954 | WHEN [read_to_update] BETWEEN 10 AND 99 THEN '$$' 955 | WHEN [read_to_update] BETWEEN 100 AND 999 THEN '$$$' 956 | WHEN [read_to_update] > 999 THEN '$$$+' 957 | END, ''), 1, 2, ''), '') , 958 | [index_cons] = COALESCE(STUFF(CASE WHEN [index_id] = 0 THEN ', HP' 959 | ELSE '' 960 | END + CASE WHEN [user_lookups] >= @MinLookupThreshold 961 | AND [user_lookups] > [user_seeks] + [user_scans] THEN ', LKUP' 962 | ELSE '' 963 | END + CASE WHEN NULLIF([user_scans], 0) >= @MinScanThreshold 964 | AND [user_seeks] / NULLIF([user_scans], 0) < @Scan2SeekRatio THEN ', SCN' 965 | ELSE '' 966 | END + CASE WHEN [duplicate_indexes] IS NOT NULL THEN ', DUP' 967 | ELSE '' 968 | END + CASE WHEN [overlapping_indexes] IS NOT NULL THEN ', OVLP' 969 | ELSE '' 970 | END + CASE WHEN [sibling_indexes] IS NOT NULL THEN ', SIB' 971 | ELSE '' 972 | END + COALESCE(', ' + CASE WHEN [update_to_read] BETWEEN 1 AND 9 THEN '$' 973 | WHEN [update_to_read] BETWEEN 10 AND 99 THEN '$$' 974 | WHEN [update_to_read] BETWEEN 100 AND 999 THEN '$$$' 975 | WHEN [update_to_read] > 999 THEN '$$$+' 976 | END, '') + COALESCE(', ' 977 | + CASE WHEN [index_id] <= 1 978 | OR [indexed_column_count] 979 | + [included_column_count] < 4 980 | THEN NULL 981 | WHEN 100. * ([indexed_column_count] 982 | + [included_column_count]) 983 | / [table_column_count] >= 90 984 | THEN 'C90%' 985 | WHEN 100. * ([indexed_column_count] 986 | + [included_column_count]) 987 | / [table_column_count] >= 50 988 | THEN 'C50%' 989 | WHEN 100. * ([indexed_column_count] 990 | + [included_column_count]) 991 | / [table_column_count] >= 25 992 | THEN 'C25%' 993 | END, '') 994 | + CASE WHEN [index_id] IS NOT NULL 995 | AND [user_total_pct] < 1 THEN ', U1%' 996 | ELSE '' 997 | END + CASE WHEN @CheckCompression = 1 998 | AND [compression_type] = 'NONE' THEN ', NOCMP' 999 | ELSE '' 1000 | END + CASE WHEN [is_disabled] = 1 THEN ', DSB' 1001 | ELSE '' 1002 | END, 1, 2, ''), ''); 1003 | 1004 | --================================================================================================ 1005 | -- Update Index Action information 1006 | --================================================================================================ 1007 | WITH [IndexAction] 1008 | AS (SELECT [row_id] , 1009 | CASE WHEN [user_lookups] >= @MinLookupThreshold 1010 | AND [user_lookups] > [user_seeks] 1011 | AND [type_desc] IN ('CLUSTERED', 'HEAP', 'UNIQUE CLUSTERED') THEN 'REALIGN' 1012 | WHEN [user_total_pct] < 5. 1013 | AND [type_desc] IN ('CLUSTERED', 'HEAP', 'UNIQUE CLUSTERED') 1014 | AND SUM([user_seeks] + [user_scans] + [user_lookups]) OVER (PARTITION BY [object_id]) > 0 THEN 'REALIGN' 1015 | WHEN [is_disabled] = 1 THEN 'ENABLE' 1016 | WHEN [duplicate_indexes] IS NOT NULL 1017 | AND [first_dup_index_id] IS NOT NULL 1018 | AND [index_id] IS NOT NULL THEN 'NEG-DUP' 1019 | WHEN [type_desc] = '--MISSING FOREIGN KEY--' THEN 'CREATE' 1020 | WHEN [type_desc] = 'XML' THEN '---' 1021 | WHEN [is_unique] = 1 THEN '---' 1022 | WHEN [related_foreign_keys] IS NOT NULL THEN '---' 1023 | WHEN [type_desc] = '--NONCLUSTERED--' 1024 | AND ROW_NUMBER() OVER (PARTITION BY [table_name] ORDER BY [user_total] DESC) <= @MaxMissingIndexCount 1025 | AND [estimated_user_total_pct] > 1 THEN 'CREATE' 1026 | WHEN [type_desc] = '--NONCLUSTERED--' 1027 | AND [estimated_user_total_pct] > .1 THEN 'BLEND' 1028 | WHEN ROW_NUMBER() OVER (PARTITION BY [table_name] ORDER BY [user_total] DESC, [index_rank]) > 10 1029 | AND [index_id] IS NOT NULL THEN 'NEG-COUNT' 1030 | WHEN [index_id] NOT IN (0, 1) 1031 | AND [duplicate_indexes] IS NULL 1032 | AND [user_total] = 0 1033 | AND [index_id] IS NOT NULL THEN 'NEG-USAGE' 1034 | ELSE '---' 1035 | END AS [index_action] 1036 | FROM [#IndexStatistics] 1037 | ) 1038 | UPDATE [ibl] 1039 | SET [ibl].[index_action] = [ia].[index_action] 1040 | FROM [#IndexStatistics] [ibl] 1041 | INNER JOIN [IndexAction] [ia] ON [ibl].[row_id] = [ia].[row_id]; 1042 | 1043 | --================================================================================================ 1044 | -- Output results from query 1045 | --================================================================================================ 1046 | IF @Output = 'DUMP' 1047 | BEGIN 1048 | SELECT * 1049 | FROM [#IndexStatistics] 1050 | ORDER BY [table_buffered_mb] DESC , 1051 | [object_id] , 1052 | COALESCE([user_total], -1) DESC , 1053 | COALESCE([user_updates], -1) DESC , 1054 | COALESCE([index_id], 999); 1055 | END; 1056 | ELSE 1057 | IF @Output = 'DETAILED' 1058 | BEGIN 1059 | SELECT [index_action] , 1060 | [index_pros] , 1061 | [index_cons] , 1062 | [object_name] , 1063 | [index_name] , 1064 | [type_desc] , 1065 | [indexed_columns] , 1066 | [included_columns] , 1067 | [filter_definition] , 1068 | [is_primary_key] , 1069 | [is_unique] , 1070 | [is_disabled] , 1071 | [has_unique] , 1072 | [partition_number] , 1073 | [fill_factor] , 1074 | [is_padded] , 1075 | [size_in_mb] , 1076 | [buffered_mb] , 1077 | [table_buffered_mb] , 1078 | [buffered_percent] , 1079 | [index_row_count] , 1080 | [user_total_pct] , 1081 | [estimated_user_total_pct] , 1082 | [missing_index_impact] , 1083 | [user_total] , 1084 | [user_seeks] , 1085 | [user_scans] , 1086 | [user_lookups] , 1087 | [user_updates] , 1088 | [read_to_update_ratio] , 1089 | [read_to_update] , 1090 | [update_to_read] , 1091 | [row_lock_count] , 1092 | [row_lock_wait_count] , 1093 | [row_lock_wait_in_ms] , 1094 | [row_block_pct] , 1095 | [avg_row_lock_waits_ms] , 1096 | [page_latch_wait_count] , 1097 | [avg_page_latch_wait_ms] , 1098 | [page_io_latch_wait_count] , 1099 | [avg_page_io_latch_wait_ms] , 1100 | [tree_page_latch_wait_count] , 1101 | [avg_tree_page_latch_wait_ms] , 1102 | [tree_page_io_latch_wait_count] , 1103 | [avg_tree_page_io_latch_wait_ms] , 1104 | [read_operations] , 1105 | [leaf_writes] , 1106 | [leaf_page_allocations] , 1107 | [leaf_page_merges] , 1108 | [nonleaf_writes] , 1109 | [nonleaf_page_allocations] , 1110 | [nonleaf_page_merges] , 1111 | [duplicate_indexes] , 1112 | [overlapping_indexes] , 1113 | [related_foreign_keys] , 1114 | [related_foreign_keys_xml] , 1115 | [key_columns] , 1116 | [data_columns] 1117 | FROM [#IndexStatistics] 1118 | WHERE ([estimated_user_total_pct] > 0.01 1119 | AND [index_id] IS NULL 1120 | ) 1121 | OR [related_foreign_keys] IS NOT NULL 1122 | OR [index_id] IS NOT NULL 1123 | ORDER BY [table_buffered_mb] DESC , 1124 | [object_id] , 1125 | COALESCE([user_total], -1) DESC , 1126 | COALESCE([user_updates], -1) DESC , 1127 | COALESCE([index_id], 999); 1128 | END; 1129 | ELSE 1130 | IF @Output = 'REALIGN' 1131 | BEGIN 1132 | SELECT [index_action] , 1133 | [object_name] , 1134 | [index_name] , 1135 | [partition_number] , 1136 | [type_desc] , 1137 | [index_pros] , 1138 | [index_cons] , 1139 | [index_row_count] , 1140 | [user_total] , 1141 | [user_seeks] , 1142 | [user_scans] , 1143 | [user_lookups] , 1144 | [user_updates] , 1145 | [user_total_pct] , 1146 | [size_in_mb] , 1147 | [buffered_mb] , 1148 | [table_buffered_mb] , 1149 | [buffered_percent] , 1150 | [indexed_columns] , 1151 | [included_columns] , 1152 | [is_primary_key] , 1153 | [is_unique] , 1154 | [is_disabled] , 1155 | [has_unique] , 1156 | [read_to_update_ratio] , 1157 | [read_to_update] , 1158 | [update_to_read] , 1159 | [row_lock_count] , 1160 | [row_lock_wait_count] , 1161 | [row_lock_wait_in_ms] , 1162 | [row_block_pct] , 1163 | [avg_row_lock_waits_ms] , 1164 | [page_latch_wait_count] , 1165 | [avg_page_latch_wait_ms] , 1166 | [page_io_latch_wait_count] , 1167 | [avg_page_io_latch_wait_ms] , 1168 | [read_operations] 1169 | FROM [#IndexStatistics] 1170 | WHERE [object_id] IN (SELECT [object_id] 1171 | FROM [#IndexStatistics] 1172 | WHERE [index_action] = 'REALIGN') 1173 | ORDER BY SUM([user_total]) OVER (PARTITION BY [object_id]) DESC , 1174 | [object_id] , 1175 | COALESCE([user_total], -1) DESC , 1176 | COALESCE([user_updates], -1) DESC , 1177 | COALESCE([index_id], 999); 1178 | END; 1179 | ELSE 1180 | IF @Output = 'DUPLICATE' 1181 | BEGIN 1182 | SELECT DENSE_RANK() OVER (ORDER BY [key_columns], [data_columns]) AS [duplicate_group] , 1183 | [index_action] , 1184 | [index_pros] , 1185 | [index_cons] , 1186 | [object_name] , 1187 | [index_name] , 1188 | [type_desc] , 1189 | [indexed_columns] , 1190 | [included_columns] , 1191 | [is_primary_key] , 1192 | [is_unique] , 1193 | [duplicate_indexes] , 1194 | [size_in_mb] , 1195 | [index_row_count] , 1196 | [user_total_pct] , 1197 | [user_total] , 1198 | [user_seeks] , 1199 | [user_scans] , 1200 | [user_lookups] , 1201 | [user_updates] , 1202 | [read_operations] 1203 | FROM [#IndexStatistics] 1204 | WHERE [duplicate_indexes] IS NOT NULL 1205 | ORDER BY [table_buffered_mb] DESC , 1206 | [object_id] , 1207 | RANK() OVER (ORDER BY [key_columns], [data_columns]); 1208 | END; 1209 | ELSE 1210 | IF @Output = 'OVERLAPPING' 1211 | BEGIN 1212 | SELECT [index_action] , 1213 | [index_pros] , 1214 | [index_cons] , 1215 | [object_name] , 1216 | [overlapping_indexes] , 1217 | [index_name] , 1218 | [type_desc] , 1219 | [indexed_columns] , 1220 | [included_columns] , 1221 | [is_primary_key] , 1222 | [is_unique] , 1223 | [size_in_mb] , 1224 | [index_row_count] , 1225 | [user_total_pct] , 1226 | [user_total] , 1227 | [user_seeks] , 1228 | [user_scans] , 1229 | [user_lookups] , 1230 | [user_updates] , 1231 | [read_operations] 1232 | FROM [#IndexStatistics] 1233 | WHERE [overlapping_indexes] IS NOT NULL 1234 | ORDER BY [table_buffered_mb] DESC , 1235 | [object_id] , 1236 | [user_total] DESC; 1237 | END; 1238 | END TRY 1239 | BEGIN CATCH 1240 | SELECT @ERROR_MESSAGE = 'Procedure Error (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 1241 | @ERROR_SEVERITY = ERROR_SEVERITY() , 1242 | @ERROR_STATE = ERROR_STATE(); 1243 | 1244 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 1245 | END CATCH; 1246 | END; 1247 | 1248 | -------------------------------------------------------------------------------- /sp_IndexAnalysis-SQLServer2005.sql: -------------------------------------------------------------------------------- 1 | USE master 2 | GO 3 | 4 | IF OBJECT_ID('dbo.sp_IndexAnalysis') IS NOT NULL 5 | DROP PROCEDURE dbo.sp_IndexAnalysis 6 | GO 7 | 8 | /********************************************************************************************* 9 | Index Analysis Script v9.06 10 | (C) 2013, Jason Strate 11 | 12 | Feedback: 13 | mailto:jasonstrate@gmail.com 14 | http://www.jasonstrate.com 15 | 16 | License: 17 | This query is free to download and use for personal, educational, and internal 18 | corporate purposes, provided that this header is preserved. Redistribution or sale 19 | of this query, in whole or in part, is prohibited without the author's express 20 | written consent. 21 | 22 | Note: 23 | Recommendations in the Index Action column are not black and white recommendations. 24 | They are more light grey ideas of what may be appropriate. Always use your experience 25 | with the database in place of a blanket recommendation. 26 | 27 | The information in the DMVs is gathered from when the SQL Server service last started, the 28 | database was brought onling, or when the index metadata was updated (such as during reindex 29 | operations, which ever event is more recent. 30 | 31 | The index statistics accumulated in sys.dm_db_index_operational_stats and 32 | sys.dm_db_index_usage_stats are reset when the index is rebuilt. 33 | 34 | The index statistics for a table that are accumulated in the DMVs 35 | sys.dm_db_missing_index_* are reset whenever an index is created on the table. 36 | 37 | The index name provided in the name column for indexes that do not exist is not a 38 | recommended name for the index. It’s just an informative placeholder. 39 | 40 | Parameters 41 | @TableName(NVARCHAR(256)): Optional parameter to add 42 | @IncludeMissingIndexes(BIT): Identifies whether to include missing indexes in the output 43 | @IncludeMissingFKIndexes(BIT): Identifies whether to include missing foreign key indexes 44 | in the output 45 | @Output(VARCHAR(20)): Determines the output results from the stored procedure. The 46 | available values are 47 | * DETAILED: All results from the index analysis 48 | * DUPLICATE: Index results for deplicate indexes 49 | * OVERLAPPING: Index results for overlapping indexes 50 | 51 | Columns: 52 | index_action: Analysis recommendation on action to take on the index 53 | CREATE: Recommend adding the index to the table. 54 | DROP-DUP: Recommend dropping the index since it is a duplicate 55 | DROP-COUNT: Count of indexes on tables may indicate that the index may be a candidate 56 | for removal. 57 | DROP-USAGE: Usage of the index suggests it may be a candidate for removal 58 | BLEND: Review the missing index details to see if the missing index details can be 59 | added to an existing index. 60 | REALIGN: Bookmark lookups on the index exceed the number of seeks on the table. 61 | Recommend investigating whether to move the clustered index to another index or 62 | add included columns to the indexes that are part of the bookmark lookups. 63 | index_pros: list of reasons that indicate the benefits provided by the index 64 | FK: The index schema maps to a foreign key 65 | UQ: Index is a unique constraint 66 | $, $$, $$$, $$$+: Indicates the ratio of read to write uses in execution plans. The 67 | higher the ratio the more dollar signs; this should correlate to greater benefit 68 | provided by the index. 69 | index_cons: list of reasons that indicate some negative aspects associate with the index 70 | SCN: Flag indicating that the ratio of seeks to scans on the index less than 1,000. 71 | DP: Index schema is a duplicate of another index. 72 | OV: Index schema overlaps another index. 73 | $, $$, $$$, $$$+: Indicates the ratio of write to read uses in execution plans. The 74 | higher the ratio the more dollar signs; this should correlate to more cost 75 | incurred by the index. 76 | DSB: Index is disabled. These should be enabled or removed. 77 | filegroup: file group that the index is located. 78 | schema_id: Schema ID 79 | schema_name: Name of the schema. 80 | object_id: Object ID 81 | table_name: Name of the table name 82 | index_id: Index ID 83 | index_name: Name of the index. 84 | is_unique: Flag indicating whether an index has a unique index. 85 | has_unique: Flag indicating whether the table has a unique index. 86 | type_desc: Type of index; either clustered or non-clustered. 87 | partition_number: Partition number. 88 | fill_factor: Percentage of free space left on pages the index was created or rebuilt. 89 | is_padded: Boolean value indicating whether fill factor is applied to nonleaf levels 90 | reserved_page_count: Total number of pages reserved for the index. 91 | size_in_mb: The amount of space in MB the index utilizes on disk. 92 | buffered_page_count: Total number of pages in the buffer for the index. 93 | buffer_mb: The amount of space in MB in the buffer for the index. 94 | pct_in_buffer: The percentage of an index that is current in the SQL Server buffer. 95 | table_buffer_mb: The amount of space in MB in the SQL Server buffer that is being 96 | utilized by the table. 97 | row_count: Number of rows in the index. 98 | missing_index_impact: Calculation of impact of a potential index. This is based on the seeks and 99 | scans that the index could have utilized multiplied by average improvement the index 100 | would have provided. This is included only for missing indexes. 101 | existing_ranking: Ranking of the existing indexes ordered by user_total descending across 102 | the indexes for the table. 103 | user_total: Total number of seek, scan, and lookup operations for the index. 104 | user_total_pct: Percentage of total number of seek, scan, and lookup operations for this 105 | index compared to all seek, scan, and lookup operations for existing indexes for the 106 | table. 107 | estimated_user_total_pct: Percentage of total number of seek, scan, and lookup operations 108 | for this index compared to all seek, scan, and lookup operations for existing and 109 | potential indexes for the table. This number is naturally skewed because a seek for 110 | potential Index A resulted in another operation on an existing index and both of 111 | these operations would be counted. 112 | user_seeks: Number of seek operations on the index. 113 | user_scans: Number of scan operations on the index. 114 | user_lookups: Number of lookup operations on the index. 115 | user_updates: Number of update operations on the index. 116 | read_to_update_ratio: Ratio of user_seeks, user_scans, and user_lookups to user_updates. 117 | read_to_update: Division of user_seeks, user_scans, and user_lookups by user_updates. 118 | update_to_read: Division of user_updates to user_seeks, user_scans by user_lookups. 119 | row_lock_count: Cumulative number of row locks requested. 120 | row_lock_wait_count: Cumulative number of times the Database Engine waited on a row lock. 121 | row_lock_wait_in_ms: Total number of milliseconds the Database Engine waited on a row 122 | lock. 123 | row_block_pct: Percentage of row locks that encounter waits on a row lock. 124 | avg_row_lock_waits_ms: Average number of milliseconds the Database Engine waited on a row 125 | lock. 126 | page_latch_wait_count: Cumulative number of times the page latch waits occurred 127 | avg_page_latch_wait_ms: Average number of milliseconds the Database Engine waited on a 128 | page latch wait. 129 | page_io_latch_wait_count: Cumulative number of times the page IO latch waits occurred 130 | avg_page_io_latch_wait_ms: Average number of milliseconds the Database Engine waited on a 131 | page IO latch wait. 132 | read_operations: Cumulative count of range_scan_count and singleton_lookup_count 133 | operations 134 | leaf_writes: Cumulative count of leaf_insert_count, leaf_update_count, leaf_delete_count 135 | and leaf_ghost_count operations 136 | leaf_page_allocations: Cumulative count of leaf-level page allocations in the index or 137 | heap. For an index, a page allocation corresponds to a page split. 138 | leaf_page_merges: Cumulative count of page merges at the leaf level. 139 | nonleaf_writes: Cumulative count of leaf_insert_count, leaf_update_count and 140 | leaf_delete_count operations 141 | nonleaf_page_allocations: Cumulative count of page allocations caused by page splits 142 | above the leaf level. 143 | nonleaf_page_merges: Cumulative count of page merges above the leaf level. 144 | indexed_columns: Columns that are part of the index, missing index or foreign key. 145 | included_columns: Columns that are included in the index or missing index. 146 | indexed_columns_ids: Column IDs that are part of the index, missing index or foreign 147 | key 148 | included_column_ids: Column IDs that are included in the index or missing index. 149 | duplicate_indexes: List of Indexes that exist on the table that are identical to the 150 | index on this row. 151 | overlapping_indexes: List of Indexes that exist on the table that overlap the index on 152 | this row. 153 | related_foreign_keys: List of foreign keys that are related to the index either as an 154 | exact match or covering index. 155 | related_foreign_keys_xml: XML document listing foreign keys that are related to the index 156 | either as an exact match or covering index. 157 | 158 | Revision History 159 | Date Version DESCRIPTION 160 | ---------------------------------------------------------------------------------------------- 161 | 2012-12-10 9.01 Rewrote information collection to reduce dynamic SQL 162 | * Fixed issue with Object_ID 163 | * Added unique check to duplication and 164 | overlapping indexes 165 | * Fixed errors with documentation section. 166 | * Added parameters @IncludeMissingIndexes, @IncludeMissingFKIndexes, 167 | and @Output 168 | * Removed DDL create and drop columns for indexes, too much risk in 169 | automatic index building 170 | 2012-12-28 9.02 * Fixed new issues WITH Object_ID 171 | * change missing foreign key logic to include basic details but not 172 | suggest missing indexes with @IncludeMissingFKIndexes flag 173 | * Fixed issues with missing foreign keys that was not displaying them 174 | * Improved default sort for DETAILED output 175 | * Updated case for case-sensitive collations 176 | 2013-01-08 9.03 * Improved error handling to solve issue with truncation MESSAGE 177 | 2013-03-07 9.04 * Fixed duplicate index logic to match that from 178 | http://www.jasonstrate.com/2013/03/thats-actually-a-duplicate-index/ 179 | * Added check for disabled indexes to checks 180 | * Expanded drop reasons with explanations and descriptions for 181 | dropping because of duplication, usage, and count of indexes 182 | * Increased size of foreign key name to accommodate larger names 183 | * Fixed issue causing DROP recommmendation on missing indexes 184 | 2013-03-20 9.05 * Fixed data type on missing_index_impact (Credit: Dick Baker) 185 | 2013-05-22 9.06 * Fixed bug causing mismatch with foreign key analysis 186 | * Adjusted overlapping index logic which was broke with new duplicate 187 | index logic 188 | *********************************************************************************************/ 189 | CREATE PROCEDURE dbo.sp_IndexAnalysis 190 | ( 191 | @TableName NVARCHAR(256) = NULL 192 | ,@IncludeMissingIndexes BIT = 1 193 | ,@IncludeMissingFKIndexes BIT = 1 194 | ,@Output VARCHAR(20) = 'DETAILED' 195 | ) 196 | WITH RECOMPILE 197 | AS 198 | 199 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED 200 | SET NOCOUNT ON 201 | 202 | DECLARE @ERROR_MESSAGE NVARCHAR(2048) 203 | ,@ERROR_SEVERITY INT 204 | ,@ERROR_STATE INT 205 | 206 | DECLARE @SQL NVARCHAR(max) 207 | ,@DB_ID INT 208 | ,@ObjectID INT 209 | ,@DatabaseName NVARCHAR(max) 210 | 211 | BEGIN TRY 212 | IF @Output NOT IN ('DETAILED','DUPLICATE','OVERLAPPING') 213 | RAISERROR('The value "%s" provided for the @Output parameter is not valid',16,1,@Output) 214 | 215 | SELECT @DB_ID = DB_ID() 216 | ,@ObjectID = OBJECT_ID(QUOTENAME(DB_NAME(DB_ID()))+'.'+COALESCE(QUOTENAME(PARSENAME(@TableName,2)),'')+'.'+QUOTENAME(PARSENAME(@TableName,1))) 217 | ,@DatabaseName = QUOTENAME(DB_NAME(DB_ID())) 218 | 219 | -- Obtain memory buffer information on database objects 220 | IF OBJECT_ID('tempdb..#MemoryBuffer') IS NOT NULL 221 | DROP TABLE #MemoryBuffer 222 | 223 | CREATE TABLE #MemoryBuffer ( 224 | database_id INT 225 | ,object_id INT 226 | ,index_id INT 227 | ,partition_number INT 228 | ,buffered_page_count INT 229 | ,buffered_mb DECIMAL(12, 2) 230 | ) 231 | 232 | SET @SQL = 'WITH AllocationUnits 233 | AS ( 234 | SELECT p.object_id 235 | ,p.index_id 236 | ,p.partition_number 237 | ,au.allocation_unit_id 238 | FROM '+@DatabaseName+'.sys.allocation_units AS au 239 | INNER JOIN '+@DatabaseName+'.sys.partitions AS p ON au.container_id = p.hobt_id AND (au.type = 1 OR au.type = 3) 240 | UNION ALL 241 | SELECT p.object_id 242 | ,p.index_id 243 | ,p.partition_number 244 | ,au.allocation_unit_id 245 | FROM '+@DatabaseName+'.sys.allocation_units AS au 246 | INNER JOIN '+@DatabaseName+'.sys.partitions AS p ON au.container_id = p.partition_id AND au.type = 2 247 | ) 248 | SELECT DB_ID() 249 | ,au.object_id 250 | ,au.index_id 251 | ,au.partition_number 252 | ,COUNT(*)AS buffered_page_count 253 | ,CONVERT(DECIMAL(12,2), CAST(COUNT(*) as bigint)*CAST(8 as float)/1024) as buffer_mb 254 | FROM '+@DatabaseName+'.sys.dm_os_buffer_descriptors AS bd 255 | INNER JOIN AllocationUnits au ON bd.allocation_unit_id = au.allocation_unit_id 256 | WHERE bd.database_id = db_id() 257 | GROUP BY au.object_id, au.index_id, au.partition_number' 258 | 259 | BEGIN TRY 260 | INSERT INTO #MemoryBuffer 261 | EXEC sys.sp_executesql @SQL 262 | END TRY 263 | BEGIN CATCH 264 | SELECT @ERROR_MESSAGE = 'Populate #MemoryBuffer (Line '+CAST(ERROR_LINE() AS NVARCHAR(25))+'): ' + ERROR_MESSAGE() 265 | ,@ERROR_SEVERITY = ERROR_SEVERITY() 266 | ,@ERROR_STATE = ERROR_STATE() 267 | 268 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE) 269 | END CATCH 270 | 271 | -- Obtain index meta data information 272 | IF OBJECT_ID('tempdb..#IndexMeta') IS NOT NULL 273 | DROP TABLE #IndexMeta 274 | 275 | CREATE TABLE #IndexMeta ( 276 | database_id SMALLINT 277 | ,filegroup_name NVARCHAR(128) 278 | ,schema_id INT 279 | ,schema_name NVARCHAR(128) 280 | ,object_id INT 281 | ,table_name NVARCHAR(128) 282 | ,index_id INT 283 | ,index_name NVARCHAR(128) 284 | ,is_primary_key BIT 285 | ,is_unique BIT 286 | ,is_disabled BIT 287 | ,type_desc NVARCHAR(128) 288 | ,partition_number INT 289 | ,fill_factor TINYINT 290 | ,is_padded BIT 291 | ,reserved_page_count BIGINT 292 | ,size_in_mb DECIMAL(12, 2) 293 | ,row_count BIGINT 294 | ,indexed_columns NVARCHAR(MAX) 295 | ,included_columns NVARCHAR(MAX) 296 | ,key_columns NVARCHAR(MAX) 297 | ,data_columns NVARCHAR(MAX) 298 | ,indexed_columns_ids NVARCHAR(1024) 299 | ,included_column_ids NVARCHAR(1024) 300 | ) 301 | 302 | SET @SQL = N'SELECT 303 | database_id = DB_ID() 304 | , filegroup = ds.name 305 | , s.schema_id 306 | , schema_name = s.name 307 | , object_id = t.object_id 308 | , table_name = t.name 309 | , i.index_id 310 | , index_name = COALESCE(i.name, ''N/A'') 311 | , ps.partition_number 312 | , i.is_primary_key 313 | , i.is_unique 314 | , i.is_disabled 315 | , type_desc = CASE WHEN i.is_unique = 1 THEN ''UNIQUE '' ELSE '''' END + i.type_desc 316 | , i.fill_factor 317 | , i.is_padded 318 | , ps.reserved_page_count 319 | , size_in_mb = CAST(reserved_page_count * CAST(8 as float) / 1024 as DECIMAL(12,2)) 320 | , row_count 321 | , indexed_columns = STUFF(( 322 | SELECT '', '' + QUOTENAME(c.name) 323 | FROM '+@DatabaseName+'.sys.index_columns ic 324 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 325 | WHERE i.object_id = ic.object_id 326 | AND i.index_id = ic.index_id 327 | AND is_included_column = 0 328 | ORDER BY key_ordinal ASC 329 | FOR XML PATH('''')), 1, 2, '''') 330 | , included_columns = STUFF(( 331 | SELECT '', '' + QUOTENAME(c.name) 332 | FROM '+@DatabaseName+'.sys.index_columns ic 333 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 334 | WHERE i.object_id = ic.object_id 335 | AND i.index_id = ic.index_id 336 | AND is_included_column = 1 337 | ORDER BY key_ordinal ASC 338 | FOR XML PATH('''')), 1, 2, '''') 339 | , key_columns = STUFF(( 340 | SELECT '', '' + QUOTENAME(c.name) 341 | FROM '+@DatabaseName+'.sys.index_columns ic 342 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 343 | WHERE i.object_id = ic.object_id 344 | AND i.index_id = ic.index_id 345 | AND is_included_column = 0 346 | ORDER BY key_ordinal ASC 347 | FOR XML PATH('''')) 348 | + COALESCE((SELECT '', '' + QUOTENAME(c.name) 349 | FROM '+@DatabaseName+'.sys.index_columns ic 350 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 351 | LEFT OUTER JOIN '+@DatabaseName+'.sys.index_columns ic_key ON c.object_id = ic_key.object_id 352 | AND c.column_id = ic_key.column_id 353 | AND i.index_id = ic_key.index_id 354 | AND ic_key.is_included_column = 0 355 | WHERE i.object_id = ic.object_id 356 | AND ic.index_id = 1 357 | AND ic.is_included_column = 0 358 | AND ic_key.index_id IS NULL 359 | ORDER BY ic.key_ordinal ASC 360 | FOR XML PATH('''')),''''), 1, 2, '''') 361 | , data_columns = CASE WHEN i.index_id IN (0,1) THEN ''ALL-COLUMNS'' ELSE STUFF(( 362 | SELECT '', '' + QUOTENAME(c.name) 363 | FROM '+@DatabaseName+'.sys.index_columns ic 364 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 365 | LEFT OUTER JOIN '+@DatabaseName+'.sys.index_columns ic_key ON c.object_id = ic_key.object_id AND c.column_id = ic_key.column_id AND ic_key.index_id = 1 366 | WHERE i.object_id = ic.object_id 367 | AND i.index_id = ic.index_id 368 | AND ic.is_included_column = 1 369 | AND ic_key.index_id IS NULL 370 | ORDER BY ic.key_ordinal ASC 371 | FOR XML PATH('''')), 1, 2, '''') END 372 | , indexed_column_ids = (SELECT QUOTENAME(CAST(ic.column_id AS VARCHAR(10)) 373 | + CASE WHEN ic.is_descending_key = 0 THEN ''+'' ELSE ''-'' END, ''('') 374 | FROM '+@DatabaseName+'.sys.index_columns ic 375 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 376 | WHERE i.object_id = ic.object_id 377 | AND i.index_id = ic.index_id 378 | AND is_included_column = 0 379 | ORDER BY key_ordinal ASC 380 | FOR XML PATH('''')) 381 | + ''|'' + COALESCE((SELECT QUOTENAME(CAST(ic.column_id AS VARCHAR(10)) 382 | + CASE WHEN ic.is_descending_key = 0 THEN ''+'' ELSE ''-'' END, ''('') 383 | FROM '+@DatabaseName+'.sys.index_columns ic 384 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 385 | LEFT OUTER JOIN '+@DatabaseName+'.sys.index_columns ic_key ON c.object_id = ic_key.object_id 386 | AND c.column_id = ic_key.column_id 387 | AND i.index_id = ic_key.index_id 388 | AND ic_key.is_included_column = 0 389 | WHERE i.object_id = ic.object_id 390 | AND ic.index_id = 1 391 | AND ic.is_included_column = 0 392 | AND ic_key.index_id IS NULL 393 | ORDER BY ic.key_ordinal ASC 394 | FOR XML PATH('''')),'''') 395 | + CASE WHEN i.is_unique = 1 THEN ''U'' ELSE '''' END 396 | , included_column_ids = CASE WHEN i.index_id IN (0,1) THEN ''ALL-COLUMNS'' ELSE 397 | COALESCE((SELECT QUOTENAME(ic.column_id,''('') 398 | FROM '+@DatabaseName+'.sys.index_columns ic 399 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 400 | LEFT OUTER JOIN '+@DatabaseName+'.sys.index_columns ic_key ON c.object_id = ic_key.object_id AND c.column_id = ic_key.column_id AND ic_key.index_id = 1 401 | WHERE i.object_id = ic.object_id 402 | AND i.index_id = ic.index_id 403 | AND ic.is_included_column = 1 404 | AND ic_key.index_id IS NULL 405 | ORDER BY ic.key_ordinal ASC 406 | FOR XML PATH('''')), SPACE(0)) END 407 | FROM '+@DatabaseName+'.sys.tables t 408 | INNER JOIN '+@DatabaseName+'.sys.schemas s ON t.schema_id = s.schema_id 409 | INNER JOIN '+@DatabaseName+'.sys.indexes i ON t.object_id = i.object_id 410 | INNER JOIN '+@DatabaseName+'.sys.data_spaces ds ON i.data_space_id = ds.data_space_id 411 | INNER JOIN '+@DatabaseName+'.sys.dm_db_partition_stats ps ON i.object_id = ps.object_id AND i.index_id = ps.index_id' 412 | 413 | IF @ObjectID IS NOT NULL 414 | SET @SQL = @SQL + CHAR(13) + 'WHERE t.object_id = @ObjectID ' 415 | 416 | BEGIN TRY 417 | INSERT INTO #IndexMeta ( 418 | database_id 419 | ,filegroup_name 420 | ,schema_id 421 | ,schema_name 422 | ,object_id 423 | ,table_name 424 | ,index_id 425 | ,index_name 426 | ,partition_number 427 | ,is_primary_key 428 | ,is_unique 429 | ,is_disabled 430 | ,type_desc 431 | ,fill_factor 432 | ,is_padded 433 | ,reserved_page_count 434 | ,size_in_mb 435 | ,row_count 436 | ,indexed_columns 437 | ,included_columns 438 | ,key_columns 439 | ,data_columns 440 | ,indexed_columns_ids 441 | ,included_column_ids) 442 | EXEC sys.sp_executesql @SQL, N'@DB_ID INT, @ObjectID INT', @DB_ID = @DB_ID, @ObjectID = @ObjectID 443 | END TRY 444 | BEGIN CATCH 445 | SELECT @ERROR_MESSAGE = 'Populate #IndexMeta (Line '+CAST(ERROR_LINE() AS NVARCHAR(25))+'): ' + ERROR_MESSAGE() 446 | ,@ERROR_SEVERITY = ERROR_SEVERITY() 447 | ,@ERROR_STATE = ERROR_STATE() 448 | 449 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE) 450 | END CATCH 451 | 452 | IF OBJECT_ID('tempdb..#IndexStatistics') IS NOT NULL 453 | DROP TABLE #IndexStatistics 454 | 455 | SELECT IDENTITY(INT,1,1) AS row_id 456 | ,CAST('' AS VARCHAR(10)) AS index_action 457 | ,CAST('' AS VARCHAR(25)) AS index_pros 458 | ,CAST('' AS VARCHAR(25)) AS index_cons 459 | ,im.database_id 460 | ,im.filegroup_name 461 | ,im.schema_id 462 | ,im.schema_name 463 | ,im.object_id 464 | ,im.table_name 465 | ,im.index_id 466 | ,im.index_name 467 | ,im.is_primary_key 468 | ,im.is_unique 469 | ,im.is_disabled 470 | ,CAST(0 AS BIT) AS has_unique 471 | ,im.type_desc 472 | ,im.partition_number 473 | ,im.fill_factor 474 | ,im.is_padded 475 | ,im.reserved_page_count 476 | ,im.size_in_mb 477 | ,mb.buffered_page_count 478 | ,mb.buffered_mb 479 | ,CAST(0 AS INT) AS table_buffered_mb 480 | ,CAST(100.*mb.buffered_page_count/NULLIF(im.reserved_page_count,0) AS DECIMAL(12,2)) AS buffered_percent 481 | ,im.row_count 482 | ,ROW_NUMBER() OVER (PARTITION BY im.object_id ORDER BY im.is_primary_key desc,ius.user_seeks + ius.user_scans + ius.user_lookups DESC) AS index_rank 483 | , ius.user_seeks + ius.user_scans + ius.user_lookups AS user_total 484 | , COALESCE(CAST(100 * (ius.user_seeks + ius.user_scans + ius.user_lookups) 485 | /(NULLIF(SUM(ius.user_seeks + ius.user_scans + ius.user_lookups) 486 | OVER(PARTITION BY im.object_id), 0) * 1.) as DECIMAL(6,2)),0) AS user_total_pct 487 | ,CAST(0 AS DECIMAL(6,2)) AS estimated_user_total_pct 488 | ,CAST(0 AS FLOAT) AS missing_index_impact -- Dick Baker 201303 (INT range not big enough and is f.p. anyway) 489 | ,ius.user_seeks 490 | ,ius.user_scans 491 | ,ius.user_lookups 492 | ,ius.user_updates 493 | ,(1.*(ius.user_seeks + ius.user_scans + ius.user_lookups))/NULLIF(ius.user_updates,0) AS read_to_update_ratio 494 | ,CASE WHEN ius.user_seeks + ius.user_scans + ius.user_lookups >= ius.user_updates 495 | THEN CEILING(1.*(ius.user_seeks + ius.user_scans + ius.user_lookups)/COALESCE(NULLIF(ius.user_seeks,0),1)) 496 | ELSE 0 END AS read_to_update 497 | ,CASE WHEN ius.user_seeks + ius.user_scans + ius.user_lookups <= ius.user_updates 498 | THEN CEILING(1.*(ius.user_updates)/COALESCE(NULLIF(ius.user_seeks + ius.user_scans + ius.user_lookups,0),1)) 499 | ELSE 0 END AS update_to_read 500 | ,ios.row_lock_count 501 | ,ios.row_lock_wait_count 502 | ,ios.row_lock_wait_in_ms 503 | ,CAST(100.0 * ios.row_lock_wait_count/NULLIF(ios.row_lock_count,0) AS DECIMAL(12,2)) AS row_block_pct 504 | ,CAST(1. * ios.row_lock_wait_in_ms /NULLIF(ios.row_lock_wait_count,0) AS DECIMAL(12,2)) AS avg_row_lock_waits_ms 505 | ,ios.page_latch_wait_count 506 | ,CAST(1. * page_latch_wait_in_ms / NULLIF(ios.page_io_latch_wait_count,0) AS DECIMAL(12,2)) AS avg_page_latch_wait_ms 507 | ,ios.page_io_latch_wait_count 508 | ,CAST(1. * ios.page_io_latch_wait_in_ms / NULLIF(ios.page_io_latch_wait_count,0) AS DECIMAL(12,2)) AS avg_page_io_latch_wait_ms 509 | ,range_scan_count + singleton_lookup_count AS read_operations 510 | ,ios.leaf_insert_count + ios.leaf_update_count + ios.leaf_delete_count + ios.leaf_ghost_count AS leaf_writes 511 | ,leaf_allocation_count As leaf_page_allocations 512 | ,ios.leaf_page_merge_count AS leaf_page_merges 513 | ,ios.nonleaf_insert_count + ios.nonleaf_update_count + ios.nonleaf_delete_count AS nonleaf_writes 514 | ,ios.nonleaf_allocation_count AS nonleaf_page_allocations 515 | ,ios.nonleaf_page_merge_count AS nonleaf_page_merges 516 | ,im.indexed_columns 517 | ,im.included_columns 518 | ,key_columns 519 | ,data_columns 520 | ,im.indexed_columns_ids 521 | ,im.included_column_ids 522 | ,CAST('' AS VARCHAR(MAX)) AS duplicate_indexes 523 | ,CAST('' AS SMALLINT) AS first_dup_index_id 524 | ,CAST('' AS VARCHAR(MAX)) AS overlapping_indexes 525 | ,CAST('' AS VARCHAR(MAX)) AS related_foreign_keys 526 | ,CAST('' AS XML) AS related_foreign_keys_xml 527 | INTO #IndexStatistics 528 | FROM #IndexMeta im 529 | LEFT OUTER JOIN sys.dm_db_index_usage_stats ius ON im.object_id = ius.object_id AND im.index_id = ius.index_id AND im.database_id = ius.database_id 530 | LEFT OUTER JOIN sys.dm_db_index_operational_stats(@DB_ID, NULL, NULL, NULL) ios ON im.object_id = ios.object_id AND im.index_id = ios.index_id AND im.partition_number = ios.partition_number 531 | LEFT OUTER JOIN #MemoryBuffer mb ON im.object_id = mb.object_id AND im.index_id = mb.index_id AND im.partition_number = mb.partition_number 532 | 533 | IF @IncludeMissingIndexes = 1 534 | BEGIN 535 | INSERT INTO #IndexStatistics 536 | (filegroup_name, schema_id, schema_name, object_id, table_name, index_name, type_desc, missing_index_impact, index_rank, user_total, user_seeks, user_scans, user_lookups, indexed_columns, included_columns) 537 | SELECT 538 | '' AS filegroup_name 539 | ,SCHEMA_ID(OBJECT_SCHEMA_NAME(mid.object_id)) AS schema_id 540 | ,OBJECT_SCHEMA_NAME(mid.object_id) AS schema_name 541 | ,mid.object_id 542 | ,OBJECT_NAME(mid.object_id) AS table_name 543 | ,'--MISSING INDEX--' AS index_name 544 | ,'NONCLUSTERED' AS type_desc 545 | ,(migs.user_seeks + migs.user_scans) * migs.avg_user_impact as impact 546 | ,0 AS index_rank 547 | ,migs.user_seeks + migs.user_scans as user_total 548 | ,migs.user_seeks 549 | ,migs.user_scans 550 | ,0 as user_lookups 551 | ,COALESCE(equality_columns + CASE WHEN inequality_columns IS NOT NULL THEN ', ' ELSE SPACE(0) END, SPACE(0)) + COALESCE(inequality_columns, SPACE(0)) as indexed_columns 552 | ,included_columns 553 | FROM sys.dm_db_missing_index_details mid 554 | INNER JOIN sys.dm_db_missing_index_groups mig ON mid.index_handle = mig.index_handle 555 | INNER JOIN sys.dm_db_missing_index_group_stats migs ON mig.index_group_handle = migs.group_handle 556 | WHERE mid.database_id = @DB_ID 557 | END 558 | 559 | -- Collect foreign key information. 560 | IF OBJECT_ID('tempdb..#ForeignKeys') IS NOT NULL 561 | DROP TABLE #ForeignKeys 562 | 563 | CREATE TABLE #ForeignKeys 564 | ( 565 | foreign_key_name NVARCHAR(256) 566 | ,object_id INT 567 | ,fk_columns NVARCHAR(max) 568 | ,fk_columns_ids NVARCHAR(1024) 569 | ) 570 | 571 | SET @SQL = N'SELECT fk.name + ''|PARENT'' AS foreign_key_name 572 | ,fkc.parent_object_id AS object_id 573 | ,STUFF((SELECT '', '' + QUOTENAME(c.name) 574 | FROM '+@DatabaseName+'.sys.foreign_key_columns ifkc 575 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ifkc.parent_object_id = c.object_id AND ifkc.parent_column_id = c.column_id 576 | WHERE fk.object_id = ifkc.constraint_object_id 577 | ORDER BY ifkc.constraint_column_id 578 | FOR XML PATH('''')), 1, 2, '''') AS fk_columns 579 | ,(SELECT QUOTENAME(CAST(ifkc.parent_column_id AS VARCHAR(10))+''+'',''('') 580 | FROM '+@DatabaseName+'.sys.foreign_key_columns ifkc 581 | WHERE fk.object_id = ifkc.constraint_object_id 582 | ORDER BY ifkc.constraint_column_id 583 | FOR XML PATH('''')) AS fk_columns_compare 584 | FROM '+@DatabaseName+'.sys.foreign_keys fk 585 | INNER JOIN '+@DatabaseName+'.sys.foreign_key_columns fkc ON fk.object_id = fkc.constraint_object_id 586 | WHERE fkc.constraint_column_id = 1 587 | AND (fkc.parent_object_id = @ObjectID OR @ObjectID IS NULL) 588 | UNION ALL 589 | SELECT fk.name + ''|REFERENCED'' as foreign_key_name 590 | ,fkc.referenced_object_id AS object_id 591 | ,STUFF((SELECT '', '' + QUOTENAME(c.name) 592 | FROM '+@DatabaseName+'.sys.foreign_key_columns ifkc 593 | INNER JOIN '+@DatabaseName+'.sys.columns c ON ifkc.referenced_object_id = c.object_id AND ifkc.referenced_column_id = c.column_id 594 | WHERE fk.object_id = ifkc.constraint_object_id 595 | ORDER BY ifkc.constraint_column_id 596 | FOR XML PATH('''')), 1, 2, '''') AS fk_columns 597 | ,(SELECT QUOTENAME(CAST(ifkc.referenced_column_id AS VARCHAR(10))+''+'',''('') 598 | FROM '+@DatabaseName+'.sys.foreign_key_columns ifkc 599 | WHERE fk.object_id = ifkc.constraint_object_id 600 | ORDER BY ifkc.constraint_column_id 601 | FOR XML PATH('''')) AS fk_columns_compare 602 | FROM '+@DatabaseName+'.sys.foreign_keys fk 603 | INNER JOIN '+@DatabaseName+'.sys.foreign_key_columns fkc ON fk.object_id = fkc.constraint_object_id 604 | WHERE fkc.constraint_column_id = 1 605 | AND (fkc.referenced_object_id = @ObjectID OR @ObjectID IS NULL)' 606 | 607 | BEGIN TRY 608 | INSERT INTO #ForeignKeys 609 | (foreign_key_name, object_id, fk_columns, fk_columns_ids) 610 | EXEC sp_executesql @SQL, N'@DB_ID INT, @ObjectID INT', @DB_ID = @DB_ID, @ObjectID = @ObjectID 611 | END TRY 612 | BEGIN CATCH 613 | SELECT @ERROR_MESSAGE = 'Populate #ForeignKeys (Line '+CAST(ERROR_LINE() AS NVARCHAR(25))+'): ' + ERROR_MESSAGE() 614 | ,@ERROR_SEVERITY = ERROR_SEVERITY() 615 | ,@ERROR_STATE = ERROR_STATE() 616 | 617 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE) 618 | END CATCH 619 | 620 | -- Determine duplicate, overlapping, and foreign key index information 621 | UPDATE i 622 | SET duplicate_indexes = STUFF((SELECT ', ' + index_name AS [data()] 623 | FROM #IndexStatistics iibl 624 | WHERE i.object_id = iibl.object_id 625 | AND i.is_primary_key = iibl.is_primary_key 626 | AND i.is_unique = iibl.is_unique 627 | AND i.index_id <> iibl.index_id 628 | AND REPLACE(i.indexed_columns_ids,'|','') = REPLACE(iibl.indexed_columns_ids,'|','') 629 | AND i.included_column_ids = iibl.included_column_ids 630 | FOR XML PATH('')), 1, 2, '') 631 | ,first_dup_index_id = (SELECT MIN(index_id) 632 | FROM #IndexStatistics iibl 633 | WHERE i.object_id = iibl.object_id 634 | AND i.is_primary_key = iibl.is_primary_key 635 | AND i.is_unique = iibl.is_unique 636 | AND i.index_id > iibl.index_id 637 | AND REPLACE(i.indexed_columns_ids,'|','') = REPLACE(iibl.indexed_columns_ids,'|','') 638 | AND i.included_column_ids = iibl.included_column_ids) 639 | ,overlapping_indexes = STUFF((SELECT ', ' + index_name AS [data()] 640 | FROM #IndexStatistics iibl 641 | WHERE i.object_id = iibl.object_id 642 | AND i.is_primary_key = iibl.is_primary_key 643 | AND i.is_unique = iibl.is_unique 644 | AND i.index_id <> iibl.index_id 645 | AND LEFT(i.indexed_columns_ids, CHARINDEX('|',iibl.indexed_columns_ids,1)-1) 646 | LIKE LEFT(iibl.indexed_columns_ids, CHARINDEX('|',i.indexed_columns_ids,1)-1) + '%' 647 | AND Replace(i.indexed_columns_ids,'|','') <> Replace(iibl.indexed_columns_ids,'|','') 648 | FOR XML PATH('')), 1, 2, '') 649 | ,related_foreign_keys = STUFF((SELECT ', ' + foreign_key_name AS [data()] 650 | FROM #ForeignKeys ifk 651 | WHERE ifk.object_id = i.object_id 652 | AND i.indexed_columns_ids LIKE ifk.fk_columns_ids + '%' 653 | FOR XML PATH('')), 1, 2, '') 654 | ,related_foreign_keys_xml = CAST((SELECT foreign_key_name 655 | FROM #ForeignKeys fk 656 | WHERE fk.object_id = i.object_id 657 | AND i.indexed_columns_ids LIKE fk.fk_columns_ids + '%' 658 | FOR XML AUTO) as xml) 659 | FROM #IndexStatistics i 660 | 661 | IF @IncludeMissingFKIndexes = 1 662 | BEGIN 663 | INSERT INTO #IndexStatistics 664 | (filegroup_name, schema_id, schema_name, object_id, table_name, index_name, type_desc, index_rank, indexed_columns, related_foreign_keys) 665 | SELECT '' AS filegroup_name 666 | ,SCHEMA_ID(OBJECT_SCHEMA_NAME(fk.object_id)) AS schema_id 667 | ,OBJECT_SCHEMA_NAME(fk.object_id) AS schema_name 668 | ,fk.object_id 669 | ,OBJECT_NAME(fk.object_id) AS table_name 670 | ,'--MISSING FOREIGN KEY--' AS index_name 671 | ,'NONCLUSTERED' AS type_desc 672 | ,9999 673 | ,fk.fk_columns 674 | ,fk.foreign_key_name 675 | FROM #ForeignKeys fk 676 | LEFT OUTER JOIN #IndexStatistics i ON fk.object_id = i.object_id AND i.indexed_columns_ids LIKE fk.fk_columns_ids + '%' 677 | WHERE i.index_name IS NULL 678 | END 679 | 680 | -- Determine whether tables have unique indexes 681 | UPDATE i 682 | SET has_unique = 1 683 | FROM #IndexStatistics i 684 | WHERE EXISTS (SELECT * FROM #IndexStatistics ii WHERE i.object_id = ii.object_id AND ii.is_unique = 1) 685 | 686 | -- Calculate estimated user total for each index. 687 | ;WITH Aggregation 688 | AS ( 689 | SELECT row_id 690 | ,CAST(100. * (user_seeks + user_scans + user_lookups) 691 | /(NULLIF(SUM(user_seeks + user_scans + user_lookups) 692 | OVER(PARTITION BY schema_name, table_name), 0) * 1.) as DECIMAL(12,2)) AS estimated_user_total_pct 693 | ,SUM(buffered_mb) OVER(PARTITION BY schema_name, table_name) as table_buffered_mb 694 | FROM #IndexStatistics 695 | ) 696 | UPDATE ibl 697 | SET estimated_user_total_pct = COALESCE(a.estimated_user_total_pct, 0) 698 | ,table_buffered_mb = a.table_buffered_mb 699 | FROM #IndexStatistics ibl 700 | INNER JOIN Aggregation a ON ibl.row_id = a.row_id 701 | 702 | -- Update Index Action information 703 | ;WITH IndexAction 704 | AS ( 705 | SELECT row_id 706 | ,CASE WHEN user_lookups > user_seeks AND type_desc IN ('CLUSTERED', 'HEAP', 'UNIQUE CLUSTERED') THEN 'REALIGN' 707 | WHEN is_disabled = 1 THEN 'ENABLE' 708 | WHEN duplicate_indexes IS NOT NULL AND first_dup_index_id IS NOT NULL AND index_id IS NOT NULL THEN 'DROP-DUP' 709 | WHEN type_desc = '--MISSING FOREIGN KEY--' THEN 'CREATE' 710 | WHEN type_desc = 'XML' THEN '---' 711 | WHEN is_unique = 1 THEN '---' 712 | WHEN related_foreign_keys IS NOT NULL THEN '---' 713 | WHEN type_desc = '--NONCLUSTERED--' AND ROW_NUMBER() OVER (PARTITION BY table_name ORDER BY user_total desc) <= 10 AND estimated_user_total_pct > 1 THEN 'CREATE' 714 | WHEN type_desc = '--NONCLUSTERED--' THEN 'BLEND' 715 | WHEN ROW_NUMBER() OVER (PARTITION BY table_name ORDER BY user_total desc, index_rank) > 10 AND index_id IS NOT NULL THEN 'DROP-COUNT' 716 | WHEN index_id NOT IN (0,1) AND duplicate_indexes IS NULL AND user_total = 0 AND index_id IS NOT NULL 717 | THEN 'DROP-USAGE' 718 | ELSE '---' END AS index_action 719 | FROM #IndexStatistics 720 | ) 721 | UPDATE ibl 722 | SET index_action = ia.index_action 723 | FROM #IndexStatistics ibl INNER JOIN IndexAction ia 724 | ON ibl.row_id = ia.row_id 725 | 726 | -- Update Pro/Con statuses 727 | UPDATE #IndexStatistics 728 | SET index_pros = COALESCE(STUFF(CASE WHEN related_foreign_keys IS NOT NULL THEN ', FK' ELSE '' END 729 | + CASE WHEN is_unique = 1 THEN ', UQ' ELSE '' END 730 | + COALESCE(', ' + CASE WHEN read_to_update BETWEEN 1 AND 9 THEN '$' 731 | WHEN read_to_update BETWEEN 10 AND 99 THEN '$$' 732 | WHEN read_to_update BETWEEN 100 AND 999 THEN '$$$' 733 | WHEN read_to_update > 999 THEN '$$$+' END, '') 734 | ,1,2,''),'') 735 | ,index_cons = COALESCE(STUFF(CASE WHEN user_seeks / NULLIF(user_scans,0) < 1000 THEN ', SCN' ELSE '' END 736 | + CASE WHEN duplicate_indexes IS NOT NULL THEN ', DP' ELSE '' END 737 | + CASE WHEN overlapping_indexes IS NOT NULL THEN ', OV' ELSE '' END 738 | + COALESCE(', ' + CASE WHEN update_to_read BETWEEN 1 AND 9 THEN '$' 739 | WHEN update_to_read BETWEEN 10 AND 99 THEN '$$' 740 | WHEN update_to_read BETWEEN 100 AND 999 THEN '$$$' 741 | WHEN update_to_read > 999 THEN '$$$+' END, '') 742 | + CASE WHEN is_disabled = 1 THEN ', DSB' ELSE '' END 743 | ,1,2,''),'') 744 | 745 | IF @Output = 'DETAILED' 746 | BEGIN 747 | SELECT 748 | index_action 749 | , index_pros 750 | , index_cons 751 | , QUOTENAME(schema_name) + '.' + QUOTENAME(table_name) as object_name 752 | , index_name 753 | , type_desc 754 | , indexed_columns 755 | , included_columns 756 | , is_primary_key 757 | , is_unique 758 | , is_disabled 759 | , has_unique 760 | , partition_number 761 | , fill_factor 762 | , is_padded 763 | , size_in_mb 764 | , buffered_mb 765 | , table_buffered_mb 766 | , buffered_percent 767 | , row_count 768 | , user_total_pct 769 | , estimated_user_total_pct 770 | , missing_index_impact 771 | , user_total 772 | , user_seeks 773 | , user_scans 774 | , user_lookups 775 | , user_updates 776 | , read_to_update_ratio 777 | , read_to_update 778 | , update_to_read 779 | , row_lock_count 780 | , row_lock_wait_count 781 | , row_lock_wait_in_ms 782 | , row_block_pct 783 | , avg_row_lock_waits_ms 784 | , page_latch_wait_count 785 | , avg_page_latch_wait_ms 786 | , page_io_latch_wait_count 787 | , avg_page_io_latch_wait_ms 788 | , read_operations 789 | , leaf_writes 790 | , leaf_page_allocations 791 | , leaf_page_merges 792 | , nonleaf_writes 793 | , nonleaf_page_allocations 794 | , nonleaf_page_merges 795 | , duplicate_indexes 796 | , overlapping_indexes 797 | , related_foreign_keys 798 | , related_foreign_keys_xml 799 | , key_columns 800 | , data_columns 801 | FROM #IndexStatistics 802 | WHERE (estimated_user_total_pct > 0.01 AND index_id IS NULL) 803 | OR related_foreign_keys IS NOT NULL 804 | OR index_id IS NOT NULL 805 | ORDER BY table_buffered_mb DESC, object_id, COALESCE(user_total,-1) DESC, COALESCE(user_updates,-1) DESC, COALESCE(index_id,999) 806 | END 807 | ELSE IF @Output = 'DUPLICATE' 808 | BEGIN 809 | SELECT 810 | DENSE_RANK() OVER (ORDER BY key_columns, data_columns) AS duplicate_group 811 | , index_action 812 | , index_pros 813 | , index_cons 814 | , QUOTENAME(schema_name) + '.' + QUOTENAME(table_name) as object_name 815 | , index_name 816 | , type_desc 817 | , indexed_columns 818 | , included_columns 819 | , is_primary_key 820 | , is_unique 821 | , duplicate_indexes 822 | , size_in_mb 823 | , buffered_mb 824 | , table_buffered_mb 825 | , buffered_percent 826 | , row_count 827 | , user_total_pct 828 | , user_total 829 | , user_seeks 830 | , user_scans 831 | , user_lookups 832 | , user_updates 833 | , read_operations 834 | FROM #IndexStatistics 835 | WHERE duplicate_indexes IS NOT NULL 836 | ORDER BY table_buffered_mb DESC, object_id, RANK() OVER (ORDER BY key_columns, data_columns) 837 | END 838 | ELSE IF @Output = 'OVERLAPPING' 839 | BEGIN 840 | SELECT 841 | index_action 842 | , index_pros 843 | , index_cons 844 | , QUOTENAME(schema_name) + '.' + QUOTENAME(table_name) as OBJECT_NAME 845 | , overlapping_indexes 846 | , index_name 847 | , type_desc 848 | , indexed_columns 849 | , included_columns 850 | , is_primary_key 851 | , is_unique 852 | , size_in_mb 853 | , buffered_mb 854 | , table_buffered_mb 855 | , buffered_percent 856 | , row_count 857 | , user_total_pct 858 | , user_total 859 | , user_seeks 860 | , user_scans 861 | , user_lookups 862 | , user_updates 863 | , read_operations 864 | FROM #IndexStatistics 865 | WHERE overlapping_indexes IS NOT NULL 866 | ORDER BY table_buffered_mb DESC, object_id, user_total DESC 867 | END 868 | 869 | END TRY 870 | BEGIN CATCH 871 | SELECT @ERROR_MESSAGE = 'Procedure Error (Line '+CAST(ERROR_LINE() AS NVARCHAR(25))+'): ' + ERROR_MESSAGE() 872 | ,@ERROR_SEVERITY = ERROR_SEVERITY() 873 | ,@ERROR_STATE = ERROR_STATE() 874 | 875 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE) 876 | END CATCH 877 | GO 878 | 879 | USE AdventureWorks 880 | GO 881 | 882 | EXEC dbo.sp_IndexAnalysis @Output = 'DETAILED' 883 | ,@TableName = 'Sales.SalesOrderDetail' 884 | ,@IncludeMissingIndexes = 1 885 | ,@IncludeMissingFKIndexes = 1 886 | -------------------------------------------------------------------------------- /sp_IndexAnalysis-SQLServer2008.sql: -------------------------------------------------------------------------------- 1 | USE [master]; 2 | GO 3 | 4 | IF OBJECT_ID('dbo.sp_IndexAnalysis') IS NOT NULL 5 | DROP PROCEDURE [dbo].[sp_IndexAnalysis]; 6 | GO 7 | 8 | /********************************************************************************************* 9 | Index Analysis Script - SQL Server 2008 10 | (C) 2013, Jason Strate 11 | 12 | Feedback: 13 | mailto:jasonstrate@gmail.com 14 | http://www.jasonstrate.com 15 | 16 | License: 17 | This query is free to download and use for personal, educational, and internal 18 | corporate purposes, provided that this header is preserved. Redistribution or sale 19 | of this query, in whole or in part, is prohibited without the author's express 20 | written consent. 21 | 22 | More details: 23 | https://github.com/StrateSQL/sqlserver_indexanalysis 24 | 25 | *********************************************************************************************/ 26 | CREATE PROCEDURE [dbo].[sp_IndexAnalysis] 27 | ( 28 | @TableName NVARCHAR(256) = NULL , 29 | @IncludeMemoryDetails BIT = 1 , 30 | @IncludeMissingIndexes BIT = 1 , 31 | @IncludeMissingFKIndexes BIT = 1 , 32 | @ConsolidatePartitionStats BIT = 1 , 33 | @Output VARCHAR(20) = 'DUMP' , 34 | @PageCompressionThreshold INT = 1000 , 35 | @RowCompressionThreshold DECIMAL(4, 2) = 1 , 36 | @CheckCompression BIT = 1 , 37 | @ReadOnlyDatabase BIT = 0 , 38 | @MaxMissingIndexCount TINYINT = 5 , 39 | @MinLookupThreshold INT = 1000 , 40 | @MinScanThreshold INT = 100 , 41 | @Scan2SeekRatio INT = 1000 , 42 | @ProcessingMessages BIT = 0 43 | ) 44 | WITH RECOMPILE 45 | AS 46 | BEGIN 47 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 48 | SET NOCOUNT ON; 49 | 50 | DECLARE @ERROR_MESSAGE NVARCHAR(2048) , 51 | @ERROR_SEVERITY INT , 52 | @ERROR_STATE INT , 53 | @PROCESSING_START DATETIME; 54 | 55 | DECLARE @SQL NVARCHAR(MAX) , 56 | @DB_ID INT , 57 | @ObjectID INT , 58 | @DatabaseName NVARCHAR(MAX); 59 | 60 | BEGIN TRY 61 | --================================================================================================ 62 | -- Remove temporary tables 63 | --================================================================================================ 64 | IF OBJECT_ID('tempdb..#MemoryBuffer') IS NOT NULL 65 | DROP TABLE [#MemoryBuffer]; 66 | 67 | IF OBJECT_ID('tempdb..#TableMeta') IS NOT NULL 68 | DROP TABLE [#TableMeta]; 69 | 70 | IF OBJECT_ID('tempdb..#IndexMeta') IS NOT NULL 71 | DROP TABLE [#IndexMeta]; 72 | 73 | IF OBJECT_ID('tempdb..#IndexStatistics') IS NOT NULL 74 | DROP TABLE [#IndexStatistics]; 75 | 76 | IF OBJECT_ID('tempdb..#ForeignKeys') IS NOT NULL 77 | DROP TABLE [#ForeignKeys]; 78 | 79 | IF @Output NOT IN ('DUMP', 'DETAILED', 'DUPLICATE', 'OVERLAPPING', 'REALIGN') 80 | RAISERROR('The value "%s" provided for the @Output parameter is not valid',16,1,@Output); 81 | 82 | SELECT @DB_ID = DB_ID() , 83 | @ObjectID = OBJECT_ID(QUOTENAME(DB_NAME(DB_ID())) + '.' + COALESCE(QUOTENAME(PARSENAME(@TableName, 2)), '') + '.' 84 | + QUOTENAME(PARSENAME(@TableName, 1))) , 85 | @DatabaseName = QUOTENAME(DB_NAME(DB_ID())); 86 | 87 | IF @TableName IS NOT NULL 88 | AND @ObjectID IS NULL 89 | RAISERROR('The object "%s" could not be found. Execution cancelled.',16,1,@TableName); 90 | 91 | -- Obtain memory buffer information on database objects 92 | CREATE TABLE [#MemoryBuffer] 93 | ( 94 | [database_id] INT , 95 | [object_id] INT , 96 | [index_id] INT , 97 | [partition_number] INT , 98 | [buffered_page_count] INT , 99 | [buffered_mb] DECIMAL(12, 2) 100 | ); 101 | 102 | IF @IncludeMemoryDetails = 1 103 | BEGIN 104 | SET @PROCESSING_START = GETDATE(); 105 | SET @SQL = 'WITH AllocationUnits 106 | AS ( 107 | SELECT p.object_id 108 | ,p.index_id 109 | ,CASE WHEN @ConsolidatePartitionStats = 0 THEN p.partition_number ELSE -1 END AS partition_number 110 | ,au.allocation_unit_id 111 | FROM ' + @DatabaseName + '.sys.allocation_units AS au 112 | INNER JOIN ' + @DatabaseName + '.sys.partitions AS p ON au.container_id = p.hobt_id AND (au.type = 1 OR au.type = 3) 113 | UNION ALL 114 | SELECT p.object_id 115 | ,p.index_id 116 | ,CASE WHEN @ConsolidatePartitionStats = 0 THEN p.partition_number ELSE -1 END AS partition_number 117 | ,au.allocation_unit_id 118 | FROM ' + @DatabaseName + '.sys.allocation_units AS au 119 | INNER JOIN ' + @DatabaseName + '.sys.partitions AS p ON au.container_id = p.partition_id AND au.type = 2 120 | ) 121 | SELECT DB_ID() 122 | ,au.object_id 123 | ,au.index_id 124 | ,au.partition_number 125 | ,COUNT(*) AS buffered_page_count 126 | ,CONVERT(DECIMAL(12,2), CAST(COUNT(*) as bigint)*CAST(8 as float)/1024) as buffer_mb 127 | FROM ' + @DatabaseName + '.sys.dm_os_buffer_descriptors AS bd 128 | INNER JOIN AllocationUnits au ON bd.allocation_unit_id = au.allocation_unit_id 129 | WHERE bd.database_id = db_id() 130 | GROUP BY au.object_id, au.index_id, au.partition_number 131 | '; 132 | 133 | BEGIN TRY 134 | IF @ConsolidatePartitionStats = 1 135 | BEGIN 136 | RAISERROR('Strate''s Warning: Buffered memory totals are an aggregate for all partitions on the table. This behaviour is controlled by the @ConsolidatePartitionStats parameter',10,1) WITH NOWAIT; 137 | PRINT ''; 138 | END; 139 | 140 | INSERT INTO [#MemoryBuffer] 141 | EXEC [sys].[sp_executesql] @SQL, N'@ConsolidatePartitionStats BIT', @ConsolidatePartitionStats = @ConsolidatePartitionStats; 142 | 143 | IF @ProcessingMessages = 1 144 | PRINT 'Processing #MemoryBuffer... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 145 | END TRY 146 | BEGIN CATCH 147 | SELECT @ERROR_MESSAGE = 'Populate #MemoryBuffer (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 148 | @ERROR_SEVERITY = ERROR_SEVERITY() , 149 | @ERROR_STATE = ERROR_STATE(); 150 | 151 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 152 | END CATCH; 153 | END; 154 | 155 | -- Obtain index meta data information 156 | BEGIN 157 | SET @PROCESSING_START = GETDATE(); 158 | 159 | CREATE TABLE [#TableMeta] 160 | ( 161 | [database_id] SMALLINT , 162 | [schema_id] INT , 163 | [schema_name] NVARCHAR(128) , 164 | [object_id] INT , 165 | [table_name] NVARCHAR(128) , 166 | [object_name] NVARCHAR(260) , 167 | [table_column_count] SMALLINT , 168 | [table_row_count] BIGINT , 169 | [has_unique] BIT 170 | ); 171 | 172 | SET @SQL = N'SELECT 173 | DB_ID() 174 | , s.schema_id 175 | , s.name 176 | , t.object_id 177 | , t.name 178 | , QUOTENAME(s.name)+''.''+QUOTENAME(t.name) 179 | , c2.table_column_count 180 | , ps2.row_count 181 | , CASE WHEN i2.is_unique > 0 THEN 1 ELSE 0 END 182 | FROM ' + @DatabaseName + '.sys.tables t 183 | INNER JOIN ' + @DatabaseName + '.sys.schemas s ON t.schema_id = s.schema_id 184 | CROSS APPLY (SELECT SUM(row_count) AS row_count FROM ' + @DatabaseName 185 | + '.sys.dm_db_partition_stats ps WHERE t.object_id = ps.object_id AND ps.index_id IN (0,1)) ps2 186 | CROSS APPLY (SELECT COUNT(*) AS table_column_count FROM ' + @DatabaseName + '.sys.columns c1 WHERE t.object_id = c1.object_id) c2 187 | CROSS APPLY (SELECT COUNT(*) AS is_unique FROM ' + @DatabaseName + '.sys.indexes i1 WHERE t.object_id = i1.object_id AND is_unique = 1) i2'; 188 | 189 | IF @ObjectID IS NOT NULL 190 | SET @SQL = @SQL + CHAR(13) + 'WHERE t.object_id = @ObjectID '; 191 | 192 | BEGIN TRY 193 | INSERT INTO [#TableMeta] 194 | EXEC [sys].[sp_executesql] @SQL, N'@DB_ID INT, @ObjectID INT', @DB_ID = @DB_ID, @ObjectID = @ObjectID; 195 | 196 | IF @ProcessingMessages = 1 197 | PRINT 'Processing #TableMeta... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 198 | END TRY 199 | BEGIN CATCH 200 | SELECT @ERROR_MESSAGE = 'Populate #TableMeta (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 201 | @ERROR_SEVERITY = ERROR_SEVERITY() , 202 | @ERROR_STATE = ERROR_STATE(); 203 | 204 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 205 | END CATCH; 206 | END; 207 | 208 | BEGIN 209 | SET @PROCESSING_START = GETDATE(); 210 | 211 | CREATE TABLE [#IndexMeta] 212 | ( 213 | [database_id] SMALLINT , 214 | [object_id] INT , 215 | [filegroup_name] NVARCHAR(128) , 216 | [compression_type] NVARCHAR(128) , 217 | [index_id] INT , 218 | [index_name] NVARCHAR(128) , 219 | [partition_count] SMALLINT , 220 | [partition_number] INT , 221 | [is_primary_key] BIT , 222 | [is_unique] BIT , 223 | [is_disabled] BIT , 224 | [type_desc] NVARCHAR(128) , 225 | [fill_factor] TINYINT , 226 | [is_padded] BIT , 227 | [reserved_page_count] BIGINT , 228 | [used_page_count] BIGINT , 229 | [size_in_mb] DECIMAL(12, 2) , 230 | [index_row_count] BIGINT , 231 | [filter_definition] NVARCHAR(MAX) , 232 | [indexed_columns] NVARCHAR(MAX) , 233 | [indexed_column_count] SMALLINT , 234 | [included_columns] NVARCHAR(MAX) , 235 | [included_column_count] SMALLINT , 236 | [key_columns] NVARCHAR(MAX) , 237 | [data_columns] NVARCHAR(MAX) , 238 | [indexed_columns_ids] NVARCHAR(1024) , 239 | [included_column_ids] NVARCHAR(1024) , 240 | [distinct_indexed_columns_ids] NVARCHAR(1024) 241 | ); 242 | 243 | 244 | SET @SQL = N'SELECT 245 | database_id = DB_ID() 246 | , object_id = t.object_id 247 | , filegroup = ds.name 248 | , x.data_compression_desc 249 | , i.index_id 250 | , index_name = COALESCE(i.name, ''N/A'') 251 | , x.partition_count 252 | , x.partition_number 253 | , i.is_primary_key 254 | , i.is_unique 255 | , i.is_disabled 256 | , type_desc = CASE WHEN i.is_unique = 1 THEN ''UNIQUE '' ELSE '''' END + i.type_desc 257 | , i.fill_factor 258 | , i.is_padded 259 | , x.reserved_page_count 260 | , x.used_page_count 261 | , size_in_mb = CAST(reserved_page_count * CAST(8 as float) / 1024 as DECIMAL(12,2)) 262 | , row_count 263 | , i.filter_definition 264 | , indexed_columns = STUFF(( 265 | SELECT '', '' + QUOTENAME(c.name) 266 | FROM ' + @DatabaseName + '.sys.index_columns ic 267 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 268 | WHERE i.object_id = ic.object_id 269 | AND i.index_id = ic.index_id 270 | AND is_included_column = 0 271 | ORDER BY key_ordinal ASC 272 | FOR XML PATH('''')), 1, 2, '''') 273 | , indexed_column_count = ( 274 | SELECT COUNT(*) 275 | FROM ' + @DatabaseName + '.sys.index_columns ic 276 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 277 | WHERE i.object_id = ic.object_id 278 | AND i.index_id = ic.index_id 279 | AND is_included_column = 0) 280 | , included_columns = STUFF(( 281 | SELECT '', '' + QUOTENAME(c.name) 282 | FROM ' + @DatabaseName + '.sys.index_columns ic 283 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 284 | WHERE i.object_id = ic.object_id 285 | AND i.index_id = ic.index_id 286 | AND is_included_column = 1 287 | ORDER BY key_ordinal ASC 288 | FOR XML PATH('''')), 1, 2, '''') 289 | , included_column_count = ( 290 | SELECT COUNT(*) 291 | FROM ' + @DatabaseName + '.sys.index_columns ic 292 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 293 | WHERE i.object_id = ic.object_id 294 | AND i.index_id = ic.index_id 295 | AND is_included_column = 1) 296 | , key_columns = STUFF(( 297 | SELECT '', '' + QUOTENAME(c.name) 298 | FROM ' + @DatabaseName + '.sys.index_columns ic 299 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 300 | WHERE i.object_id = ic.object_id 301 | AND i.index_id = ic.index_id 302 | AND is_included_column = 0 303 | ORDER BY key_ordinal ASC 304 | FOR XML PATH('''')) 305 | + COALESCE((SELECT '', '' + QUOTENAME(c.name) 306 | FROM ' + @DatabaseName + '.sys.index_columns ic 307 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 308 | LEFT OUTER JOIN ' + @DatabaseName + '.sys.index_columns ic_key ON c.object_id = ic_key.object_id 309 | AND c.column_id = ic_key.column_id 310 | AND i.index_id = ic_key.index_id 311 | AND ic_key.is_included_column = 0 312 | WHERE i.object_id = ic.object_id 313 | AND ic.index_id = 1 314 | AND ic.is_included_column = 0 315 | AND ic_key.index_id IS NULL 316 | ORDER BY ic.key_ordinal ASC 317 | FOR XML PATH('''')),''''), 1, 2, '''') 318 | , data_columns = CASE WHEN i.index_id IN (0,1) THEN ''ALL-COLUMNS'' ELSE STUFF(( 319 | SELECT '', '' + QUOTENAME(c.name) 320 | FROM ' + @DatabaseName + '.sys.index_columns ic 321 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 322 | LEFT OUTER JOIN ' + @DatabaseName 323 | + '.sys.index_columns ic_key ON c.object_id = ic_key.object_id AND c.column_id = ic_key.column_id AND ic_key.index_id = 1 324 | WHERE i.object_id = ic.object_id 325 | AND i.index_id = ic.index_id 326 | AND ic.is_included_column = 1 327 | AND ic_key.index_id IS NULL 328 | ORDER BY ic.key_ordinal ASC 329 | FOR XML PATH('''')), 1, 2, '''') END 330 | , indexed_column_ids = (SELECT QUOTENAME(CAST(ic.column_id AS VARCHAR(10)) 331 | + CASE WHEN ic.is_descending_key = 0 THEN ''+'' ELSE ''-'' END,''('') 332 | FROM ' + @DatabaseName + '.sys.index_columns ic 333 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 334 | WHERE i.object_id = ic.object_id 335 | AND i.index_id = ic.index_id 336 | AND is_included_column = 0 337 | ORDER BY key_ordinal ASC 338 | FOR XML PATH('''')) 339 | + ''|'' + COALESCE((SELECT QUOTENAME(CAST(ic.column_id AS VARCHAR(10)) 340 | + CASE WHEN ic.is_descending_key = 0 THEN ''+'' ELSE ''-'' END, ''('') 341 | FROM ' + @DatabaseName + '.sys.index_columns ic 342 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 343 | LEFT OUTER JOIN ' + @DatabaseName + '.sys.index_columns ic_key ON c.object_id = ic_key.object_id 344 | AND c.column_id = ic_key.column_id 345 | AND i.index_id = ic_key.index_id 346 | AND ic_key.is_included_column = 0 347 | WHERE i.object_id = ic.object_id 348 | AND ic.index_id = 1 349 | AND ic.is_included_column = 0 350 | AND ic_key.index_id IS NULL 351 | ORDER BY ic.key_ordinal ASC 352 | FOR XML PATH('''')),'''') 353 | + CASE WHEN i.is_unique = 1 THEN ''U'' ELSE '''' END 354 | , included_column_ids = CASE WHEN i.index_id IN (0,1) THEN ''ALL-COLUMNS'' ELSE 355 | COALESCE((SELECT QUOTENAME(ic.column_id,''('') 356 | FROM ' + @DatabaseName + '.sys.index_columns ic 357 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id 358 | LEFT OUTER JOIN ' + @DatabaseName 359 | + '.sys.index_columns ic_key ON c.object_id = ic_key.object_id AND c.column_id = ic_key.column_id AND ic_key.index_id = 1 360 | WHERE i.object_id = ic.object_id 361 | AND i.index_id = ic.index_id 362 | AND ic.is_included_column = 1 363 | AND ic_key.index_id IS NULL 364 | ORDER BY ic.key_ordinal ASC 365 | FOR XML PATH('''')), SPACE(0)) END 366 | , distinct_indexed_columns_ids = (SELECT QUOTENAME(ic.column_id) 367 | FROM ' + @DatabaseName + '.sys.index_columns ic 368 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON c.object_id = ic.object_id AND c.column_id = ic.column_id 369 | WHERE ic.object_id = i.object_id 370 | AND (ic.index_id = i.index_id OR ic.index_id = 1) 371 | AND is_included_column = 0 372 | GROUP BY ic.column_id 373 | ORDER BY ic.column_id 374 | FOR XML PATH('''')) 375 | FROM ' + @DatabaseName + '.sys.tables t 376 | INNER JOIN ' + @DatabaseName + '.sys.schemas s ON t.schema_id = s.schema_id 377 | INNER JOIN ' + @DatabaseName + '.sys.indexes i ON t.object_id = i.object_id 378 | INNER JOIN ' + @DatabaseName + '.sys.data_spaces ds ON i.data_space_id = ds.data_space_id 379 | CROSS APPLY (SELECT p.object_id , 380 | p.index_id , 381 | CASE WHEN @ConsolidatePartitionStats = 0 THEN p.partition_number ELSE -1 END AS partition_number, 382 | COUNT(*) AS partition_count, 383 | SUM(ps.row_count) AS row_count, 384 | CASE 1.*SUM(p.data_compression)/NULLIF(COUNT(*),0) 385 | WHEN 0 THEN ''NONE'' 386 | WHEN 1 THEN ''ROW'' 387 | WHEN 2 THEN ''PAGE'' 388 | ELSE ''MIXED'' END AS data_compression_desc, 389 | SUM(ps.in_row_data_page_count) AS in_row_data_page_count, 390 | SUM(ps.in_row_used_page_count) AS in_row_used_page_count , 391 | SUM(ps.in_row_reserved_page_count) AS in_row_reserved_page_count, 392 | SUM(ps.lob_used_page_count) AS lob_used_page_count, 393 | SUM(ps.lob_reserved_page_count) AS lob_reserved_page_count, 394 | SUM(ps.row_overflow_used_page_count) AS row_overflow_used_page_count, 395 | SUM(ps.row_overflow_reserved_page_count) AS row_overflow_reserved_page_count, 396 | SUM(ps.used_page_count) AS used_page_count , 397 | SUM(ps.reserved_page_count) AS reserved_page_count 398 | FROM ' + @DatabaseName + '.sys.partitions p 399 | INNER JOIN ' + @DatabaseName 400 | + '.sys.dm_db_partition_stats ps ON ps.object_id = p.object_id AND ps.index_id = p.index_id AND ps.partition_id = p.partition_id 401 | WHERE i.object_id = p.object_id AND i.index_id = p.index_id 402 | GROUP BY p.object_id, p.index_id, CASE WHEN @ConsolidatePartitionStats = 0 THEN p.partition_number ELSE -1 END) x 403 | '; 404 | 405 | IF @ObjectID IS NOT NULL 406 | SET @SQL = @SQL + CHAR(13) + 'WHERE t.object_id = @ObjectID '; 407 | 408 | BEGIN TRY 409 | IF @ConsolidatePartitionStats = 1 410 | BEGIN 411 | RAISERROR('Strate''s Warning: Page count totals are a summary of all partitions. This behaviour is controlled by the @ConsolidatePartitionStats parameter',10,1) WITH NOWAIT; 412 | PRINT ''; 413 | END; 414 | 415 | INSERT INTO [#IndexMeta] 416 | EXEC [sys].[sp_executesql] @SQL, N'@DB_ID INT, @ObjectID INT, @ConsolidatePartitionStats INT', @DB_ID = @DB_ID, @ObjectID = @ObjectID, 417 | @ConsolidatePartitionStats = @ConsolidatePartitionStats; 418 | 419 | IF @ProcessingMessages = 1 420 | PRINT 'Processing #IndexMeta... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 421 | END TRY 422 | BEGIN CATCH 423 | SELECT @ERROR_MESSAGE = 'Populate #IndexMeta (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 424 | @ERROR_SEVERITY = ERROR_SEVERITY() , 425 | @ERROR_STATE = ERROR_STATE(); 426 | 427 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 428 | END CATCH; 429 | END; 430 | 431 | BEGIN 432 | SET @PROCESSING_START = GETDATE(); 433 | 434 | IF @ConsolidatePartitionStats = 1 435 | BEGIN 436 | RAISERROR('Strate''s Warning: Index operational stats (locking, blocking, latching, etc.) are summarized from all partitions. This behaviour is controlled by the @ConsolidatePartitionStats parameter',10,1) WITH NOWAIT; 437 | PRINT ''; 438 | END; 439 | ELSE 440 | BEGIN 441 | RAISERROR('Strate''s Warning: Index usage stats are summarized at the index level, per partition data is not available.',10,1) WITH NOWAIT; 442 | PRINT ''; 443 | END; 444 | 445 | SELECT IDENTITY( INT,1,1 ) AS [row_id] , 446 | CAST('' AS VARCHAR(10)) AS [index_action] , 447 | CAST('' AS VARCHAR(50)) AS [index_pros] , 448 | CAST('' AS VARCHAR(50)) AS [index_cons] , 449 | [tm].[database_id] , 450 | [im].[filegroup_name] , 451 | [im].[compression_type] , 452 | [tm].[schema_name] , 453 | [im].[object_id] , 454 | [tm].[table_name] , 455 | [tm].[object_name] , 456 | [im].[index_id] , 457 | [im].[index_name] , 458 | [im].[is_primary_key] , 459 | [im].[is_unique] , 460 | [im].[is_disabled] , 461 | [tm].[has_unique] , 462 | [im].[type_desc] , 463 | [im].[partition_count] , 464 | [im].[partition_number] , 465 | [im].[fill_factor] , 466 | [im].[is_padded] , 467 | [im].[reserved_page_count] , 468 | [im].[used_page_count] , 469 | [im].[index_row_count] / NULLIF([im].[used_page_count], 0) AS [average_rows_per_page] , 470 | [im].[size_in_mb] , 471 | COALESCE([mb].[buffered_page_count], 0) AS [buffered_page_count] , 472 | COALESCE([mb].[buffered_mb], 0) AS [buffered_mb] , 473 | CAST(0 AS INT) AS [table_buffered_mb] , 474 | COALESCE(CAST(100. * [mb].[buffered_page_count] / NULLIF([im].[reserved_page_count], 0) AS DECIMAL(12, 2)), 0) AS [buffered_percent] , 475 | [tm].[table_row_count] , 476 | [im].[index_row_count] , 477 | ROW_NUMBER() OVER (PARTITION BY [im].[object_id] ORDER BY [im].[is_primary_key] DESC, [ius].[user_seeks] + [ius].[user_scans] 478 | + [ius].[user_lookups] DESC) AS [index_rank] , 479 | CAST(0 AS INT) AS [full_index_rank] , 480 | [ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups] AS [user_total] , 481 | COALESCE(CAST(100 * ([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups]) 482 | / (NULLIF(SUM([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups]) OVER (PARTITION BY [im].[object_id]), 0) * 1.) AS DECIMAL(6, 483 | 2)), 0) AS [user_total_pct] , 484 | CAST(0 AS DECIMAL(6, 2)) AS [estimated_user_total_pct] , 485 | CAST(0 AS FLOAT) AS [missing_index_impact] -- Dick Baker 201303 (INT range not big enough and is f.p. anyway) 486 | , 487 | [ius].[user_seeks] , 488 | [ius].[user_scans] , 489 | [ius].[user_lookups] , 490 | [ius].[user_updates] , 491 | (1. * ([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups])) / NULLIF([ius].[user_updates], 0) AS [read_to_update_ratio] , 492 | ([ios].[leaf_insert_count] + [ios].[leaf_delete_count] + [ios].[leaf_update_count] + [ios].[leaf_ghost_count]) / NULLIF([ius].[user_updates], 493 | 0) AS [average_rows_per_update] , 494 | CASE WHEN [ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups] >= [ius].[user_updates] 495 | THEN CEILING(1. * ([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups]) / COALESCE(NULLIF([ius].[user_seeks], 0), 1)) 496 | ELSE 0 497 | END AS [read_to_update] , 498 | CASE WHEN [ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups] <= [ius].[user_updates] 499 | THEN CEILING(1. * ([ius].[user_updates]) / COALESCE(NULLIF([ius].[user_seeks] + [ius].[user_scans] + [ius].[user_lookups], 0), 1)) 500 | ELSE 0 501 | END AS [update_to_read] , 502 | [ios].[row_lock_count] , 503 | [ios].[row_lock_wait_count] , 504 | [ios].[row_lock_wait_in_ms] , 505 | CAST(100.0 * [ios].[row_lock_wait_count] / NULLIF([ios].[row_lock_count], 0) AS DECIMAL(12, 2)) AS [row_block_pct] , 506 | CAST(1. * [ios].[row_lock_wait_in_ms] / NULLIF([ios].[row_lock_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_row_lock_waits_ms] , 507 | [ios].[page_latch_wait_count] , 508 | CAST(1. * [ios].[page_latch_wait_in_ms] / NULLIF([ios].[page_io_latch_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_page_latch_wait_ms] , 509 | [ios].[page_io_latch_wait_count] , 510 | CAST(1. * [ios].[page_io_latch_wait_in_ms] / NULLIF([ios].[page_io_latch_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_page_io_latch_wait_ms] , 511 | [ios].[tree_page_latch_wait_count] AS [tree_page_latch_wait_count] , 512 | CAST(1. * [ios].[tree_page_latch_wait_in_ms] / NULLIF([ios].[tree_page_io_latch_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_tree_page_latch_wait_ms] , 513 | [ios].[tree_page_io_latch_wait_count] , 514 | CAST(1. * [ios].[tree_page_io_latch_wait_in_ms] / NULLIF([ios].[tree_page_io_latch_wait_count], 0) AS DECIMAL(12, 2)) AS [avg_tree_page_io_latch_wait_ms] , 515 | [ios].[range_scan_count] + [ios].[singleton_lookup_count] AS [read_operations] , 516 | [ios].[leaf_insert_count] + [ios].[leaf_update_count] + [ios].[leaf_delete_count] + [ios].[leaf_ghost_count] AS [leaf_writes] , 517 | [ios].[leaf_allocation_count] AS [leaf_page_allocations] , 518 | [ios].[leaf_page_merge_count] AS [leaf_page_merges] , 519 | [ios].[nonleaf_insert_count] + [ios].[nonleaf_update_count] + [ios].[nonleaf_delete_count] AS [nonleaf_writes] , 520 | [ios].[nonleaf_allocation_count] AS [nonleaf_page_allocations] , 521 | [ios].[nonleaf_page_merge_count] AS [nonleaf_page_merges] , 522 | [ios].[page_compression_attempt_count] , 523 | [ios].[page_compression_success_count] , 524 | CAST(100. * [ios].[page_compression_success_count] / NULLIF([ios].[page_compression_attempt_count], 0) AS DECIMAL(6, 2)) AS [page_compression_success_rate] , 525 | [tm].[table_column_count] , 526 | [im].[indexed_columns] , 527 | [im].[indexed_column_count] , 528 | [im].[included_columns] , 529 | [im].[included_column_count] , 530 | [im].[filter_definition] , 531 | [im].[key_columns] , 532 | [im].[data_columns] , 533 | [im].[indexed_columns_ids] , 534 | [im].[included_column_ids] , 535 | [im].[distinct_indexed_columns_ids] , 536 | CAST('' AS VARCHAR(MAX)) AS [duplicate_indexes] , 537 | CAST('' AS SMALLINT) AS [first_dup_index_id] , 538 | CAST('' AS VARCHAR(MAX)) AS [overlapping_indexes] , 539 | CAST('' AS VARCHAR(MAX)) AS [sibling_indexes] , 540 | CAST('' AS VARCHAR(MAX)) AS [related_foreign_keys] , 541 | CAST('' AS XML) AS [related_foreign_keys_xml] 542 | INTO [#IndexStatistics] 543 | FROM [#TableMeta] [tm] 544 | INNER JOIN [#IndexMeta] [im] ON [im].[database_id] = [tm].[database_id] 545 | AND [im].[object_id] = [tm].[object_id] 546 | LEFT OUTER JOIN [sys].[dm_db_index_usage_stats] [ius] ON [im].[object_id] = [ius].[object_id] 547 | AND [im].[index_id] = [ius].[index_id] 548 | AND [im].[database_id] = [ius].[database_id] 549 | LEFT OUTER JOIN [#MemoryBuffer] [mb] ON [im].[object_id] = [mb].[object_id] 550 | AND [im].[index_id] = [mb].[index_id] 551 | AND [im].[partition_number] = [mb].[partition_number] 552 | LEFT OUTER JOIN (SELECT [database_id] , 553 | [object_id] , 554 | [index_id] , 555 | CASE WHEN @ConsolidatePartitionStats = 0 THEN [partition_number] 556 | ELSE -1 557 | END AS [partition_number] , 558 | SUM([leaf_insert_count]) AS [leaf_insert_count] , 559 | SUM([leaf_delete_count]) AS [leaf_delete_count] , 560 | SUM([leaf_update_count]) AS [leaf_update_count] , 561 | SUM([leaf_ghost_count]) AS [leaf_ghost_count] , 562 | SUM([nonleaf_insert_count]) AS [nonleaf_insert_count] , 563 | SUM([nonleaf_delete_count]) AS [nonleaf_delete_count] , 564 | SUM([nonleaf_update_count]) AS [nonleaf_update_count] , 565 | SUM([leaf_allocation_count]) AS [leaf_allocation_count] , 566 | SUM([nonleaf_allocation_count]) AS [nonleaf_allocation_count] , 567 | SUM([leaf_page_merge_count]) AS [leaf_page_merge_count] , 568 | SUM([nonleaf_page_merge_count]) AS [nonleaf_page_merge_count] , 569 | SUM([range_scan_count]) AS [range_scan_count] , 570 | SUM([singleton_lookup_count]) AS [singleton_lookup_count] , 571 | SUM([forwarded_fetch_count]) AS [forwarded_fetch_count] , 572 | SUM([lob_fetch_in_pages]) AS [lob_fetch_in_pages] , 573 | SUM([lob_fetch_in_bytes]) AS [lob_fetch_in_bytes] , 574 | SUM([lob_orphan_create_count]) AS [lob_orphan_create_count] , 575 | SUM([lob_orphan_insert_count]) AS [lob_orphan_insert_count] , 576 | SUM([row_overflow_fetch_in_pages]) AS [row_overflow_fetch_in_pages] , 577 | SUM([row_overflow_fetch_in_bytes]) AS [row_overflow_fetch_in_bytes] , 578 | SUM([column_value_push_off_row_count]) AS [column_value_push_off_row_count] , 579 | SUM([column_value_pull_in_row_count]) AS [column_value_pull_in_row_count] , 580 | SUM([row_lock_count]) AS [row_lock_count] , 581 | SUM([row_lock_wait_count]) AS [row_lock_wait_count] , 582 | SUM([row_lock_wait_in_ms]) AS [row_lock_wait_in_ms] , 583 | SUM([page_lock_count]) AS [page_lock_count] , 584 | SUM([page_lock_wait_count]) AS [page_lock_wait_count] , 585 | SUM([page_lock_wait_in_ms]) AS [page_lock_wait_in_ms] , 586 | SUM([index_lock_promotion_attempt_count]) AS [index_lock_promotion_attempt_count] , 587 | SUM([index_lock_promotion_count]) AS [index_lock_promotion_count] , 588 | SUM([page_latch_wait_count]) AS [page_latch_wait_count] , 589 | SUM([page_latch_wait_in_ms]) AS [page_latch_wait_in_ms] , 590 | SUM([page_io_latch_wait_count]) AS [page_io_latch_wait_count] , 591 | SUM([page_io_latch_wait_in_ms]) AS [page_io_latch_wait_in_ms] , 592 | SUM([tree_page_latch_wait_count]) AS [tree_page_latch_wait_count] , 593 | SUM([tree_page_latch_wait_in_ms]) AS [tree_page_latch_wait_in_ms] , 594 | SUM([tree_page_io_latch_wait_count]) AS [tree_page_io_latch_wait_count] , 595 | SUM([tree_page_io_latch_wait_in_ms]) AS [tree_page_io_latch_wait_in_ms] , 596 | SUM([page_compression_attempt_count]) AS [page_compression_attempt_count] , 597 | SUM([page_compression_success_count]) AS [page_compression_success_count] 598 | FROM [sys].[dm_db_index_operational_stats](DB_ID(), NULL, NULL, NULL) 599 | GROUP BY [database_id] , 600 | [object_id] , 601 | [index_id] , 602 | CASE WHEN @ConsolidatePartitionStats = 0 THEN [partition_number] 603 | ELSE -1 604 | END 605 | ) [ios] ON [im].[object_id] = [ios].[object_id] 606 | AND [im].[index_id] = [ios].[index_id] 607 | AND [im].[partition_number] = [ios].[partition_number]; 608 | 609 | IF @ProcessingMessages = 1 610 | PRINT 'Processing #IndexStatistics... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 611 | END; 612 | 613 | -- Collect missing index information. 614 | IF @IncludeMissingIndexes = 1 615 | BEGIN 616 | SET @PROCESSING_START = GETDATE(); 617 | 618 | INSERT INTO [#IndexStatistics] 619 | ([index_action] , 620 | [index_pros] , 621 | [index_cons] , 622 | [database_id] , 623 | [has_unique] , 624 | [is_primary_key] , 625 | [is_disabled] , 626 | [user_total_pct] , 627 | [table_column_count] , 628 | [filegroup_name] , 629 | [schema_name] , 630 | [object_id] , 631 | [table_name] , 632 | [object_name] , 633 | [index_name] , 634 | [type_desc] , 635 | [missing_index_impact] , 636 | [index_rank] , 637 | [user_total] , 638 | [user_seeks] , 639 | [user_scans] , 640 | [user_lookups] , 641 | [indexed_columns] , 642 | [included_columns] , 643 | [compression_type] , 644 | [indexed_column_count] , 645 | [included_column_count] 646 | ) 647 | SELECT '' AS [index_action] , 648 | '' AS [index_pros] , 649 | '' AS [index_cons] , 650 | [tm].[database_id] , 651 | [tm].[has_unique] , 652 | 0 [is_primary_key] , 653 | 0 [is_disabled] , 654 | 0 [user_total_pct] , 655 | [tm].[table_column_count] , 656 | '--TBD--' AS [filegroup_name] , 657 | [tm].[schema_name] , 658 | [mid].[object_id] , 659 | [tm].[table_name] , 660 | [tm].[object_name] , 661 | '--MISSING INDEX--' AS [index_name] , 662 | '--NONCLUSTERED--' AS [type_desc] , 663 | ([migs].[user_seeks] + [migs].[user_scans]) * [migs].[avg_user_impact] AS [impact] , 664 | 0 AS [index_rank] , 665 | [migs].[user_seeks] + [migs].[user_scans] AS [user_total] , 666 | [migs].[user_seeks] , 667 | [migs].[user_scans] , 668 | 0 AS [user_lookups] , 669 | COALESCE([mid].[equality_columns] + CASE WHEN [mid].[inequality_columns] IS NOT NULL THEN ', ' 670 | ELSE SPACE(0) 671 | END, SPACE(0)) + COALESCE([mid].[inequality_columns], SPACE(0)) AS [indexed_columns] , 672 | [mid].[included_columns] , 673 | '--TBD--' , 674 | [mic].[indexed_column_count] , 675 | [mic].[included_column_count] 676 | FROM [#TableMeta] [tm] 677 | INNER JOIN [sys].[dm_db_missing_index_details] [mid] ON [mid].[database_id] = [tm].[database_id] 678 | AND [mid].[object_id] = [tm].[object_id] 679 | INNER JOIN [sys].[dm_db_missing_index_groups] [mig] ON [mid].[index_handle] = [mig].[index_handle] 680 | INNER JOIN [sys].[dm_db_missing_index_group_stats] [migs] ON [mig].[index_group_handle] = [migs].[group_handle] 681 | CROSS APPLY (SELECT SUM(CASE WHEN [column_usage] != 'INCLUDE' THEN 1 682 | ELSE 0 683 | END) AS [indexed_column_count] , 684 | SUM(CASE WHEN [column_usage] = 'INCLUDE' THEN 1 685 | ELSE 0 686 | END) AS [included_column_count] 687 | FROM [sys].[dm_db_missing_index_columns]([mid].[index_handle]) 688 | ) [mic]; 689 | IF @ProcessingMessages = 1 690 | PRINT 'Add missing indexes to #IndexStatistics... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 691 | END; 692 | 693 | -- Collect foreign key information. 694 | BEGIN 695 | SET @PROCESSING_START = GETDATE(); 696 | 697 | CREATE TABLE [#ForeignKeys] 698 | ( 699 | [foreign_key_name] NVARCHAR(256) , 700 | [object_id] INT , 701 | [fk_columns] NVARCHAR(MAX) , 702 | [fk_columns_ids] NVARCHAR(1024) , 703 | [related_object_id] INT , 704 | [distinct_column_ids] NVARCHAR(1024) , 705 | [indexed_column_count] INT 706 | ); 707 | 708 | SET @SQL = N'SELECT fk.name + ''|CHILD'' AS foreign_key_name 709 | ,fkc.parent_object_id AS object_id 710 | ,STUFF((SELECT '', '' + QUOTENAME(c.name) 711 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 712 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ifkc.parent_object_id = c.object_id AND ifkc.parent_column_id = c.column_id 713 | WHERE fk.object_id = ifkc.constraint_object_id 714 | ORDER BY ifkc.constraint_column_id 715 | FOR XML PATH('''')), 1, 2, '''') AS fk_columns 716 | ,(SELECT QUOTENAME(CAST(ifkc.parent_column_id AS VARCHAR(10))+''+'',''('') 717 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 718 | WHERE fk.object_id = ifkc.constraint_object_id 719 | ORDER BY ifkc.constraint_column_id 720 | FOR XML PATH('''')) AS fk_columns_compare 721 | ,fkc.referenced_object_id AS related_object_id 722 | 723 | ,(SELECT QUOTENAME(CAST(ifkc.parent_column_id AS VARCHAR(10))) 724 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 725 | WHERE fk.object_id = ifkc.constraint_object_id 726 | ORDER BY ifkc.parent_column_id 727 | FOR XML PATH('''')) AS distinct_column_ids 728 | ,(SELECT COUNT(*) 729 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 730 | WHERE fk.object_id = ifkc.constraint_object_id) AS indexed_column_count 731 | 732 | FROM #TableMeta tm 733 | INNER JOIN ' + @DatabaseName + '.sys.foreign_keys fk ON tm.object_id = fk.parent_object_id 734 | INNER JOIN ' + @DatabaseName + '.sys.foreign_key_columns fkc ON fk.object_id = fkc.constraint_object_id 735 | WHERE fkc.constraint_column_id = 1 736 | AND (@ObjectID IS NULL OR (fk.parent_object_id = @ObjectID OR fk.referenced_object_id = @ObjectID)) 737 | UNION ALL 738 | SELECT fk.name + ''|PARENT'' as foreign_key_name 739 | ,fkc.referenced_object_id AS object_id 740 | ,STUFF((SELECT '', '' + QUOTENAME(c.name) 741 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 742 | INNER JOIN ' + @DatabaseName + '.sys.columns c ON ifkc.referenced_object_id = c.object_id AND ifkc.referenced_column_id = c.column_id 743 | WHERE fk.object_id = ifkc.constraint_object_id 744 | ORDER BY ifkc.constraint_column_id 745 | FOR XML PATH('''')), 1, 2, '''') AS fk_columns 746 | ,(SELECT QUOTENAME(CAST(ifkc.referenced_column_id AS VARCHAR(10))+''+'',''('') 747 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 748 | WHERE fk.object_id = ifkc.constraint_object_id 749 | ORDER BY ifkc.constraint_column_id 750 | FOR XML PATH('''')) AS fk_columns_compare 751 | ,fkc.parent_object_id AS related_object_id 752 | ,(SELECT QUOTENAME(CAST(ifkc.referenced_column_id AS VARCHAR(10))) 753 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 754 | WHERE fk.object_id = ifkc.constraint_object_id 755 | ORDER BY ifkc.parent_column_id 756 | FOR XML PATH('''')) AS fk_columns_compare 757 | ,(SELECT COUNT(*) 758 | FROM ' + @DatabaseName + '.sys.foreign_key_columns ifkc 759 | WHERE fk.object_id = ifkc.constraint_object_id) AS indexed_column_count 760 | FROM #TableMeta tm 761 | INNER JOIN ' + @DatabaseName + '.sys.foreign_keys fk ON tm.object_id = fk.referenced_object_id 762 | INNER JOIN ' + @DatabaseName + '.sys.foreign_key_columns fkc ON fk.object_id = fkc.constraint_object_id 763 | WHERE fkc.constraint_column_id = 1 764 | AND (@ObjectID IS NULL OR (fk.parent_object_id = @ObjectID OR fk.referenced_object_id = @ObjectID)) 765 | '; 766 | 767 | BEGIN TRY 768 | INSERT INTO [#ForeignKeys] 769 | ([foreign_key_name] , 770 | [object_id] , 771 | [fk_columns] , 772 | [fk_columns_ids] , 773 | [related_object_id] , 774 | [distinct_column_ids] , 775 | [indexed_column_count] 776 | ) 777 | EXEC [sys].[sp_executesql] @SQL, N'@DB_ID INT, @ObjectID INT', @DB_ID = @DB_ID, @ObjectID = @ObjectID; 778 | END TRY 779 | BEGIN CATCH 780 | SELECT @ERROR_MESSAGE = 'Populate #ForeignKeys (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 781 | @ERROR_SEVERITY = ERROR_SEVERITY() , 782 | @ERROR_STATE = ERROR_STATE(); 783 | 784 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 785 | END CATCH; 786 | 787 | IF @ProcessingMessages = 1 788 | PRINT 'Processing #ForeignKeys... ' + CONVERT(VARCHAR, DATEDIFF(MILLISECOND, @PROCESSING_START, GETDATE())) + ' ms'; 789 | END; 790 | 791 | -- Determine duplicate, overlapping, and foreign key index information 792 | UPDATE [i] 793 | SET [i].[duplicate_indexes] = STUFF((SELECT ', ' + [iibl].[index_name] AS [data()] 794 | FROM [#IndexStatistics] [iibl] 795 | WHERE [i].[object_id] = [iibl].[object_id] 796 | AND [i].[is_primary_key] = [iibl].[is_primary_key] 797 | AND [i].[is_unique] = [iibl].[is_unique] 798 | AND ISNULL([i].[filter_definition], '') = ISNULL([iibl].[filter_definition], '') 799 | AND [i].[index_id] <> [iibl].[index_id] 800 | AND REPLACE([i].[indexed_columns_ids], '|', '') = REPLACE([iibl].[indexed_columns_ids], '|', '') 801 | AND [i].[included_column_ids] = [iibl].[included_column_ids] 802 | FOR 803 | XML PATH('') 804 | ), 1, 2, '') , 805 | [i].[first_dup_index_id] = (SELECT MIN([iibl].[index_id]) 806 | FROM [#IndexStatistics] [iibl] 807 | WHERE [i].[object_id] = [iibl].[object_id] 808 | AND [i].[is_primary_key] = [iibl].[is_primary_key] 809 | AND [i].[is_unique] = [iibl].[is_unique] 810 | AND ISNULL([i].[filter_definition], '') = ISNULL([iibl].[filter_definition], '') 811 | AND [i].[index_id] > [iibl].[index_id] 812 | AND REPLACE([i].[indexed_columns_ids], '|', '') = REPLACE([iibl].[indexed_columns_ids], '|', '') 813 | AND [i].[included_column_ids] = [iibl].[included_column_ids] 814 | ) , 815 | [i].[overlapping_indexes] = STUFF((SELECT ', ' + [iibl].[index_name] AS [data()] 816 | FROM [#IndexStatistics] [iibl] 817 | WHERE [i].[object_id] = [iibl].[object_id] 818 | AND ISNULL([i].[filter_definition], '') = ISNULL([iibl].[filter_definition], '') 819 | AND [i].[index_id] <> [iibl].[index_id] 820 | AND LEFT([iibl].[indexed_columns_ids], CHARINDEX('|', [iibl].[indexed_columns_ids], 1) - 1) LIKE LEFT([i].[indexed_columns_ids], 821 | CHARINDEX('|', 822 | [i].[indexed_columns_ids], 823 | 1) - 1) + '%' 824 | FOR 825 | XML PATH('') 826 | ), 1, 2, '') , 827 | [i].[sibling_indexes] = STUFF((SELECT ', ' + [iibl].[index_name] AS [data()] 828 | FROM [#IndexStatistics] [iibl] 829 | WHERE [i].[object_id] = [iibl].[object_id] 830 | AND [i].[index_id] <> [iibl].[index_id] 831 | AND [i].[distinct_indexed_columns_ids] = [iibl].[distinct_indexed_columns_ids] 832 | FOR 833 | XML PATH('') 834 | ), 1, 2, '') , 835 | [i].[related_foreign_keys] = STUFF((SELECT ', ' + [ifk].[foreign_key_name] AS [data()] 836 | FROM [#ForeignKeys] [ifk] 837 | WHERE [ifk].[object_id] = [i].[object_id] 838 | AND [i].[indexed_columns_ids] LIKE [ifk].[fk_columns_ids] + '%' 839 | FOR 840 | XML PATH('') 841 | ), 1, 2, '') , 842 | [i].[related_foreign_keys_xml] = CAST((SELECT [fk].[foreign_key_name] 843 | FROM [#ForeignKeys] [fk] 844 | WHERE [fk].[object_id] = [i].[object_id] 845 | AND [i].[indexed_columns_ids] LIKE [fk].[fk_columns_ids] + '%' 846 | FOR 847 | XML AUTO 848 | ) AS XML) 849 | FROM [#IndexStatistics] [i]; 850 | 851 | IF @IncludeMissingFKIndexes = 1 852 | BEGIN 853 | INSERT INTO [#IndexStatistics] 854 | ([database_id] , 855 | [filegroup_name] , 856 | [schema_name] , 857 | [object_id] , 858 | [table_name] , 859 | [object_name] , 860 | [index_name] , 861 | [type_desc] , 862 | [has_unique] , 863 | [is_primary_key] , 864 | [is_disabled] , 865 | [user_total_pct] , 866 | [table_column_count] , 867 | [index_rank] , 868 | [indexed_columns] , 869 | [indexed_column_count] , 870 | [indexed_columns_ids] , 871 | [distinct_indexed_columns_ids] , 872 | [included_column_count] , 873 | [key_columns] , 874 | [related_foreign_keys] , 875 | [compression_type] 876 | ) 877 | SELECT [tm].[database_id] , 878 | '--TBD--' AS [filegroup_name] , 879 | OBJECT_SCHEMA_NAME([fk].[object_id]) AS [schema_name] , 880 | [fk].[object_id] , 881 | OBJECT_NAME([fk].[object_id]) AS [table_name] , 882 | [tm].[object_name] , 883 | '--MISSING FOREIGN KEY INDEX--' AS [index_name] , 884 | 'NONCLUSTERED' AS [type_desc] , 885 | [tm].[has_unique] , 886 | 0 AS [is_primary_key] , 887 | 0 AS [is_disabled] , 888 | 0 AS [user_total_pct] , 889 | [tm].[table_column_count] , 890 | 9999 AS [index_rank] , 891 | [fk].[fk_columns] , 892 | [fk].[indexed_column_count] , 893 | [fk].[fk_columns_ids] , 894 | [fk].[distinct_column_ids] , 895 | 0 AS [included_column_count] , 896 | [fk].[fk_columns] , 897 | [fk].[foreign_key_name] , 898 | '--TBD--' 899 | FROM [#TableMeta] AS [tm] 900 | INNER JOIN [#ForeignKeys] [fk] ON [fk].[object_id] = [tm].[object_id] 901 | LEFT OUTER JOIN [#IndexStatistics] [i] ON [fk].[object_id] = [i].[object_id] 902 | AND [i].[indexed_columns_ids] LIKE [fk].[fk_columns_ids] + '%' 903 | WHERE [i].[index_name] IS NULL; 904 | END; 905 | 906 | --================================================================================================ 907 | -- Calculate estimated user total for each index. 908 | --================================================================================================ 909 | WITH [StatAggregation1] 910 | AS (SELECT [row_id] , 911 | [object_id] , 912 | [user_seeks] , 913 | [user_scans] , 914 | [user_lookups] , 915 | [user_total_pct] , 916 | CONVERT(INT, SUM(CASE WHEN [index_id] IS NULL THEN [user_seeks] 917 | END) OVER (PARTITION BY [object_id]) * 1. * [user_scans] 918 | / NULLIF(SUM(CASE WHEN [index_id] IS NOT NULL THEN [user_scans] 919 | END) OVER (PARTITION BY [object_id]), 0)) AS [weighted_scans] , 920 | SUM([buffered_mb]) OVER (PARTITION BY [schema_name], [table_name]) AS [table_buffered_mb] 921 | FROM [#IndexStatistics] 922 | ), 923 | [StatAggregation2] 924 | AS (SELECT * , 925 | CONVERT(DECIMAL(6, 2), 100. * ([StatAggregation1].[user_seeks] + [StatAggregation1].[user_scans] 926 | - [StatAggregation1].[weighted_scans] + [StatAggregation1].[user_lookups]) 927 | / SUM([StatAggregation1].[user_seeks] + [StatAggregation1].[user_scans] - [StatAggregation1].[weighted_scans] 928 | + [StatAggregation1].[user_lookups]) OVER (PARTITION BY [StatAggregation1].[object_id])) AS [estimated_user_total_pct] 929 | FROM [StatAggregation1] 930 | ), 931 | [StatAggregation3] 932 | AS (SELECT * , 933 | ROW_NUMBER() OVER (PARTITION BY [StatAggregation2].[object_id] ORDER BY [StatAggregation2].[estimated_user_total_pct] DESC, [StatAggregation2].[user_total_pct] DESC) AS [full_index_rank] 934 | FROM [StatAggregation2] 935 | ) 936 | UPDATE [ibl] 937 | SET [ibl].[estimated_user_total_pct] = COALESCE([a].[estimated_user_total_pct], 0) , 938 | [ibl].[table_buffered_mb] = [a].[table_buffered_mb] , 939 | [ibl].[full_index_rank] = [a].[full_index_rank] 940 | FROM [#IndexStatistics] [ibl] 941 | INNER JOIN [StatAggregation3] [a] ON [ibl].[row_id] = [a].[row_id]; 942 | 943 | --================================================================================================ 944 | -- Update Pro/Con statuses 945 | --================================================================================================ 946 | UPDATE [#IndexStatistics] 947 | SET [index_pros] = COALESCE(STUFF(CASE WHEN [index_name] = '--MISSING INDEX--' 948 | AND [related_foreign_keys] IS NOT NULL THEN ', MIFK' 949 | WHEN [related_foreign_keys] IS NOT NULL THEN ', FK' 950 | ELSE '' 951 | END + CASE WHEN [is_unique] = 1 THEN ', UQ' 952 | ELSE '' 953 | END + CASE WHEN [full_index_rank] <= 5 954 | AND [index_name] = '--MISSING INDEX--' THEN ', TM5' 955 | ELSE '' 956 | END + COALESCE(', ' + CASE WHEN [read_to_update] BETWEEN 1 AND 9 THEN '$' 957 | WHEN [read_to_update] BETWEEN 10 AND 99 THEN '$$' 958 | WHEN [read_to_update] BETWEEN 100 AND 999 THEN '$$$' 959 | WHEN [read_to_update] > 999 THEN '$$$+' 960 | END, ''), 1, 2, ''), '') , 961 | [index_cons] = COALESCE(STUFF(CASE WHEN [index_id] = 0 THEN ', HP' 962 | ELSE '' 963 | END + CASE WHEN [user_lookups] >= @MinLookupThreshold 964 | AND [user_lookups] > [user_seeks] + [user_scans] THEN ', LKUP' 965 | ELSE '' 966 | END + CASE WHEN NULLIF([user_scans], 0) >= @MinScanThreshold 967 | AND [user_seeks] / NULLIF([user_scans], 0) < @Scan2SeekRatio THEN ', SCN' 968 | ELSE '' 969 | END + CASE WHEN [duplicate_indexes] IS NOT NULL THEN ', DUP' 970 | ELSE '' 971 | END + CASE WHEN [overlapping_indexes] IS NOT NULL THEN ', OVLP' 972 | ELSE '' 973 | END + CASE WHEN [sibling_indexes] IS NOT NULL THEN ', SIB' 974 | ELSE '' 975 | END + COALESCE(', ' + CASE WHEN [update_to_read] BETWEEN 1 AND 9 THEN '$' 976 | WHEN [update_to_read] BETWEEN 10 AND 99 THEN '$$' 977 | WHEN [update_to_read] BETWEEN 100 AND 999 THEN '$$$' 978 | WHEN [update_to_read] > 999 THEN '$$$+' 979 | END, '') + COALESCE(', ' 980 | + CASE WHEN [index_id] <= 1 981 | OR [indexed_column_count] 982 | + [included_column_count] < 4 983 | THEN NULL 984 | WHEN 100. * ([indexed_column_count] 985 | + [included_column_count]) 986 | / [table_column_count] >= 90 987 | THEN 'C90%' 988 | WHEN 100. * ([indexed_column_count] 989 | + [included_column_count]) 990 | / [table_column_count] >= 50 991 | THEN 'C50%' 992 | WHEN 100. * ([indexed_column_count] 993 | + [included_column_count]) 994 | / [table_column_count] >= 25 995 | THEN 'C25%' 996 | END, '') 997 | + CASE WHEN [index_id] IS NOT NULL 998 | AND [user_total_pct] < 1 THEN ', U1%' 999 | ELSE '' 1000 | END + CASE WHEN @CheckCompression = 1 1001 | AND [compression_type] = 'NONE' THEN ', NOCMP' 1002 | ELSE '' 1003 | END + CASE WHEN [is_disabled] = 1 THEN ', DSB' 1004 | ELSE '' 1005 | END, 1, 2, ''), ''); 1006 | 1007 | --================================================================================================ 1008 | -- Update Index Action information 1009 | --================================================================================================ 1010 | WITH [IndexAction] 1011 | AS (SELECT [row_id] , 1012 | CASE WHEN [user_lookups] >= @MinLookupThreshold 1013 | AND [user_lookups] > [user_seeks] 1014 | AND [type_desc] IN ('CLUSTERED', 'HEAP', 'UNIQUE CLUSTERED') THEN 'REALIGN' 1015 | WHEN [user_total_pct] < 5. 1016 | AND [type_desc] IN ('CLUSTERED', 'HEAP', 'UNIQUE CLUSTERED') 1017 | AND SUM([user_seeks] + [user_scans] + [user_lookups]) OVER (PARTITION BY [object_id]) > 0 THEN 'REALIGN' 1018 | WHEN [is_disabled] = 1 THEN 'ENABLE' 1019 | WHEN [duplicate_indexes] IS NOT NULL 1020 | AND [first_dup_index_id] IS NOT NULL 1021 | AND [index_id] IS NOT NULL THEN 'NEG-DUP' 1022 | WHEN [type_desc] = '--MISSING FOREIGN KEY--' THEN 'CREATE' 1023 | WHEN [type_desc] = 'XML' THEN '---' 1024 | WHEN [is_unique] = 1 THEN '---' 1025 | WHEN [related_foreign_keys] IS NOT NULL THEN '---' 1026 | WHEN [type_desc] = '--NONCLUSTERED--' 1027 | AND ROW_NUMBER() OVER (PARTITION BY [table_name] ORDER BY [user_total] DESC) <= @MaxMissingIndexCount 1028 | AND [estimated_user_total_pct] > 1 THEN 'CREATE' 1029 | WHEN [type_desc] = '--NONCLUSTERED--' 1030 | AND [estimated_user_total_pct] > .1 THEN 'BLEND' 1031 | WHEN ROW_NUMBER() OVER (PARTITION BY [table_name] ORDER BY [user_total] DESC, [index_rank]) > 10 1032 | AND [index_id] IS NOT NULL THEN 'NEG-COUNT' 1033 | WHEN [index_id] NOT IN (0, 1) 1034 | AND [duplicate_indexes] IS NULL 1035 | AND [user_total] = 0 1036 | AND [index_id] IS NOT NULL THEN 'NEG-USAGE' 1037 | ELSE '---' 1038 | END AS [index_action] 1039 | FROM [#IndexStatistics] 1040 | ) 1041 | UPDATE [ibl] 1042 | SET [ibl].[index_action] = [ia].[index_action] 1043 | FROM [#IndexStatistics] [ibl] 1044 | INNER JOIN [IndexAction] [ia] ON [ibl].[row_id] = [ia].[row_id]; 1045 | 1046 | --================================================================================================ 1047 | -- Output results from query 1048 | --================================================================================================ 1049 | IF @Output = 'DUMP' 1050 | BEGIN 1051 | SELECT * 1052 | FROM [#IndexStatistics] 1053 | ORDER BY [table_buffered_mb] DESC , 1054 | [object_id] , 1055 | COALESCE([user_total], -1) DESC , 1056 | COALESCE([user_updates], -1) DESC , 1057 | COALESCE([index_id], 999); 1058 | END; 1059 | ELSE 1060 | IF @Output = 'DETAILED' 1061 | BEGIN 1062 | SELECT [index_action] , 1063 | [index_pros] , 1064 | [index_cons] , 1065 | [object_name] , 1066 | [index_name] , 1067 | [type_desc] , 1068 | [indexed_columns] , 1069 | [included_columns] , 1070 | [filter_definition] , 1071 | [is_primary_key] , 1072 | [is_unique] , 1073 | [is_disabled] , 1074 | [has_unique] , 1075 | [partition_number] , 1076 | [fill_factor] , 1077 | [is_padded] , 1078 | [size_in_mb] , 1079 | [buffered_mb] , 1080 | [table_buffered_mb] , 1081 | [buffered_percent] , 1082 | [index_row_count] , 1083 | [user_total_pct] , 1084 | [estimated_user_total_pct] , 1085 | [missing_index_impact] , 1086 | [user_total] , 1087 | [user_seeks] , 1088 | [user_scans] , 1089 | [user_lookups] , 1090 | [user_updates] , 1091 | [read_to_update_ratio] , 1092 | [read_to_update] , 1093 | [update_to_read] , 1094 | [row_lock_count] , 1095 | [row_lock_wait_count] , 1096 | [row_lock_wait_in_ms] , 1097 | [row_block_pct] , 1098 | [avg_row_lock_waits_ms] , 1099 | [page_latch_wait_count] , 1100 | [avg_page_latch_wait_ms] , 1101 | [page_io_latch_wait_count] , 1102 | [avg_page_io_latch_wait_ms] , 1103 | [tree_page_latch_wait_count] , 1104 | [avg_tree_page_latch_wait_ms] , 1105 | [tree_page_io_latch_wait_count] , 1106 | [avg_tree_page_io_latch_wait_ms] , 1107 | [read_operations] , 1108 | [leaf_writes] , 1109 | [leaf_page_allocations] , 1110 | [leaf_page_merges] , 1111 | [nonleaf_writes] , 1112 | [nonleaf_page_allocations] , 1113 | [nonleaf_page_merges] , 1114 | [duplicate_indexes] , 1115 | [overlapping_indexes] , 1116 | [related_foreign_keys] , 1117 | [related_foreign_keys_xml] , 1118 | [key_columns] , 1119 | [data_columns] 1120 | FROM [#IndexStatistics] 1121 | WHERE ([estimated_user_total_pct] > 0.01 1122 | AND [index_id] IS NULL 1123 | ) 1124 | OR [related_foreign_keys] IS NOT NULL 1125 | OR [index_id] IS NOT NULL 1126 | ORDER BY [table_buffered_mb] DESC , 1127 | [object_id] , 1128 | COALESCE([user_total], -1) DESC , 1129 | COALESCE([user_updates], -1) DESC , 1130 | COALESCE([index_id], 999); 1131 | END; 1132 | ELSE 1133 | IF @Output = 'REALIGN' 1134 | BEGIN 1135 | SELECT [index_action] , 1136 | [object_name] , 1137 | [index_name] , 1138 | [partition_number] , 1139 | [type_desc] , 1140 | [index_pros] , 1141 | [index_cons] , 1142 | [index_row_count] , 1143 | [user_total] , 1144 | [user_seeks] , 1145 | [user_scans] , 1146 | [user_lookups] , 1147 | [user_updates] , 1148 | [user_total_pct] , 1149 | [size_in_mb] , 1150 | [buffered_mb] , 1151 | [table_buffered_mb] , 1152 | [buffered_percent] , 1153 | [indexed_columns] , 1154 | [included_columns] , 1155 | [is_primary_key] , 1156 | [is_unique] , 1157 | [is_disabled] , 1158 | [has_unique] , 1159 | [read_to_update_ratio] , 1160 | [read_to_update] , 1161 | [update_to_read] , 1162 | [row_lock_count] , 1163 | [row_lock_wait_count] , 1164 | [row_lock_wait_in_ms] , 1165 | [row_block_pct] , 1166 | [avg_row_lock_waits_ms] , 1167 | [page_latch_wait_count] , 1168 | [avg_page_latch_wait_ms] , 1169 | [page_io_latch_wait_count] , 1170 | [avg_page_io_latch_wait_ms] , 1171 | [read_operations] 1172 | FROM [#IndexStatistics] 1173 | WHERE [object_id] IN (SELECT [object_id] 1174 | FROM [#IndexStatistics] 1175 | WHERE [index_action] = 'REALIGN') 1176 | ORDER BY SUM([user_total]) OVER (PARTITION BY [object_id]) DESC , 1177 | [object_id] , 1178 | COALESCE([user_total], -1) DESC , 1179 | COALESCE([user_updates], -1) DESC , 1180 | COALESCE([index_id], 999); 1181 | END; 1182 | ELSE 1183 | IF @Output = 'DUPLICATE' 1184 | BEGIN 1185 | SELECT DENSE_RANK() OVER (ORDER BY [key_columns], [data_columns]) AS [duplicate_group] , 1186 | [index_action] , 1187 | [index_pros] , 1188 | [index_cons] , 1189 | [object_name] , 1190 | [index_name] , 1191 | [type_desc] , 1192 | [indexed_columns] , 1193 | [included_columns] , 1194 | [is_primary_key] , 1195 | [is_unique] , 1196 | [duplicate_indexes] , 1197 | [size_in_mb] , 1198 | [index_row_count] , 1199 | [user_total_pct] , 1200 | [user_total] , 1201 | [user_seeks] , 1202 | [user_scans] , 1203 | [user_lookups] , 1204 | [user_updates] , 1205 | [read_operations] 1206 | FROM [#IndexStatistics] 1207 | WHERE [duplicate_indexes] IS NOT NULL 1208 | ORDER BY [table_buffered_mb] DESC , 1209 | [object_id] , 1210 | RANK() OVER (ORDER BY [key_columns], [data_columns]); 1211 | END; 1212 | ELSE 1213 | IF @Output = 'OVERLAPPING' 1214 | BEGIN 1215 | SELECT [index_action] , 1216 | [index_pros] , 1217 | [index_cons] , 1218 | [object_name] , 1219 | [overlapping_indexes] , 1220 | [index_name] , 1221 | [type_desc] , 1222 | [indexed_columns] , 1223 | [included_columns] , 1224 | [is_primary_key] , 1225 | [is_unique] , 1226 | [size_in_mb] , 1227 | [index_row_count] , 1228 | [user_total_pct] , 1229 | [user_total] , 1230 | [user_seeks] , 1231 | [user_scans] , 1232 | [user_lookups] , 1233 | [user_updates] , 1234 | [read_operations] 1235 | FROM [#IndexStatistics] 1236 | WHERE [overlapping_indexes] IS NOT NULL 1237 | ORDER BY [table_buffered_mb] DESC , 1238 | [object_id] , 1239 | [user_total] DESC; 1240 | END; 1241 | END TRY 1242 | BEGIN CATCH 1243 | SELECT @ERROR_MESSAGE = 'Procedure Error (Line ' + CAST(ERROR_LINE() AS NVARCHAR(25)) + '): ' + ERROR_MESSAGE() , 1244 | @ERROR_SEVERITY = ERROR_SEVERITY() , 1245 | @ERROR_STATE = ERROR_STATE(); 1246 | 1247 | RAISERROR(@ERROR_MESSAGE, @ERROR_SEVERITY, @ERROR_STATE); 1248 | END CATCH; 1249 | END; 1250 | 1251 | 1252 | --------------------------------------------------------------------------------