Browse Source

Added more solutions

Eval compression gains; Fix VLFs; Index related solutions
Pedro Lopes 9 năm trước cách đây
mục cha
commit
37b546c469

+ 15 - 0
Evaluate-Compression-Gains/README.md

@@ -0,0 +1,15 @@
+Change log and other information available at http://aka.ms/SQLInsights - SQL Swiss Army Knife Series
+
+**Purpose:** Evaluates table and index compression, specifically an approach on how to select the best compression method for a database object.
+
+The Compression feature takes additional CPU resources while compressing and decompressing data, so it is important to know the workload on the specific database/instance/host combo when deciding how and what to compress. Usually, as long as your server is not CPU bound, the benefits outweigh the cost.
+With this in mind, it is highly recommended that you start by reading about table and index compression (http://msdn.microsoft.com/en-us/library/cc280449.aspx) and the related whitepaper (http://msdn.microsoft.com/en-us/library/dd894051(SQL.100).aspx) before moving on with any choice. The whitepaper is the basis for the choice algorithm I use in this script.
+Also, there is a caveat with using this script, because table and index compression (and even the system SP sp_estimate_data_compression_savings that this script wraps around) is an Enterprise only feature, and outputs the savings that can occur when you enable a table or partition for row or page compression. 
+Furthermore, this script is all the more trustworthy as instance uptime increases (or full business cycles go through it), because it uses sys.dm_db_index_operational_stats to assert read and write ratio.  Keep in mind that it is meant to provide mere guidance on the best compression method for a given object, providing enough memory and CPU resources are available.
+
+In the output, you will find the following information:
+-  Column *Percent_Update* shows the percentage of update operations on a specific table, index, or partition, relative to total operations on that object. The lower the percentage of Updates (that is, the table, index, or partition is infrequently updated), the better candidate it is for page compression. 
+-  Column *Percent_Scan* shows the percentage of scan operations on a table, index, or partition, relative to total operations on that object. The higher the value of Scan (that is, the table, index, or partition is mostly scanned), the better candidate it is for page compression. 
+-  Column *Compression_Type_Recommendation* can have four possible outputs indicating where there is most gain, if any: ‘PAGE’, ‘ROW’, ‘NO_GAIN’ or ‘?’. When the output is ‘?’ this approach could not give a recommendation, so as a rule of thumb I would lean to ROW if the object suffers mainly UPDATES, or PAGE if mainly INSERTS, but this is where knowing your workload is essential. When the output is ‘NO_GAIN’ well, that means that according to sp_estimate_data_compression_savings no space gains will be attained when compressing, as in the above output example, where compressing would grow the affected object. 
+
+**Note:** Note that this script will execute on the context of the current database. Also be aware that this may take awhile to execute on large objects, because if the IS locks taken by the sp_estimate_data_compression_savings cannot be honored, the SP will be blocked.

+ 145 - 0
Evaluate-Compression-Gains/view_CompressionGains.sql

@@ -0,0 +1,145 @@
+-- 2010-09-22 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/sqlinsights)
+--
+-- 2013-12-03 Fixed divide by zero error
+--
+-- Recomends type of compression per object - all more trustworthy as instance uptime increases.
+--
+-- [Percent_Update]
+-- The percentage of update operations on a specific table, index, or partition, relative to total operations on that object. The lower the value of U (that is, the table, index, or partition is infrequently updated), the better candidate it is for page compression. 
+--
+-- [Percent_Scan]
+-- The percentage of scan operations on a table, index, or partition, relative to total operations on that object. The higher the value of Scan (that is, the table, index, or partition is mostly scanned), the better candidate it is for page compression.
+--
+-- [Compression_Type_Recommendation] - READ DataCompression Best Practises before implementing.
+-- When ? means ROW if object suffers mainly UPDATES, PAGE if mainly INSERTS
+-- When NO_GAIN means that according to sp_estimate_data_compression_savings no space gains will be attained when compressing.
+--
+-- based on Data Compression Whitepaper at http://msdn.microsoft.com/en-us/library/dd894051(SQL.100).aspx
+--
+-- General algorithm validated by Paul Randall IF ENOUGH CPU AND RAM AVAILABLE.
+-- 
+SET NOCOUNT ON;
+
+CREATE TABLE ##tmpCompression ([Schema] sysname,
+	[Table_Name] sysname,
+	[Index_Name] sysname NULL,
+	[Partition] int,
+	[Index_ID] int,
+	[Index_Type] VARCHAR(12),
+	[Percent_Scan] smallint,
+	[Percent_Update] smallint,
+	[ROW_estimate_Pct_of_orig] smallint,
+	[PAGE_estimate_Pct_of_orig] smallint,
+	[Compression_Type_Recommendation] VARCHAR(7)
+);
+
+CREATE TABLE ##tmpEstimateRow (
+	objname sysname,
+	schname sysname,
+	indid int,
+	partnr int,
+	size_cur bigint,
+	size_req bigint,
+	sample_cur bigint,
+	sample_req bigint
+);
+
+CREATE TABLE ##tmpEstimatePage (
+	objname sysname,
+	schname sysname,
+	indid int,
+	partnr int,
+	size_cur bigint,
+	size_req bigint,
+	sample_cur bigint,
+	sample_req bigint
+);
+
+INSERT INTO ##tmpCompression ([Schema], [Table_Name], [Index_Name], [Partition], [Index_ID], [Index_Type], [Percent_Scan], [Percent_Update])
+SELECT s.name AS [Schema], o.name AS [Table_Name], x.name AS [Index_Name],
+       i.partition_number AS [Partition], i.index_id AS [Index_ID], x.type_desc AS [Index_Type],
+       i.range_scan_count * 100.0 / (i.range_scan_count + i.leaf_insert_count + i.leaf_delete_count + i.leaf_update_count + i.leaf_page_merge_count + i.singleton_lookup_count) AS [Percent_Scan],
+       i.leaf_update_count * 100.0 / (i.range_scan_count + i.leaf_insert_count + i.leaf_delete_count + i.leaf_update_count + i.leaf_page_merge_count + i.singleton_lookup_count) AS [Percent_Update]
+FROM sys.dm_db_index_operational_stats (db_id(), NULL, NULL, NULL) i
+	INNER JOIN sys.objects o ON o.object_id = i.object_id
+	INNER JOIN sys.schemas s ON o.schema_id = s.schema_id
+	INNER JOIN sys.indexes x ON x.object_id = i.object_id AND x.index_id = i.index_id
+WHERE (i.range_scan_count + i.leaf_insert_count + i.leaf_delete_count + leaf_update_count + i.leaf_page_merge_count + i.singleton_lookup_count) <> 0
+	AND objectproperty(i.object_id,'IsUserTable') = 1
+ORDER BY [Table_Name] ASC;
+
+DECLARE @schema sysname, @tbname sysname, @ixid int
+DECLARE cur CURSOR FAST_FORWARD FOR SELECT [Schema], [Table_Name], [Index_ID] FROM ##tmpCompression
+OPEN cur
+FETCH NEXT FROM cur INTO @schema, @tbname, @ixid
+WHILE @@FETCH_STATUS = 0
+BEGIN
+	--SELECT @schema, @tbname
+	INSERT INTO ##tmpEstimateRow
+	EXEC ('sp_estimate_data_compression_savings ''' + @schema + ''', ''' + @tbname + ''', ''' + @ixid + ''', NULL, ''ROW''' );
+	INSERT INTO ##tmpEstimatePage
+	EXEC ('sp_estimate_data_compression_savings ''' + @schema + ''', ''' + @tbname + ''', ''' + @ixid + ''', NULL, ''PAGE''');
+	FETCH NEXT FROM cur INTO @schema, @tbname, @ixid
+END
+CLOSE cur
+DEALLOCATE cur;
+
+--SELECT * FROM ##tmpEstimateRow
+--SELECT * FROM ##tmpEstimatePage;
+
+WITH tmp_CTE (objname, schname, indid, pct_of_orig_row, pct_of_orig_page)
+AS (SELECT tr.objname, tr.schname, tr.indid,	
+	(tr.sample_req*100)/CASE WHEN tr.sample_cur = 0 THEN 1 ELSE tr.sample_cur END AS pct_of_orig_row,
+	(tp.sample_req*100)/CASE WHEN tp.sample_cur = 0 THEN 1 ELSE tp.sample_cur END AS pct_of_orig_page
+	FROM ##tmpEstimateRow tr INNER JOIN ##tmpEstimatePage tp ON tr.objname = tp.objname
+	AND tr.schname = tp.schname AND tr.indid = tp.indid AND tr.partnr = tp.partnr)
+UPDATE ##tmpCompression
+SET [ROW_estimate_Pct_of_orig] = tcte.pct_of_orig_row, [PAGE_estimate_Pct_of_orig] = tcte.pct_of_orig_page
+FROM tmp_CTE tcte, ##tmpCompression tcomp
+WHERE tcte.objname = tcomp.Table_Name AND
+tcte.schname = tcomp.[Schema] AND
+tcte.indid = tcomp.Index_ID;
+
+WITH tmp_CTE2 (Table_Name, [Schema], Index_ID, [Compression_Type_Recommendation])
+AS (SELECT Table_Name, [Schema], Index_ID,
+	CASE WHEN [ROW_estimate_Pct_of_orig] >= 100 AND [PAGE_estimate_Pct_of_orig] >= 100 THEN 'NO_GAIN'
+		WHEN [Percent_Update] >= 10 THEN 'ROW' 
+		WHEN [Percent_Scan] <= 1 AND [Percent_Update] <= 1 AND [ROW_estimate_Pct_of_orig] < [PAGE_estimate_Pct_of_orig] THEN 'ROW'
+		WHEN [Percent_Scan] <= 1 AND [Percent_Update] <= 1 AND [ROW_estimate_Pct_of_orig] > [PAGE_estimate_Pct_of_orig] THEN 'PAGE'
+		WHEN [Percent_Scan] >= 60 AND [Percent_Update] <= 5 THEN 'PAGE'
+		WHEN [Percent_Scan] <= 35 AND [Percent_Update] <= 5 THEN '?'
+		ELSE 'ROW'
+		END
+	FROM ##tmpCompression)
+UPDATE ##tmpCompression
+SET [Compression_Type_Recommendation] = tcte2.[Compression_Type_Recommendation]
+FROM tmp_CTE2 tcte2, ##tmpCompression tcomp2
+WHERE tcte2.Table_Name = tcomp2.Table_Name AND
+tcte2.[Schema] = tcomp2.[Schema] AND
+tcte2.Index_ID = tcomp2.Index_ID;
+
+SET NOCOUNT ON;
+DECLARE @UpTime VARCHAR(12), @StartDate DATETIME, @sqlmajorver int, @sqlcmd NVARCHAR(500), @params NVARCHAR(500)
+SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
+
+IF @sqlmajorver = 9
+BEGIN
+	SET @sqlcmd = N'SELECT @StartDateOUT = login_time, @UpTimeOUT = DATEDIFF(mi, login_time, GETDATE()) FROM master..sysprocesses WHERE spid = 1';
+END
+ELSE
+BEGIN
+	SET @sqlcmd = N'SELECT @StartDateOUT = sqlserver_start_time, @UpTimeOUT = DATEDIFF(mi,sqlserver_start_time,GETDATE()) FROM sys.dm_os_sys_info';
+END
+
+SET @params = N'@StartDateOUT DATETIME OUTPUT, @UpTimeOUT VARCHAR(12) OUTPUT';
+
+EXECUTE sp_executesql @sqlcmd, @params, @StartDateOUT=@StartDate OUTPUT, @UpTimeOUT=@UpTime OUTPUT;
+
+SELECT @StartDate AS Collecting_Data_Since, CONVERT(VARCHAR(4),@UpTime/60/24) + 'd ' + CONVERT(VARCHAR(4),@UpTime/60%24) + 'h ' + CONVERT(VARCHAR(4),@UpTime%60) + 'm' AS Collecting_Data_For
+
+SELECT * FROM ##tmpCompression;
+
+DROP TABLE ##tmpCompression
+DROP TABLE ##tmpEstimateRow
+DROP TABLE ##tmpEstimatePage;
+GO

+ 248 - 0
Fixing-VLFs/Fix_VLFs.sql

@@ -0,0 +1,248 @@
+-- 2011-05-24 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/sqlinsights)
+--
+-- 2012-03-25 Added SQL 2012 support
+--
+-- 2012-09-19 Simplified logic
+--
+-- 2012-09-20 Changed grow settings if not SQL Server 2012
+--
+-- Generates the sql statements to preemtively fix VLF issues in all DBs within the server, based on the transaction log current size.
+--
+SET NOCOUNT ON;
+
+DECLARE @query VARCHAR(1000), @dbname VARCHAR(255), @count int, @usedlogsize bigint, @logsize bigint
+DECLARE @sqlcmd NVARCHAR(1000), @sqlparam NVARCHAR(100), @filename VARCHAR(255), @i int, @recmodel NVARCHAR(128)
+DECLARE @potsize int, @n_iter int, @n_iter_final int, @initgrow int, @n_init_iter int, @bckpath NVARCHAR(255)
+DECLARE @majorver smallint, @minorver smallint, @build smallint
+
+CREATE TABLE #loginfo (dbname varchar(100), num_of_rows int, used_logsize_MB DECIMAL(20,1))
+
+DECLARE @tblvlf TABLE (dbname varchar(100), 
+	Actual_log_size_MB DECIMAL(20,1), 
+	Potential_log_size_MB DECIMAL(20,1), 
+	Actual_VLFs int, 
+	Potential_VLFs int, 
+	Growth_iterations int,
+	Log_Initial_size_MB DECIMAL(20,1), 
+	File_autogrow_MB DECIMAL(20,1))
+	
+SELECT TOP 1 @bckpath = REVERSE(RIGHT(REVERSE(physical_device_name), LEN(physical_device_name)-CHARINDEX('\',REVERSE(physical_device_name),0))) FROM msdb.dbo.backupmediafamily WHERE device_type = 2
+
+SELECT @majorver = (@@microsoftversion / 0x1000000) & 0xff, @minorver = (@@microsoftversion / 0x10000) & 0xff, @build = @@microsoftversion & 0xffff
+ 
+--DECLARE csr CURSOR FAST_FORWARD FOR SELECT name FROM master..sysdatabases WHERE dbid > 4 AND DATABASEPROPERTYEX(name,'status') = 'ONLINE' AND DATABASEPROPERTYEX(name,'Updateability') = 'READ_WRITE' AND name <> 'tempdb' AND name <> 'ReportServerTempDB'
+DECLARE csr CURSOR FAST_FORWARD FOR SELECT name FROM master.sys.databases WHERE is_read_only = 0 AND state = 0 AND database_id <> 2;
+OPEN csr
+FETCH NEXT FROM csr INTO @dbname
+WHILE (@@FETCH_STATUS <> -1)
+BEGIN
+	CREATE TABLE #log_info (recoveryunitid int NULL,
+	fileid tinyint,
+	file_size bigint,
+	start_offset bigint,
+	FSeqNo int,
+	[status] tinyint,
+	parity tinyint,
+	create_lsn numeric(25,0))
+
+	SET @query = 'DBCC LOGINFO (' + '''' + @dbname + ''') WITH NO_INFOMSGS'
+	IF @majorver < 11
+	BEGIN
+		INSERT INTO #log_info (fileid, file_size, start_offset, FSeqNo, [status], parity, create_lsn)
+		EXEC (@query)
+	END
+	ELSE
+	BEGIN
+		INSERT INTO #log_info (recoveryunitid, fileid, file_size, start_offset, FSeqNo, [status], parity, create_lsn)
+		EXEC (@query)
+	END
+	SET @count = @@ROWCOUNT
+	SET @usedlogsize = (SELECT (MIN(l.start_offset) + SUM(CASE WHEN l.status <> 0 THEN l.file_size ELSE 0 END))/1024.00/1024.00 FROM #log_info l)
+	DROP TABLE #log_info;
+	INSERT #loginfo
+	VALUES(@dbname, @count, @usedlogsize);
+	FETCH NEXT FROM csr INTO @dbname
+END
+
+CLOSE csr
+DEALLOCATE csr
+
+PRINT '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */' + CHAR(10)
+	
+DECLARE cshrk CURSOR FAST_FORWARD FOR SELECT dbname, num_of_rows FROM #loginfo 
+WHERE num_of_rows >= 50 --My rule of thumb is 50 VLFs. Your mileage may vary.
+ORDER BY dbname
+OPEN cshrk
+FETCH NEXT FROM cshrk INTO @dbname, @count
+WHILE (@@FETCH_STATUS <> -1)
+BEGIN
+	SET @sqlcmd = 'SELECT @nameout = name, @logsizeout = (size*8)/1024 FROM [' + @dbname + '].dbo.sysfiles WHERE (64 & status) = 64'
+	SET @sqlparam = '@nameout NVARCHAR(100) OUTPUT, @logsizeout bigint OUTPUT'
+	EXEC sp_executesql @sqlcmd, @sqlparam, @nameout = @filename OUTPUT, @logsizeout = @logsize OUTPUT;
+	PRINT '---------------------------------------------------------------------------------------------------------- '
+	PRINT CHAR(13) + 'USE ' + QUOTENAME(@dbname) + ';'
+	PRINT 'DBCC SHRINKFILE (N''' + @filename + ''', 1, TRUNCATEONLY);'
+	PRINT '--'
+	PRINT '-- CHECK: if the tlog file has shrunk with the following query:'
+	PRINT 'SELECT name, (size*8)/1024 AS log_MB FROM [' + @dbname + '].dbo.sysfiles WHERE (64 & status) = 64'
+	PRINT '--'
+	SET @recmodel = CONVERT(NVARCHAR, DATABASEPROPERTYEX(@dbname,'Recovery'))
+	IF @recmodel <> 'SIMPLE'
+	BEGIN
+		PRINT '-- If the log has not shrunk, you must backup the transaction log next.'
+		PRINT '-- Repeat the backup and shrink process alternatively until you get the desired log size (about 1MB).'
+		PRINT '--'
+		PRINT '-- METHOD: Backup -> Shrink (repeat the backup and shrink process until the log has shrunk):'
+		PRINT '--'
+		PRINT '-- Create example logical backup device.' 
+		PRINT 'USE master;' + CHAR(13) + 'EXEC sp_addumpdevice ''disk'', ''BckLog'', ''' + @bckpath + '\example_bck.trn'';'
+		PRINT 'USE ' + QUOTENAME(@dbname) + ';'
+		PRINT '-- Backup Log'
+		PRINT 'BACKUP LOG ' + QUOTENAME(@dbname) + ' TO BckLog;'
+		PRINT '-- Shrink'
+		PRINT 'DBCC SHRINKFILE (N''' + @filename + ''', 1);'
+		PRINT '--'
+		PRINT '-- METHOD: Alter recovery model -> Shrink:'
+		PRINT '-- NOTE: Because the database is in ' + @recmodel + ' recovery model, one alternative is to set it to SIMPLE to truncate the log, shrink it, and reset it to ' + @recmodel + '.'
+		PRINT '-- NOTE2: This method of setting the recovery model to SIMPLE and back again WILL BREAK log chaining, and thus any log shipping or mirroring.'
+		PRINT 'USE [master]; ' + CHAR(13) + 'ALTER DATABASE ' + QUOTENAME(@dbname) + ' SET RECOVERY SIMPLE;'
+		PRINT 'USE ' + QUOTENAME(@dbname) + ';' + CHAR(13) + 'DBCC SHRINKFILE (N''' + @filename + ''', 1);'
+		PRINT 'USE [master]; ' + CHAR(13) + 'ALTER DATABASE ' + QUOTENAME(@dbname) + ' SET RECOVERY ' + @recmodel + ';'
+		PRINT '--'
+		PRINT '-- CHECK: if the tlog file has shrunk with the following query:'
+		PRINT 'SELECT name, (size*8)/1024 AS log_MB FROM [' + @dbname + '].dbo.sysfiles WHERE (64 & status) = 64'
+	END
+	ELSE
+	BEGIN
+		PRINT '-- If not, then proceed to the next step (it may be necessary to execute multiple times):'
+		PRINT 'DBCC SHRINKFILE (N''' + @filename + ''', 1);'
+		PRINT '-- CHECK: if the tlog file has shrunk with the following query:'
+		PRINT 'SELECT name, (size*8)/1024 AS log_MB FROM [' + @dbname + '].dbo.sysfiles WHERE (64 & status) = 64'
+	END
+
+	-- We are growing in MB instead of GB because of known issue prior to SQL 2012.
+	-- More detail here: http://www.sqlskills.com/BLOGS/PAUL/post/Bug-log-file-growth-broken-for-multiples-of-4GB.aspx
+	-- and http://connect.microsoft.com/SQLServer/feedback/details/481594/log-growth-not-working-properly-with-specific-growth-sizes-vlfs-also-not-created-appropriately
+	-- or https://connect.microsoft.com/SQLServer/feedback/details/357502/transaction-log-file-size-will-not-grow-exactly-4gb-when-filegrowth-4gb
+	IF @majorver >= 11
+	BEGIN
+		SET @n_iter = (SELECT CASE WHEN @logsize <= 64 THEN 1
+			WHEN @logsize > 64 AND @logsize < 256 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/256, 0)
+			WHEN @logsize >= 256 AND @logsize < 1024 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/512, 0)
+			WHEN @logsize >= 1024 AND @logsize < 4096 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/1024, 0)
+			WHEN @logsize >= 4096 AND @logsize < 8192 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/2048, 0)
+			WHEN @logsize >= 8192 AND @logsize < 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/4096, 0)
+			WHEN @logsize >= 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/8192, 0)
+			END)
+		SET @potsize = (SELECT CASE WHEN @logsize <= 64 THEN 1*64
+			WHEN @logsize > 64 AND @logsize < 256 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/256, 0)*256
+			WHEN @logsize >= 256 AND @logsize < 1024 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/512, 0)*512
+			WHEN @logsize >= 1024 AND @logsize < 4096 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/1024, 0)*1024
+			WHEN @logsize >= 4096 AND @logsize < 8192 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/2048, 0)*2048
+			WHEN @logsize >= 8192 AND @logsize < 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/4096, 0)*4096
+			WHEN @logsize >= 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/8192, 0)*8192
+			END)
+	END
+	ELSE
+	BEGIN
+		SET @n_iter = (SELECT CASE WHEN @logsize <= 64 THEN 1
+			WHEN @logsize > 64 AND @logsize < 256 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/256, 0)
+			WHEN @logsize >= 256 AND @logsize < 1024 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/512, 0)
+			WHEN @logsize >= 1024 AND @logsize < 4096 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/1024, 0)
+			WHEN @logsize >= 4096 AND @logsize < 8192 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/2048, 0)
+			WHEN @logsize >= 8192 AND @logsize < 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/4000, 0)
+			WHEN @logsize >= 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/8000, 0)
+			END)
+		SET @potsize = (SELECT CASE WHEN @logsize <= 64 THEN 1*64
+			WHEN @logsize > 64 AND @logsize < 256 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/256, 0)*256
+			WHEN @logsize >= 256 AND @logsize < 1024 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/512, 0)*512
+			WHEN @logsize >= 1024 AND @logsize < 4096 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/1024, 0)*1024
+			WHEN @logsize >= 4096 AND @logsize < 8192 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/2048, 0)*2048
+			WHEN @logsize >= 8192 AND @logsize < 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/4000, 0)*4000
+			WHEN @logsize >= 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/8000, 0)*8000
+			END)
+	END
+	
+	-- If the proposed log size is smaller than current log, and also smaller than 4GB,
+	-- and there is less than 512MB of diff between the current size and proposed size, add 1 grow.
+	SET @n_iter_final = @n_iter
+	IF @logsize > @potsize AND @potsize <= 4096 AND ABS(@logsize - @potsize) < 512
+	BEGIN
+		SET @n_iter_final = @n_iter + 1
+	END
+	-- If the proposed log size is larger than current log, and also larger than 50GB, 
+	-- and there is less than 1GB of diff between the current size and proposed size, take 1 grow.
+	ELSE IF @logsize < @potsize AND @potsize <= 51200 AND ABS(@logsize - @potsize) > 1024
+	BEGIN
+		SET @n_iter_final = @n_iter - 1
+	END
+
+	IF @potsize = 0 
+	BEGIN 
+		SET @potsize = 64 
+	END
+	IF @n_iter = 0 
+	BEGIN 
+		SET @n_iter = 1
+	END
+	
+	SET @potsize = (SELECT CASE WHEN @n_iter < @n_iter_final THEN @potsize + (@potsize/@n_iter) 
+			WHEN @n_iter > @n_iter_final THEN @potsize - (@potsize/@n_iter) 
+			ELSE @potsize END)
+	
+	SET @n_init_iter = @n_iter_final
+	IF @potsize >= 8192
+	BEGIN
+		SET @initgrow = @potsize/@n_iter_final
+	END
+	IF @potsize >= 64 AND @potsize <= 512
+	BEGIN
+		SET @n_init_iter = 1
+		SET @initgrow = 512
+	END
+	IF @potsize > 512 AND @potsize <= 1024
+	BEGIN
+		SET @n_init_iter = 1
+		SET @initgrow = 1023
+	END
+	IF @potsize > 1024 AND @potsize < 8192
+	BEGIN
+		SET @n_init_iter = 1
+		SET @initgrow = @potsize
+	END
+
+	INSERT INTO @tblvlf
+	SELECT @dbname, @logsize, @potsize, @count, 
+		CASE WHEN @potsize <= 64 THEN (@potsize/(@potsize/@n_init_iter))*4
+			WHEN @potsize > 64 AND @potsize < 1024 THEN (@potsize/(@potsize/@n_init_iter))*8
+			WHEN @potsize >= 1024 THEN (@potsize/(@potsize/@n_init_iter))*16
+			END, 
+		@n_init_iter, @initgrow, CASE WHEN (@potsize/@n_iter_final) <= 1024 THEN (@potsize/@n_iter_final) ELSE 1024 END
+	
+	SET @i = 0
+	WHILE @i <= @n_init_iter
+	BEGIN
+		IF @i = 1
+		BEGIN
+			--Log Autogrow should not be above 1GB
+			PRINT CHAR(13) + '-- Now for the log file growth:'
+			PRINT 'ALTER DATABASE [' + @dbname + '] MODIFY FILE ( NAME = N''' + @filename + ''', SIZE = ' + CONVERT(VARCHAR, @initgrow) + 'MB , FILEGROWTH = ' + CASE WHEN (@potsize/@n_iter_final) <= 1024 THEN CONVERT(VARCHAR, (@potsize/@n_iter_final)) ELSE '1024' END + 'MB );'
+		END
+		IF @i > 1
+		BEGIN
+			PRINT 'ALTER DATABASE [' + @dbname + '] MODIFY FILE ( NAME = N''' + @filename + ''', SIZE = ' + CONVERT(VARCHAR, @initgrow*@i)+ 'MB );'
+		END		
+		SET @i = @i + 1
+		CONTINUE
+	END
+	FETCH NEXT FROM cshrk INTO @dbname, @count
+END
+CLOSE cshrk
+DEALLOCATE cshrk;
+
+DROP TABLE #loginfo;
+
+SELECT dbname AS [Database_Name], Actual_log_size_MB, Potential_log_size_MB, Actual_VLFs, 
+	Potential_VLFs, Growth_iterations, Log_Initial_size_MB, File_autogrow_MB
+FROM @tblvlf;
+GO

+ 12 - 0
Fixing-VLFs/README.md

@@ -0,0 +1,12 @@
+Change log and other information available at http://aka.ms/SQLInsights - SQL Swiss Army Knife Series
+
+**Purpose:** Gets an overview of the current VLF status in all databases of a given instance, and if the number of VLFs are above a pre-determined threshold, also makes a suggestion of how many and how large the VLFs should be for that particular database.
+
+In the output, you will find the following information:
+-  The database name;
+-  The transaction log current size and the size it will be after applying suggested changes. Both in MB;
+-  The current number of VLFs and the number of VLFs that will remain after applying suggested changes;
+-  The amount of growth iterations necessary to get to the suggested size;
+-  The transaction log initial size and the autogrow size that should be set;
+
+In addition, a script is generated with the typical example steps needed to deal with the issue, depending on whether the database is in Simple recovery model or not.

+ 8 - 0
Index-Creation/README.md

@@ -0,0 +1,8 @@
+More information available at http://aka.ms/SQLInsights - SQL Swiss Army Knife Series
+
+**Purpose:** Looks for relevant missing indexes in SQL Server. Results are relevant if one or more business cycles have been executed.
+
+In the output, you will find the following information:
+-  Missing indexes with the highest user impact. The higher the score, higher is the anticipated improvement for user queries.
+-  Possibly redundant indexes in above list, whcih provides an opportunity to do some index consolidation.
+-  Index creation scripts.

+ 268 - 0
Index-Creation/view_IndexCreation.sql

@@ -0,0 +1,268 @@
+--
+-- 2007-10-11 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/sqlinsights/)
+--
+-- 2008-01-17 Check for possibly redundant indexes in the output.
+-- 2009-05-21 Changed index scoring method;
+--		Disregards indexes with [Score] < 100000 and [User_Hits_on_Missing_Index] < 99;
+-- 2013-03-21 Changed database loop method;
+-- 2013-11-10 Added search for redundant indexes in missing indexes;
+
+SET NOCOUNT ON;
+SET QUOTED_IDENTIFIER ON;
+
+DECLARE @IC VARCHAR(4000), @ICWI VARCHAR(4000), @editionCheck bit
+
+/* Refer to http://msdn.microsoft.com/en-us/library/ms174396.aspx */	
+IF (SELECT SERVERPROPERTY('EditionID')) IN (1804890536, 1872460670, 610778273, -2117995310)	
+SET @editionCheck = 1 -- supports enterprise only features
+ELSE	
+SET @editionCheck = 0; -- does not support enterprise only features
+
+-- Create the helper functions
+EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_allcols'')) DROP FUNCTION dbo.fn_createindex_allcols')
+EXEC ('USE tempdb; EXEC(''
+CREATE FUNCTION dbo.fn_createindex_allcols (@ix_handle int)
+RETURNS NVARCHAR(max)
+AS
+BEGIN
+	DECLARE @ReturnCols NVARCHAR(max)
+	;WITH ColumnToPivot ([data()]) AS ( 
+		SELECT CONVERT(VARCHAR(3),ic.column_id) + N'''','''' 
+		FROM sys.dm_db_missing_index_details id 
+		CROSS APPLY sys.dm_db_missing_index_columns(id.index_handle) ic
+		WHERE id.index_handle = @ix_handle 
+		ORDER BY ic.column_id ASC
+		FOR XML PATH(''''''''), TYPE 
+		), 
+		XmlRawData (CSVString) AS ( 
+			SELECT (SELECT [data()] AS InputData 
+			FROM ColumnToPivot AS d FOR XML RAW, TYPE).value(''''/row[1]/InputData[1]'''', ''''NVARCHAR(max)'''') AS CSVCol 
+		) 
+	SELECT @ReturnCols = CASE WHEN LEN(CSVString) <= 1 THEN NULL ELSE LEFT(CSVString, LEN(CSVString)-1) END
+	FROM XmlRawData
+	RETURN (@ReturnCols)
+END'')
+')
+
+EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_keycols'')) DROP FUNCTION dbo.fn_createindex_keycols')
+EXEC ('USE tempdb; EXEC(''
+CREATE FUNCTION dbo.fn_createindex_keycols (@ix_handle int)
+RETURNS NVARCHAR(max)
+AS
+BEGIN
+	DECLARE @ReturnCols NVARCHAR(max)
+	;WITH ColumnToPivot ([data()]) AS ( 
+		SELECT CONVERT(VARCHAR(3),ic.column_id) + N'''','''' 
+		FROM sys.dm_db_missing_index_details id 
+		CROSS APPLY sys.dm_db_missing_index_columns(id.index_handle) ic
+		WHERE id.index_handle = @ix_handle
+		AND (ic.column_usage = ''''EQUALITY'''' OR ic.column_usage = ''''INEQUALITY'''')
+		ORDER BY ic.column_id ASC
+		FOR XML PATH(''''''''), TYPE 
+		), 
+		XmlRawData (CSVString) AS ( 
+			SELECT (SELECT [data()] AS InputData 
+			FROM ColumnToPivot AS d FOR XML RAW, TYPE).value(''''/row[1]/InputData[1]'''', ''''NVARCHAR(max)'''') AS CSVCol 
+		) 
+	SELECT @ReturnCols = CASE WHEN LEN(CSVString) <= 1 THEN NULL ELSE LEFT(CSVString, LEN(CSVString)-1) END
+	FROM XmlRawData
+	RETURN (@ReturnCols)
+END'')
+')
+
+EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_includedcols'')) DROP FUNCTION dbo.fn_createindex_includedcols')
+EXEC ('USE tempdb; EXEC(''
+CREATE FUNCTION dbo.fn_createindex_includedcols (@ix_handle int)
+RETURNS NVARCHAR(max)
+AS
+BEGIN
+	DECLARE @ReturnCols NVARCHAR(max)
+	;WITH ColumnToPivot ([data()]) AS ( 
+		SELECT CONVERT(VARCHAR(3),ic.column_id) + N'''','''' 
+		FROM sys.dm_db_missing_index_details id 
+		CROSS APPLY sys.dm_db_missing_index_columns(id.index_handle) ic
+		WHERE id.index_handle = @ix_handle
+		AND ic.column_usage = ''''INCLUDE''''
+		ORDER BY ic.column_id ASC
+		FOR XML PATH(''''''''), TYPE 
+		), 
+		XmlRawData (CSVString) AS ( 
+			SELECT (SELECT [data()] AS InputData 
+			FROM ColumnToPivot AS d FOR XML RAW, TYPE).value(''''/row[1]/InputData[1]'''', ''''NVARCHAR(max)'''') AS CSVCol 
+		) 
+	SELECT @ReturnCols = CASE WHEN LEN(CSVString) <= 1 THEN NULL ELSE LEFT(CSVString, LEN(CSVString)-1) END
+	FROM XmlRawData
+	RETURN (@ReturnCols)
+END'')
+')
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#IndexCreation'))
+DROP TABLE #IndexCreation
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#IndexCreation'))
+CREATE TABLE #IndexCreation (
+	[database_id] int,
+	DBName VARCHAR(255),
+	[Table] VARCHAR(255),
+	[ix_handle] int,
+	[User_Hits_on_Missing_Index] int,
+	[Estimated_Improvement_Percent] DECIMAL(5,2),
+	[Avg_Total_User_Cost] int,
+	[Unique_Compiles] int,
+	[Score] NUMERIC(19,3),
+	[KeyCols] VARCHAR(1000),
+	[IncludedCols] VARCHAR(4000),
+	[Ix_Name] VARCHAR(255),
+	[AllCols] NVARCHAR(max),
+	[KeyColsOrdered] NVARCHAR(max),
+	[IncludedColsOrdered] NVARCHAR(max)
+	)
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#IndexRedundant'))
+DROP TABLE #IndexRedundant
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#IndexRedundant'))
+CREATE TABLE #IndexRedundant (
+	DBName VARCHAR(255),
+	[Table] VARCHAR(255),
+	[Ix_Name] VARCHAR(255),
+	[ix_handle] int,
+	[KeyCols] VARCHAR(1000),
+	[IncludedCols] VARCHAR(4000),
+	[Redundant_With] VARCHAR(255)
+	)
+
+INSERT INTO #IndexCreation
+SELECT i.database_id,
+	m.[name],
+	RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)) AS [Table],
+	i.index_handle AS [ix_handle],
+	[User_Hits_on_Missing_Index] = (s.user_seeks + s.user_scans),
+	s.avg_user_impact, -- Query cost would reduce by this amount in percentage, on average.
+	s.avg_total_user_cost, -- Average cost of the user queries that could be reduced by the index in the group.
+	s.unique_compiles, -- Number of compilations and recompilations that would benefit from this missing index group.
+	(CONVERT(NUMERIC(19,3), s.user_seeks) + CONVERT(NUMERIC(19,3), s.user_scans)) 
+		* CONVERT(NUMERIC(19,3), s.avg_total_user_cost) 
+		* CONVERT(NUMERIC(19,3), s.avg_user_impact) AS Score, -- The higher the score, higher is the anticipated improvement for user queries.
+	CASE WHEN (i.equality_columns IS NOT NULL AND i.inequality_columns IS NULL) THEN i.equality_columns
+			WHEN (i.equality_columns IS NULL AND i.inequality_columns IS NOT NULL) THEN i.inequality_columns
+			ELSE i.equality_columns + ',' + i.inequality_columns END AS [KeyCols],
+	i.included_columns AS [IncludedCols],
+	'IX_' + LEFT(RIGHT(RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)), LEN(RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3))) - (CHARINDEX('.', RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)), 1)) - 1),
+		LEN(RIGHT(RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)), LEN(RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3))) - (CHARINDEX('.', RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)), 1)) - 1)) - 1) + '_' + CAST(i.index_handle AS NVARCHAR) AS [Ix_Name],
+	tempdb.dbo.fn_createindex_allcols(i.index_handle), 
+	tempdb.dbo.fn_createindex_keycols(i.index_handle),
+	tempdb.dbo.fn_createindex_includedcols(i.index_handle)
+FROM sys.dm_db_missing_index_details i
+INNER JOIN master.sys.databases m ON i.database_id = m.database_id
+INNER JOIN sys.dm_db_missing_index_groups g ON i.index_handle = g.index_handle
+INNER JOIN sys.dm_db_missing_index_group_stats s ON s.group_handle = g.index_group_handle
+WHERE i.database_id > 4
+
+INSERT INTO #IndexRedundant
+SELECT I.DBName, I.[Table], I.[Ix_Name], i.[ix_handle], I.[KeyCols], I.[IncludedCols], I2.[Ix_Name]
+FROM #IndexCreation I 
+INNER JOIN #IndexCreation I2 ON I.[database_id] = I2.[database_id] AND I.[Table] = I2.[Table] AND I.[Ix_Name] <> I2.[Ix_Name]
+	AND (((I.KeyColsOrdered <> I2.KeyColsOrdered OR I.[IncludedColsOrdered] <> I2.[IncludedColsOrdered])
+		AND ((CASE WHEN I.[IncludedColsOrdered] IS NULL THEN I.KeyColsOrdered ELSE I.KeyColsOrdered + ',' + I.[IncludedColsOrdered] END) = (CASE WHEN I2.[IncludedColsOrdered] IS NULL THEN I2.KeyColsOrdered ELSE I2.KeyColsOrdered + ',' + I2.[IncludedColsOrdered] END)
+			OR I.[AllCols] = I2.[AllCols]))
+	OR (I.KeyColsOrdered <> I2.KeyColsOrdered AND I.[IncludedColsOrdered] = I2.[IncludedColsOrdered])
+	OR (I.KeyColsOrdered = I2.KeyColsOrdered AND I.[IncludedColsOrdered] <> I2.[IncludedColsOrdered]))
+WHERE I.[Score] >= 100000
+	AND I2.[Score] >= 100000
+GROUP BY I.DBName, I.[Table], I.[Ix_Name], I.[ix_handle], I.[KeyCols], I.[IncludedCols], I2.[Ix_Name]
+ORDER BY I.DBName, I.[Table], I.[Ix_Name]
+
+IF (SELECT COUNT(*) FROM #IndexCreation WHERE [Score] >= 100000) > 0
+BEGIN
+	SELECT 'Missing_Indexes' AS [Information], IC.DBName AS [Database_Name], IC.[Table] AS [Table_Name], CONVERT(bigint,[Score]) AS [Score], [User_Hits_on_Missing_Index], 
+		[Estimated_Improvement_Percent], [Avg_Total_User_Cost], [Unique_Compiles], IC.[KeyCols], IC.[IncludedCols], IC.[Ix_Name] AS [Index_Name],
+		SUBSTRING((SELECT ',' + IR.[Redundant_With] FROM #IndexRedundant IR 
+			WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]
+		ORDER BY IR.[Redundant_With]
+	FOR XML PATH('')), 2, 8000) AS [Possibly_Redundant_With]
+	FROM #IndexCreation IC
+	WHERE [Score] >= 100000
+	ORDER BY IC.DBName, IC.[Score] DESC, IC.[User_Hits_on_Missing_Index], IC.[Estimated_Improvement_Percent];		
+
+	SELECT DISTINCT 'Possibly_redundant_IXs_in_list' AS Comments, I.DBName AS [Database_Name], I.[Table] AS [Table_Name], 
+		I.[Ix_Name] AS [Index_Name], I.[KeyCols], I.[IncludedCols]
+	FROM #IndexRedundant I
+	ORDER BY I.DBName, I.[Table], I.[Ix_Name]
+END
+ELSE
+BEGIN
+	SELECT 'Missing_Indexes' AS [Information], 'None' AS [Comment]
+END;
+
+IF (SELECT COUNT(*) FROM #IndexCreation IC WHERE IC.[IncludedCols] IS NULL AND IC.[Score] >= 100000) > 0
+BEGIN
+	PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */' + CHAR(10)
+	PRINT '--############# Indexes creation statements #############' + CHAR(10)
+	DECLARE cIC CURSOR FAST_FORWARD FOR
+	SELECT '-- User Hits on Missing Index ' + IC.[Ix_Name] + ': ' + CONVERT(VARCHAR(20),IC.[User_Hits_on_Missing_Index]) + CHAR(10) +
+		'-- Estimated Improvement Percent: ' + CONVERT(VARCHAR(6),IC.[Estimated_Improvement_Percent]) + CHAR(10) +
+		'-- Average Total User Cost: ' + CONVERT(VARCHAR(50),IC.[Avg_Total_User_Cost]) + CHAR(10) +
+		'-- Unique Compiles: ' + CONVERT(VARCHAR(50),IC.[Unique_Compiles]) + CHAR(10) +
+		'-- Score: ' + CONVERT(VARCHAR(20),CONVERT(bigint,IC.[Score])) + 
+		CASE WHEN (SELECT COUNT(IR.[Redundant_With]) FROM #IndexRedundant IR 
+			WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]) > 0 
+		THEN CHAR(10) + '-- Possibly Redundant with Missing Index(es): ' + SUBSTRING((SELECT ',' + IR.[Redundant_With] FROM #IndexRedundant IR 
+			WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]
+			FOR XML PATH('')), 2, 8000) 
+		ELSE '' END +
+		CHAR(10) + 'USE ' + QUOTENAME(IC.DBName) + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sysindexes WHERE name = N''' +
+		IC.[Ix_Name] + ''') DROP INDEX ' + IC.[Table] + '.' +
+		IC.[Ix_Name] + ';' + CHAR(10) + 'GO' + CHAR(10) + 'CREATE INDEX ' +
+		IC.[Ix_Name] + ' ON ' + IC.[Table] + ' (' + IC.[KeyCols] + CASE WHEN @editionCheck = 1 THEN ') WITH (ONLINE = ON);' ELSE ');' END + CHAR(10) + 'GO' + CHAR(10)
+	FROM #IndexCreation IC
+	WHERE IC.[IncludedCols] IS NULL AND IC.[Score] >= 100000
+	ORDER BY IC.DBName, IC.[Table], IC.[Ix_Name]
+	OPEN cIC
+	FETCH NEXT FROM cIC INTO @IC
+	WHILE @@FETCH_STATUS = 0
+		BEGIN
+			PRINT @IC
+			FETCH NEXT FROM cIC INTO @IC
+		END
+	CLOSE cIC
+	DEALLOCATE cIC
+END;
+
+IF (SELECT COUNT(*) FROM #IndexCreation IC WHERE IC.[IncludedCols] IS NOT NULL AND IC.[Score] >= 100000) > 0
+BEGIN
+	PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */' + CHAR(10)
+	PRINT '--############# Covering indexes creation statements #############' + CHAR(10)
+	DECLARE cICWI CURSOR FAST_FORWARD FOR
+	SELECT '-- User Hits on Missing Index ' + IC.[Ix_Name] + ': ' + CONVERT(VARCHAR(20),IC.[User_Hits_on_Missing_Index]) + CHAR(10) +
+		'-- Estimated Improvement Percent: ' + CONVERT(VARCHAR(6),IC.[Estimated_Improvement_Percent]) + CHAR(10) +
+		'-- Average Total User Cost: ' + CONVERT(VARCHAR(50),IC.[Avg_Total_User_Cost]) + CHAR(10) +
+		'-- Unique Compiles: ' + CONVERT(VARCHAR(50),IC.[Unique_Compiles]) + CHAR(10) +
+		'-- Score: ' + CONVERT(VARCHAR(20),CONVERT(bigint,IC.[Score])) + 
+		CASE WHEN (SELECT COUNT(IR.[Redundant_With]) FROM #IndexRedundant IR 
+			WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]) > 0 
+		THEN CHAR(10) + '-- Possibly Redundant with Missing Index(es): ' + SUBSTRING((SELECT ',' + IR.[Redundant_With] FROM #IndexRedundant IR 
+			WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]
+			FOR XML PATH('')), 2, 8000) 
+		ELSE '' END + 
+		CHAR(10) + 'USE ' + QUOTENAME(IC.DBName) + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sysindexes WHERE name = N''' +
+		IC.[Ix_Name] + ''') DROP INDEX ' + IC.[Table] + '.' +
+		IC.[Ix_Name] + ';' + CHAR(10) + 'GO' + CHAR(10) + 'CREATE INDEX ' +
+		IC.[Ix_Name] + ' ON ' + IC.[Table] + ' (' + IC.[KeyCols] + CASE WHEN @editionCheck = 1 THEN ') WITH (ONLINE = ON);' ELSE ');' END + CHAR(10) + 'GO' + CHAR(10)
+	FROM #IndexCreation IC
+	WHERE IC.[IncludedCols] IS NOT NULL AND IC.[Score] >= 100000
+	ORDER BY IC.DBName, IC.[Table], IC.[Ix_Name]
+	OPEN cICWI
+	FETCH NEXT FROM cICWI INTO @ICWI
+	WHILE @@FETCH_STATUS = 0
+		BEGIN
+			PRINT @ICWI
+			FETCH NEXT FROM cICWI INTO @ICWI
+		END
+	CLOSE cICWI
+	DEALLOCATE cICWI
+END;
+
+DROP TABLE #IndexCreation
+EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_keycols'')) DROP FUNCTION dbo.fn_createindex_keycols')
+EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_allcols'')) DROP FUNCTION dbo.fn_createindex_allcols')
+EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_includedcols'')) DROP FUNCTION dbo.fn_createindex_includedcols')
+GO

+ 51 - 0
Index-Information/README.md

@@ -0,0 +1,51 @@
+Change log and other information available at http://aka.ms/SQLInsights - SQL Swiss Army Knife Series
+
+**view_IndexInformation**
+
+**Purpose:** Output index information on all databases, including duplicate, redundant, rarely used and unused indexes.
+
+In the output, you will find the following information:
+-  Information on all rowstore and columnstore indexes.
+-  Information on all In-Memory Hash and Range indexes.
+-  Information on all heaps.
+-  Unused indexes (meaning zero reads). These can possibly be dropped or disabled. Only looks at non-clustered and non-clustered columnstore indexes. Excludes primary keys, unique constraints and alternate keys.
+  -  Includes unused indexes which have been updated since the server last started. These are adding overhead to the system in the sense they are getting updates, but are never used for reads (and here is why knowing if one or more business cycles executed is important).
+  -  Includes unused indexes that also have not been updated since the server last started.
+-  Rarely used indexes (Writes to Reads ratio less than 5 percent). These can possibly be dropped or disabled. Only looks at non-clustered and non-clustered columnstore indexes. Excludes primary keys, unique constraints and alternate keys.
+-  Duplicate indexes. Looks at clustered, non-clustered, clustered and non-clustered columnstore indexes.
+  -  From the Duplicate indexes list, separately output which indexes should be removed. 
+     **Note:** It is possible that a clustered index (unique or not) is among the duplicate indexes to be dropped, namely if a non-clustered primary key exists on the table. In this case, make the appropriate changes in the clustered index (making it unique and/or primary key in this case), and drop the non-clustered instead.
+  -  From the Duplicate indexes list, look for hard-coded (hinted) references in all sql modules. If you drop such an index your query that explicitely references it will fail unless you change the reference to another index, or remove the reference all together.
+-  Redundant Indexes. Excludes unique constraints.
+-  Large IX Keys (over 900 bytes in the key).
+-  Low Fill Factor (less than 80 percent)
+-  Non-Unique Clustered indexes.
+
+In addition, drop scripts are generated for unused, rarely used and duplicate indexes.
+
+**view_IndexInformation_CurrentDB**
+
+**Purpose:** Output index information for current database, including duplicate, redundant, rarely used and unused indexes.
+
+In the output, you will find the following information:
+-  Information on all rowstore and columnstore indexes.
+-  Information on all In-Memory Hash and Range indexes.
+-  Information on all heaps.
+-  Unused indexes (meaning zero reads). These can possibly be dropped or disabled. Only looks at non-clustered and non-clustered columnstore indexes. Excludes primary keys, unique constraints and alternate keys.
+  -  Includes unused indexes which have been updated since the server last started. These are adding overhead to the system in the sense they are getting updates, but are never used for reads (and here is why knowing if one or more business cycles executed is important).
+  -  Includes unused indexes that also have not been updated since the server last started.
+-  Rarely used indexes (Writes to Reads ratio less than 5 percent). These can possibly be dropped or disabled. Only looks at non-clustered and non-clustered columnstore indexes. Excludes primary keys, unique constraints and alternate keys.
+-  Duplicate indexes. Looks at clustered, non-clustered, clustered and non-clustered columnstore indexes.
+  -  From the Duplicate indexes list, separately output which indexes should be removed. 
+     **Note:** It is possible that a clustered index (unique or not) is among the duplicate indexes to be dropped, namely if a non-clustered primary key exists on the table. In this case, make the appropriate changes in the clustered index (making it unique and/or primary key in this case), and drop the non-clustered instead.
+  -  From the Duplicate indexes list, look for hard-coded (hinted) references in all sql modules. If you drop such an index your query that explicitely references it will fail unless you change the reference to another index, or remove the reference all together.
+-  Redundant Indexes. Excludes unique constraints.
+-  Large IX Keys (over 900 bytes in the key).
+-  Low Fill Factor (less than 80 percent)
+-  Non-Unique Clustered indexes.
+
+In addition, drop scripts are generated for unused, rarely used and duplicate indexes.
+
+**view_HypObjects**
+
+**Purpose:** List all Hypothetical objects and generates drop scripts.

+ 94 - 0
Index-Information/view_HypObjects.sql

@@ -0,0 +1,94 @@
+--
+-- 2012-06-14 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/sqlinsights/)
+--
+-- List Hypothetical objects (with drop statements);
+--
+
+SET NOCOUNT ON;
+
+DECLARE @i int, @maxi int, @dbname sysname, @sqlcmd NVARCHAR(4000), @dbid int, @ErrorMessage NVARCHAR(500)
+
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
+CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbid] int, [dbname] sysname)
+
+INSERT INTO #tmpdbs ([dbid], [dbname])
+SELECT database_id, name FROM master.sys.databases WHERE is_read_only = 0 AND state = 0 AND database_id > 4 AND is_distributor = 0;
+
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblHypObj'))
+CREATE TABLE #tblHypObj ([DBName] sysname, [Table] VARCHAR(255), [Object] VARCHAR(255), [Type] VARCHAR(10))
+
+SET @i = 1
+SET @maxi = (SELECT MAX(id) FROM #tmpdbs)
+
+WHILE @i <= @maxi
+BEGIN
+	SET @dbname = (SELECT [dbname] FROM #tmpdbs WHERE id = @i)
+	SET @dbid = (SELECT [dbid] FROM #tmpdbs WHERE id = @i)
+	SET @sqlcmd = 'SELECT ''' + @dbname + ''' AS [DBName], QUOTENAME(o.[name]), i.name, ''INDEX'' FROM ' + QUOTENAME(@dbname) + '.sys.indexes i 
+INNER JOIN sys.objects o ON o.[object_id] = i.[object_id] 
+INNER JOIN sys.tables AS mst ON mst.[object_id] = i.[object_id]
+INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+WHERE i.is_hypothetical = 1
+UNION ALL
+SELECT ''' + @dbname + ''' AS [DBName], QUOTENAME(o.[name]), s.name, ''STATISTICS'' FROM ' + QUOTENAME(@dbname) + '.sys.stats s 
+INNER JOIN sys.objects o (NOLOCK) ON o.[object_id] = s.[object_id]
+INNER JOIN sys.tables AS mst (NOLOCK) ON mst.[object_id] = s.[object_id]
+INNER JOIN sys.schemas AS t (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE (s.name LIKE ''hind_%'' OR s.name LIKE ''_dta_stat%'') AND auto_created = 0
+AND s.name NOT IN (SELECT name FROM ' + QUOTENAME(@dbname) + '.sys.indexes)'
+
+	BEGIN TRY
+		INSERT INTO #tblHypObj
+		EXECUTE sp_executesql @sqlcmd
+	END TRY
+	BEGIN CATCH
+		SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
+		SELECT @ErrorMessage = 'Hypothetical objects subsection - Error raised in TRY block. ' + ERROR_MESSAGE()
+		RAISERROR (@ErrorMessage,16,1);
+	END CATCH
+	
+	SET @i = @i + 1
+END	
+
+IF (SELECT COUNT([Object]) FROM #tblHypObj) > 0
+BEGIN
+	SELECT 'Hypothetical_objects' AS [Information], '[WARNING: Some databases have indexes or statistics that are marked as hypothetical. It is recommended to drop these objects as soon as possible]' AS [Deviation]
+	SELECT 'Hypothetical_objects' AS [Information], DBName AS [Database Name], [Table] AS [Table Name], [Object] AS [Object Name], [Type] AS [Object Type]
+	FROM #tblHypObj
+	ORDER BY 2, 3, 5
+	
+	DECLARE @strSQL NVARCHAR(4000)
+	PRINT '--** Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */' + CHAR(10)
+
+	PRINT CHAR(10) + '--############# Existing Hypothetical objects drop statements #############' + CHAR(10)
+	
+	DECLARE ITW_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + [DBName] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM ' + CASE WHEN [Type] = 'STATISTICS' THEN 'sys.stats' ELSE 'sys.indexes' END + ' WHERE name = N'''+ [Object] + ''')' + CHAR(10) +
+	CASE WHEN [Type] = 'STATISTICS' THEN 'DROP STATISTICS ' + [Table] + '.' +  QUOTENAME([Object]) + ';' + CHAR(10) + 'GO' + CHAR(10)
+		ELSE 'DROP INDEX ' + QUOTENAME([Object]) + ' ON ' + [Table] + ';' + CHAR(10) + 'GO' + CHAR(10) 
+		END
+	FROM #tblHypObj
+	ORDER BY DBName, [Table]
+
+	OPEN ITW_Stats
+	FETCH NEXT FROM ITW_Stats INTO @strSQL
+	WHILE (@@FETCH_STATUS = 0)
+	BEGIN
+		PRINT @strSQL
+		FETCH NEXT FROM ITW_Stats INTO @strSQL
+	END
+	CLOSE ITW_Stats
+	DEALLOCATE ITW_Stats
+
+	PRINT '--############# Ended Hypothetical objects drop statements #############' + CHAR(10)
+
+END
+ELSE
+BEGIN
+	SELECT 'Hypothetical_objects' AS [Information], '[OK]' AS [Deviation]
+END;
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
+DROP TABLE #tmpdbs;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblHypObj'))
+DROP TABLE #tblHypObj;
+GO

+ 1169 - 0
Index-Information/view_IndexInformation.sql

@@ -0,0 +1,1169 @@
+-- 2012-03-19 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/ezequiel)
+--
+-- All Databases index info, including duplicate, redundant, rarely used and unused indexes.
+--
+-- 4/5/2012		Simplified execution by subdividing input queries
+-- 4/5/2012		Fixed some collation issues;
+-- 4/6/2012		Split in separate listings the unused indexes from rarely used indexes; Split in separate list
+-- 6/6/2012		Fixed issue with partition aligned indexes
+-- 10/31/2012	Widened search for Redundant Indexes
+-- 12/17/2012	Fixed several issues
+-- 1/17/2013	Added several index related info
+-- 2/1/2013		Fixed issue with Heap identification
+-- 2/26/2013	Fixed issue with partition info; Removed alternate keys from search for Unused and Rarely used
+-- 4/17/2013	Added more information to duplicate and redundant indexes output, valuable when deciding which
+-- 4/19/2013	Fixed issue with potential duplicate index_ids in sys.dm_db_index_operational_stats relating t
+-- 5/6/2013		Changed data collection to minimize blocking potential on VLDBs.
+-- 5/20/2013	Fixed issue with database names with special characters.
+-- 5/29/2013	Fixed issue with large integers in aggregation.
+-- 6/20/2013	Added step to avoid entering in loop that generates dump in SQL 2005.
+-- 11/10/2013	Added index checks.
+-- 2/24/2014	Added info to Unused_IX section.
+-- 6/4/2014		Refined search for duplicate and redundant indexes.
+-- 11/12/2014	Added SQL 2014 Hash indexes support; changed scan mode to LIMITED; added search for hard coded
+-- 11/2/2016	Added support for SQL Server 2016 sys.dm_db_index_operational_stats changes; Added script creation.
+
+/*
+NOTE: on SQL Server 2005, be aware that querying sys.dm_db_index_usage_stats when it has large number of rows may lead to performance issues.
+URL: http://support.microsoft.com/kb/2003031
+*/
+
+SET NOCOUNT ON;
+
+DECLARE @UpTime VARCHAR(12), @StartDate DATETIME, @sqlmajorver int, @sqlcmd NVARCHAR(4000), @params NVARCHAR(500)
+DECLARE @DatabaseName sysname, @indexName sysname
+SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
+
+IF @sqlmajorver = 9
+BEGIN
+	SET @sqlcmd = N'SELECT @StartDateOUT = login_time, @UpTimeOUT = DATEDIFF(mi, login_time, GETDATE()) FROM master..sysprocesses WHERE spid = 1';
+END
+ELSE
+BEGIN
+	SET @sqlcmd = N'SELECT @StartDateOUT = sqlserver_start_time, @UpTimeOUT = DATEDIFF(mi,sqlserver_start_time,GETDATE()) FROM sys.dm_os_sys_info';
+END
+
+SET @params = N'@StartDateOUT DATETIME OUTPUT, @UpTimeOUT VARCHAR(12) OUTPUT';
+
+EXECUTE sp_executesql @sqlcmd, @params, @StartDateOUT=@StartDate OUTPUT, @UpTimeOUT=@UpTime OUTPUT;
+
+SELECT @StartDate AS Collecting_Data_Since, CONVERT(VARCHAR(4),@UpTime/60/24) + 'd ' + CONVERT(VARCHAR(4),@UpTime/60%24) + 'h ' + CONVERT(VARCHAR(4),@UpTime%60) + 'm' AS Collecting_Data_For
+
+RAISERROR (N'Starting...', 10, 1) WITH NOWAIT
+
+DECLARE @dbid int--, @sqlcmd NVARCHAR(4000)
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblDatabases'))
+DROP TABLE #tblDatabases;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblDatabases'))
+CREATE TABLE #tblDatabases (database_id int PRIMARY KEY, is_done bit)
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
+DROP TABLE #tblWorking;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
+CREATE TABLE #tblWorking (database_id int, [object_id] int, [object_name] NVARCHAR(255), index_id int, index_name NVARCHAR(255), [schema_name] NVARCHAR(255), partition_number int, is_done bit)
+
+INSERT INTO #tblDatabases 
+SELECT database_id, 0 FROM sys.databases WHERE is_read_only = 0 AND state = 0 AND database_id > 4 AND is_distributor = 0;
+
+RAISERROR (N'Populating support tables...', 10, 1) WITH NOWAIT
+
+WHILE (SELECT COUNT(*) FROM #tblDatabases WHERE is_done = 0) > 0
+BEGIN
+	SELECT TOP 1 @dbid = database_id FROM #tblDatabases WHERE is_done = 0
+SELECT @sqlcmd = 'SELECT ' + CONVERT(NVARCHAR(255), @dbid) + ', si.[object_id], mst.[name], si.index_id, si.name, t.name, sp.partition_number, 0
+FROM [' + DB_NAME(@dbid) + '].sys.indexes si
+INNER JOIN [' + DB_NAME(@dbid) + '].sys.partitions sp ON si.[object_id] = sp.[object_id] AND si.index_id = sp.index_id
+INNER JOIN [' + DB_NAME(@dbid) + '].sys.tables AS mst ON mst.[object_id] = si.[object_id]
+INNER JOIN [' + DB_NAME(@dbid) + '].sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+WHERE mst.is_ms_shipped = 0'
+	INSERT INTO #tblWorking
+	EXEC sp_executesql @sqlcmd;
+	
+	UPDATE #tblDatabases
+	SET is_done = 1
+	WHERE database_id = @dbid;
+END
+
+--------------------------------------------------------
+-- Index physical and usage stats
+--------------------------------------------------------
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
+DROP TABLE #tmpIPS;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
+CREATE TABLE #tmpIPS (
+	[database_id] int,
+	[object_id] int,
+	[index_id] int,
+	[partition_number] int,
+	fragmentation DECIMAL(18,3),
+	[page_count] bigint,
+	[size_MB] DECIMAL(26,3),
+	record_count int,
+	forwarded_record_count int NULL,
+	CONSTRAINT PK_IPS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]))
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
+DROP TABLE #tmpIOS;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
+CREATE TABLE #tmpIOS (
+	[database_id] int,
+	[object_id] int,
+	[index_id] int,
+	[partition_number] int,
+	range_scan_count bigint NULL,
+	singleton_lookup_count bigint NULL,
+	forwarded_fetch_count bigint NULL,
+	row_lock_count bigint NULL,
+	row_lock_wait_count bigint NULL,
+	row_lock_pct NUMERIC(15,2) NULL,
+	row_lock_wait_in_ms bigint NULL,
+	[avg_row_lock_waits_in_ms] NUMERIC(15,2) NULL,
+	page_lock_count bigint NULL,
+	page_lock_wait_count bigint NULL,
+	page_lock_pct NUMERIC(15,2) NULL,
+	page_lock_wait_in_ms bigint NULL,
+	[avg_page_lock_waits_in_ms] NUMERIC(15,2) NULL,
+	page_io_latch_wait_in_ms bigint NULL,
+	[avg_page_io_latch_wait_in_ms] NUMERIC(15,2) NULL
+	CONSTRAINT PK_IOS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
+DROP TABLE #tmpIUS;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
+CREATE TABLE #tmpIUS (
+	[database_id] int,
+	[schema_name] VARCHAR(100) COLLATE database_default,
+	[object_id] int,
+	[index_id] int,
+	[Hits] bigint NULL,
+	[Reads_Ratio] DECIMAL(5,2),
+	[Writes_Ratio] DECIMAL(5,2),
+	user_updates bigint,
+	last_user_seek DATETIME NULL,
+	last_user_scan DATETIME NULL,
+	last_user_lookup DATETIME NULL,
+	last_user_update DATETIME NULL
+	CONSTRAINT PK_IUS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
+DROP TABLE #tmpIxs;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
+CREATE TABLE #tmpIxs (
+	[database_id] int, 
+	[database_name] VARCHAR(500), 
+	[object_id] int, 
+	[schema_name] VARCHAR(100) COLLATE database_default, 
+	[table_name] VARCHAR(300) COLLATE database_default, 
+	[index_id] int, 
+	[index_name] VARCHAR(300) COLLATE database_default,
+	[partition_number] int,
+	[index_type] tinyint,
+	type_desc NVARCHAR(30),
+	is_primary_key bit,
+	is_unique_constraint bit,
+	is_disabled bit,
+	fill_factor tinyint, 
+	is_unique bit, 
+	is_padded bit, 
+	has_filter bit,
+	filter_definition NVARCHAR(max),
+	KeyCols VARCHAR(4000), 
+	KeyColsOrdered VARCHAR(4000), 
+	IncludedCols VARCHAR(4000) NULL, 
+	IncludedColsOrdered VARCHAR(4000) NULL, 
+	AllColsOrdered VARCHAR(4000) NULL,
+	[KeyCols_data_length_bytes] int,
+	CONSTRAINT PK_Ixs PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
+DROP TABLE #tmpAgg;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
+CREATE TABLE #tmpAgg (
+	[database_id] int,
+	[database_name] sysname,
+	[object_id] int,
+	[schema_name] VARCHAR(100) COLLATE database_default,
+	[table_name] VARCHAR(300) COLLATE database_default,
+	[index_id] int,
+	[index_name] VARCHAR(300) COLLATE database_default,
+	[partition_number] int,
+	fragmentation DECIMAL(18,3),
+	fill_factor tinyint,
+	[page_count] bigint,
+	[size_MB] DECIMAL(26,3),
+	record_count bigint, 
+	forwarded_record_count bigint NULL,
+	range_scan_count bigint NULL,
+	singleton_lookup_count bigint NULL,
+	forwarded_fetch_count bigint NULL,
+	row_lock_count bigint NULL,
+	row_lock_wait_count bigint NULL,
+	row_lock_pct NUMERIC(15,2) NULL,
+	row_lock_wait_in_ms bigint NULL,
+	[avg_row_lock_waits_in_ms] NUMERIC(15,2) NULL,
+	page_lock_count bigint NULL,
+	page_lock_wait_count bigint NULL,
+	page_lock_pct NUMERIC(15,2) NULL,
+	page_lock_wait_in_ms bigint NULL,
+	[avg_page_lock_waits_in_ms] NUMERIC(15,2) NULL,
+	page_io_latch_wait_in_ms bigint NULL,
+	[avg_page_io_latch_wait_in_ms] NUMERIC(15,2) NULL,
+	[Hits] bigint NULL,
+	[Reads_Ratio] DECIMAL(5,2),
+	[Writes_Ratio] DECIMAL(5,2),
+	user_updates bigint,
+	last_user_seek DATETIME NULL,
+	last_user_scan DATETIME NULL,
+	last_user_lookup DATETIME NULL,
+	last_user_update DATETIME NULL,
+	KeyCols VARCHAR(4000) COLLATE database_default,
+	KeyColsOrdered VARCHAR(4000) COLLATE database_default,
+	IncludedCols VARCHAR(4000) COLLATE database_default NULL,
+	IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL, 
+	AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
+	is_unique bit,
+	[type] tinyint,
+	type_desc NVARCHAR(30),
+	is_primary_key bit,
+	is_unique_constraint bit,
+	is_padded bit, 
+	has_filter bit, 
+	filter_definition NVARCHAR(max),
+	is_disabled bit,
+	[KeyCols_data_length_bytes] int,	
+	CONSTRAINT PK_tmpAgg PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
+DROP TABLE #tblCode;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
+CREATE TABLE #tblCode (
+	[DatabaseName] sysname, 
+	[schemaName] VARCHAR(100), 
+	[objectName] VARCHAR(200), 
+	[indexName] VARCHAR(200), 
+	type_desc NVARCHAR(60));
+	
+IF @sqlmajorver >= 12
+BEGIN
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
+	DROP TABLE #tmpXIS;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
+	CREATE TABLE #tmpXIS (
+		[database_id] int,
+		[object_id] int,
+		[schema_name] VARCHAR(100) COLLATE database_default,
+		[table_name] VARCHAR(300) COLLATE database_default,
+		[index_id] int,
+		[index_name] VARCHAR(300) COLLATE database_default,
+		total_bucket_count bigint, 
+		empty_bucket_count bigint, 
+		avg_chain_length bigint, 
+		max_chain_length bigint, 
+		scans_started bigint, 
+		scans_retries bigint, 
+		rows_returned bigint, 
+		rows_touched bigint,
+		CONSTRAINT PK_tmpXIS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
+	DROP TABLE #tmpXNCIS;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
+	CREATE TABLE #tmpXNCIS (
+		[database_id] int,
+		[object_id] int,
+		[schema_name] VARCHAR(100) COLLATE database_default,
+		[table_name] VARCHAR(300) COLLATE database_default,
+		[index_id] int,
+		[index_name] VARCHAR(300) COLLATE database_default,
+		delta_pages bigint, 
+		internal_pages bigint, 
+		leaf_pages bigint, 
+		page_update_count bigint,
+		page_update_retry_count bigint, 
+		page_consolidation_count bigint,
+		page_consolidation_retry_count bigint, 
+		page_split_count bigint, 
+		page_split_retry_count bigint,
+		key_split_count bigint, 
+		key_split_retry_count bigint, 
+		page_merge_count bigint, 
+		page_merge_retry_count bigint,
+		key_merge_count bigint, 
+		key_merge_retry_count bigint, 
+		scans_started bigint, 
+		scans_retries bigint, 
+		rows_returned bigint, 
+		rows_touched bigint,
+		CONSTRAINT PK_tmpXNCIS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
+	DROP TABLE #tmpAggXTPHash;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
+	CREATE TABLE #tmpAggXTPHash (
+		[database_id] int,
+		[database_name] sysname,
+		[object_id] int,
+		[schema_name] VARCHAR(100) COLLATE database_default,
+		[table_name] VARCHAR(300) COLLATE database_default,
+		[index_id] int,
+		[index_name] VARCHAR(300) COLLATE database_default,
+		total_bucket_count bigint, 
+		empty_bucket_count bigint, 
+		avg_chain_length bigint, 
+		max_chain_length bigint, 
+		scans_started bigint, 
+		scans_retries bigint, 
+		rows_returned bigint, 
+		rows_touched bigint,
+		KeyCols VARCHAR(4000) COLLATE database_default,
+		KeyColsOrdered VARCHAR(4000) COLLATE database_default,
+		IncludedCols VARCHAR(4000) COLLATE database_default NULL,
+		IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL, 
+		AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
+		is_unique bit,
+		[type] tinyint,
+		type_desc NVARCHAR(30),
+		is_primary_key bit,
+		is_unique_constraint bit,
+		is_padded bit, 
+		has_filter bit, 
+		filter_definition NVARCHAR(max),
+		is_disabled bit,
+		[KeyCols_data_length_bytes] int,	
+		CONSTRAINT PK_tmpAggXTPHash PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
+	DROP TABLE #tmpAggXTPNC;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
+	CREATE TABLE #tmpAggXTPNC (
+		[database_id] int,
+		[database_name] sysname,
+		[object_id] int,
+		[schema_name] VARCHAR(100) COLLATE database_default,
+		[table_name] VARCHAR(300) COLLATE database_default,
+		[index_id] int,
+		[index_name] VARCHAR(300) COLLATE database_default,
+		delta_pages bigint, 
+		internal_pages bigint, 
+		leaf_pages bigint, 
+		page_update_count bigint,
+		page_update_retry_count bigint, 
+		page_consolidation_count bigint,
+		page_consolidation_retry_count bigint, 
+		page_split_count bigint, 
+		page_split_retry_count bigint,
+		key_split_count bigint, 
+		key_split_retry_count bigint, 
+		page_merge_count bigint, 
+		page_merge_retry_count bigint,
+		key_merge_count bigint, 
+		key_merge_retry_count bigint, 
+		scans_started bigint, 
+		scans_retries bigint, 
+		rows_returned bigint, 
+		rows_touched bigint,
+		KeyCols VARCHAR(4000) COLLATE database_default,
+		KeyColsOrdered VARCHAR(4000) COLLATE database_default,
+		IncludedCols VARCHAR(4000) COLLATE database_default NULL,
+		IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL, 
+		AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
+		is_unique bit,
+		[type] tinyint,
+		type_desc NVARCHAR(30),
+		is_primary_key bit,
+		is_unique_constraint bit,
+		is_padded bit,
+		has_filter bit,
+		filter_definition NVARCHAR(max),
+		is_disabled bit,
+		[KeyCols_data_length_bytes] int,	
+		CONSTRAINT PK_tmpAggXTPNC PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
+	DROP TABLE #tmpHashIxs;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
+	CREATE TABLE #tmpHashIxs (
+		[database_id] int, 
+		[database_name] VARCHAR(500), 
+		[object_id] int, 
+		[schema_name] VARCHAR(100) COLLATE database_default, 
+		[table_name] VARCHAR(300) COLLATE database_default, 
+		[index_id] int, 
+		[index_name] VARCHAR(300) COLLATE database_default,
+		[partition_number] int,
+		[index_type] tinyint,
+		type_desc NVARCHAR(30),
+		is_primary_key bit,
+		is_unique_constraint bit,
+		is_disabled bit,
+		fill_factor tinyint, 
+		is_unique bit, 
+		is_padded bit, 
+		has_filter bit,
+		filter_definition NVARCHAR(max),
+		[bucket_count] bigint,
+		KeyCols VARCHAR(4000), 
+		KeyColsOrdered VARCHAR(4000), 
+		IncludedCols VARCHAR(4000) NULL, 
+		IncludedColsOrdered VARCHAR(4000) NULL, 
+		AllColsOrdered VARCHAR(4000) NULL,
+		[KeyCols_data_length_bytes] int,
+		CONSTRAINT PK_HashIxs PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
+END;
+
+DECLARE /*@dbid int, */@objectid int, @indexid int, @partition_nr int, @dbname NVARCHAR(255), @oname NVARCHAR(255), @iname NVARCHAR(255), @sname NVARCHAR(255)
+
+RAISERROR (N'Gathering sys.dm_db_index_physical_stats and sys.dm_db_index_operational_stats data...', 10, 1) WITH NOWAIT
+
+WHILE (SELECT COUNT(*) FROM #tblWorking WHERE is_done = 0) > 0
+BEGIN
+	SELECT TOP 1 @dbid = database_id, @objectid = [object_id], @indexid = index_id, @partition_nr = partition_number, @oname = [object_name], @iname = index_name, @sname = [schema_name]
+	FROM #tblWorking WHERE is_done = 0
+	
+	INSERT INTO #tmpIPS
+	SELECT ps.database_id, 
+		ps.[object_id], 
+		ps.index_id, 
+		ps.partition_number, 
+		SUM(ps.avg_fragmentation_in_percent),
+		SUM(ps.page_count),
+		CAST((SUM(ps.page_count)*8)/1024 AS DECIMAL(26,3)) AS [size_MB],
+		SUM(ISNULL(ps.record_count,0)),
+		SUM(ISNULL(ps.forwarded_record_count,0)) -- for heaps
+	FROM sys.dm_db_index_physical_stats(@dbid, @objectid, @indexid , @partition_nr, 'SAMPLED') AS ps
+	WHERE /*ps.index_id > 0 -- ignore heaps
+		AND */ps.index_level = 0 -- leaf-level nodes only
+		AND ps.alloc_unit_type_desc = 'IN_ROW_DATA'
+	GROUP BY ps.database_id, ps.[object_id], ps.index_id, ps.partition_number
+	OPTION (MAXDOP 2);
+
+	-- Avoid entering in loop that generates dump in SQL 2005
+	IF @sqlmajorver = 9
+	BEGIN
+		SET @sqlcmd = (SELECT 'USE [' + DB_NAME(@dbid) + '];
+UPDATE STATISTICS ' + QUOTENAME(@sname) + '.' + QUOTENAME(@oname) + CASE WHEN @iname IS NULL THEN '' ELSE ' (' + QUOTENAME(@iname) + ')' END)
+		EXEC sp_executesql @sqlcmd
+	END;
+	SET @sqlcmd = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + DB_NAME(@dbid) + '];
+WITH osCTE (database_id, [object_id], index_id, partition_number, range_scan_count, singleton_lookup_count, 
+	forwarded_fetch_count, row_lock_count, row_lock_wait_count, row_lock_wait_in_ms, page_lock_count, 
+	page_lock_wait_count, page_lock_wait_in_ms, page_io_latch_wait_count, page_io_latch_wait_in_ms)
+AS (SELECT os.database_id, 
+	os.[object_id], 
+	os.index_id,
+	os.partition_number, 
+	SUM(os.range_scan_count), 
+	SUM(os.singleton_lookup_count),
+	SUM(os.forwarded_fetch_count),
+	SUM(os.row_lock_count),
+	SUM(os.row_lock_wait_count),
+	SUM(os.row_lock_wait_in_ms),
+	SUM(os.page_lock_count),
+	SUM(os.page_lock_wait_count),
+	SUM(os.page_lock_wait_in_ms),
+	SUM(os.page_io_latch_wait_count),
+	SUM(os.page_io_latch_wait_in_ms)
+FROM sys.dm_db_index_operational_stats(' + CONVERT(NVARCHAR(20), @dbid) + ', ' + CONVERT(NVARCHAR(20), @objectid) + ', ' + CONVERT(NVARCHAR(20), @indexid) + ', ' + CONVERT(NVARCHAR(20), @partition_nr) + ') AS os
+INNER JOIN sys.objects AS o WITH (NOLOCK) ON os.[object_id] = o.[object_id]
+' + CASE WHEN @sqlmajorver >= 13 THEN 'LEFT JOIN sys.internal_partitions AS ip WITH (NOLOCK) ON os.hobt_id = ip.hobt_id AND ip.internal_object_type IN (2,3)' ELSE '' END + '
+WHERE o.[type] = ''U''
+GROUP BY os.database_id, os.[object_id], os.index_id, os.partition_number
+)
+SELECT osCTE.database_id, 
+	osCTE.[object_id], 
+	osCTE.index_id,
+	osCTE.partition_number, 
+	osCTE.range_scan_count, 
+	osCTE.singleton_lookup_count,
+	osCTE.forwarded_fetch_count,
+	osCTE.row_lock_count,
+	osCTE.row_lock_wait_count,
+	CAST(100.0 * osCTE.row_lock_wait_count / (1 + osCTE.row_lock_count) AS numeric(15,2)) AS row_lock_pct,
+	osCTE.row_lock_wait_in_ms,
+	CAST(1.0 * osCTE.row_lock_wait_in_ms / (1 + osCTE.row_lock_wait_count) AS numeric(15,2)) AS [avg_row_lock_waits_in_ms],
+	osCTE.page_lock_count,
+	osCTE.page_lock_wait_count,
+	CAST(100.0 * osCTE.page_lock_wait_count / (1 + osCTE.page_lock_count) AS numeric(15,2)) AS page_lock_pct,
+	osCTE.page_lock_wait_in_ms,
+	CAST(1.0 * osCTE.page_lock_wait_in_ms / (1 + osCTE.page_lock_wait_count) AS numeric(15,2)) AS [avg_page_lock_waits_in_ms],
+	osCTE.page_io_latch_wait_in_ms,
+	CAST(1.0 * osCTE.page_io_latch_wait_in_ms / (1 + osCTE.page_io_latch_wait_count) AS numeric(15,2)) AS [avg_page_io_latch_wait_in_ms]
+FROM osCTE
+--WHERE os.index_id > 0 -- ignore heaps
+OPTION (MAXDOP 2);'
+
+	INSERT INTO #tmpIOS
+	EXEC sp_executesql @sqlcmd
+
+	UPDATE #tblWorking
+	SET is_done = 1
+	WHERE database_id = @dbid AND [object_id] = @objectid AND index_id = @indexid AND partition_number = @partition_nr
+END;
+
+RAISERROR (N'Gathering sys.dm_db_index_usage_stats data...', 10, 1) WITH NOWAIT
+
+UPDATE #tblDatabases
+SET is_done = 0;
+
+WHILE (SELECT COUNT(*) FROM #tblDatabases WHERE is_done = 0) > 0
+BEGIN
+	SELECT TOP 1 @dbid = database_id FROM #tblDatabases WHERE is_done = 0
+	SELECT @dbname = DB_NAME(@dbid)
+	
+	SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT s.database_id, t.name, s.[object_id], s.index_id,
+	(s.user_seeks + s.user_scans + s.user_lookups) AS [Hits],
+	RTRIM(CONVERT(NVARCHAR(20),CAST(CASE WHEN (s.user_seeks + s.user_scans + s.user_lookups) = 0 THEN 0 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups)) * 100 /
+		CASE (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates) WHEN 0 THEN 1 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates)) END END AS DECIMAL(18,2))) COLLATE database_default) AS [Reads_Ratio],
+	RTRIM(CONVERT(NVARCHAR(20),CAST(CASE WHEN s.user_updates = 0 THEN 0 ELSE CONVERT(REAL, s.user_updates) * 100 /
+		CASE (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates) WHEN 0 THEN 1 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates)) END END AS DECIMAL(18,2))) COLLATE database_default) AS [Writes_Ratio],
+	s.user_updates,
+	MAX(s.last_user_seek) AS last_user_seek,
+	MAX(s.last_user_scan) AS last_user_scan,
+	MAX(s.last_user_lookup) AS last_user_lookup,
+	MAX(s.last_user_update) AS last_user_update
+FROM sys.dm_db_index_usage_stats AS s WITH (NOLOCK)
+INNER JOIN sys.objects AS o WITH (NOLOCK) ON s.[object_id] = o.[object_id]
+INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = s.[object_id]
+INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE o.[type] = ''U''
+	AND s.database_id = ' + CONVERT(NVARCHAR(20), @dbid) + ' 
+	--AND s.index_id > 0 -- ignore heaps
+GROUP BY s.database_id, t.name, s.[object_id], s.index_id, s.user_seeks, s.user_scans, s.user_lookups, s.user_updates
+OPTION (MAXDOP 2)'
+
+	INSERT INTO #tmpIUS
+	EXECUTE sp_executesql @sqlcmd
+
+	SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], t.name, i.[object_id], i.index_id, 0, 0, 0, NULL, NULL, NULL, NULL, NULL
+FROM sys.indexes i WITH (NOLOCK)
+INNER JOIN sys.objects o WITH (NOLOCK) ON i.object_id = o.object_id 
+INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = i.[object_id]
+INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE o.[type] = ''U''
+AND i.index_id NOT IN (SELECT s.index_id
+	FROM sys.dm_db_index_usage_stats s WITH (NOLOCK)
+	WHERE s.object_id = i.object_id 
+		AND i.index_id = s.index_id 
+		AND database_id = ' + CONVERT(NVARCHAR(20), @dbid) + ')
+		AND i.name IS NOT NULL
+		AND i.index_id > 1'
+
+	INSERT INTO #tmpIUS
+	EXECUTE sp_executesql @sqlcmd
+
+	UPDATE #tblDatabases
+	SET is_done = 1
+	WHERE database_id = @dbid;
+END;
+
+IF @sqlmajorver >= 12
+BEGIN
+	RAISERROR (N'Gathering sys.dm_db_xtp_hash_index_stats and sys.dm_db_xtp_nonclustered_index_stats data...', 10, 1) WITH NOWAIT
+
+	UPDATE #tblDatabases
+	SET is_done = 0;
+
+	WHILE (SELECT COUNT(*) FROM #tblDatabases WHERE is_done = 0) > 0
+	BEGIN
+		SELECT TOP 1 @dbid = database_id FROM #tblDatabases WHERE is_done = 0
+		SELECT @dbname = DB_NAME(@dbid)
+		
+		SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], xis.[object_id], t.name, o.name, xis.index_id, si.name, 
+	xhis.total_bucket_count, xhis.empty_bucket_count, xhis.avg_chain_length, xhis.max_chain_length, 
+	xis.scans_started, xis.scans_retries, xis.rows_returned, xis.rows_touched
+FROM sys.dm_db_xtp_hash_index_stats xhis
+INNER JOIN sys.dm_db_xtp_index_stats xis ON xis.[object_id] = xhis.[object_id] AND xis.[index_id] = xhis.[index_id] 
+INNER JOIN sys.indexes AS si WITH (NOLOCK) ON xis.[object_id] = si.[object_id] AND xis.[index_id] = si.[index_id]
+INNER JOIN sys.objects AS o WITH (NOLOCK) ON si.[object_id] = o.[object_id]
+INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = o.[object_id]
+INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE o.[type] = ''U'''
+
+		INSERT INTO #tmpXIS
+		EXECUTE sp_executesql @sqlcmd
+	
+		SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id],
+	xis.[object_id], t.name, o.name, xis.index_id, si.name, 
+	xnis.delta_pages, xnis.internal_pages, xnis.leaf_pages, xnis.page_update_count,
+	xnis.page_update_retry_count, xnis.page_consolidation_count,
+	xnis.page_consolidation_retry_count, xnis.page_split_count, xnis.page_split_retry_count,
+	xnis.key_split_count, xnis.key_split_retry_count, xnis.page_merge_count, xnis.page_merge_retry_count,
+	xnis.key_merge_count, xnis.key_merge_retry_count,
+	xis.scans_started, xis.scans_retries, xis.rows_returned, xis.rows_touched
+FROM sys.dm_db_xtp_nonclustered_index_stats AS xnis WITH (NOLOCK)
+INNER JOIN sys.dm_db_xtp_index_stats AS xis WITH (NOLOCK) ON xis.[object_id] = xnis.[object_id] AND xis.[index_id] = xnis.[index_id]
+INNER JOIN sys.indexes AS si WITH (NOLOCK) ON xis.[object_id] = si.[object_id] AND xis.[index_id] = si.[index_id]
+INNER JOIN sys.objects AS o WITH (NOLOCK) ON si.[object_id] = o.[object_id]
+INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = o.[object_id]
+INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE o.[type] = ''U'''
+	
+		INSERT INTO #tmpXNCIS
+		EXECUTE sp_executesql @sqlcmd
+
+		UPDATE #tblDatabases
+		SET is_done = 1
+		WHERE database_id = @dbid;
+	END
+END;
+
+RAISERROR (N'Gathering index column data...', 10, 1) WITH NOWAIT
+
+UPDATE #tblDatabases
+SET is_done = 0;
+
+WHILE (SELECT COUNT(*) FROM #tblDatabases WHERE is_done = 0) > 0
+BEGIN
+	SELECT TOP 1 @dbid = database_id FROM #tblDatabases WHERE is_done = 0
+	SELECT @dbname = DB_NAME(@dbid)
+
+	SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], ''' + DB_NAME(@dbid) + ''' AS database_name,
+	mst.[object_id], t.name, mst.[name], 
+	mi.index_id, mi.[name], p.partition_number,
+	mi.[type], mi.[type_desc], mi.is_primary_key, mi.is_unique_constraint, mi.is_disabled, 
+	mi.fill_factor, mi.is_unique, mi.is_padded, ' + CASE WHEN @sqlmajorver > 9 THEN 'mi.has_filter, mi.filter_definition,' ELSE 'NULL, NULL,' END + '
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id] 
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
+		ORDER BY ic.key_ordinal
+	FOR XML PATH('''')), 2, 8000) AS KeyCols,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id] 
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS KeyColsOrdered,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
+		ORDER BY ic.key_ordinal
+	FOR XML PATH('''')), 2, 8000) AS IncludedCols,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS IncludedColsOrdered,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS AllColsOrdered,
+	(SELECT SUM(CASE sty.name WHEN ''nvarchar'' THEN sc.max_length/2 ELSE sc.max_length END) FROM sys.indexes AS i
+		INNER JOIN sys.tables AS t ON t.[object_id] = i.[object_id]
+		INNER JOIN sys.schemas ss ON ss.[schema_id] = t.[schema_id]
+		INNER JOIN sys.index_columns AS sic ON sic.object_id = mst.object_id AND sic.index_id = mi.index_id
+		INNER JOIN sys.columns AS sc ON sc.object_id = t.object_id AND sc.column_id = sic.column_id
+		INNER JOIN sys.types AS sty ON sc.user_type_id = sty.user_type_id
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id) AS [KeyCols_data_length_bytes]
+FROM sys.indexes AS mi
+	INNER JOIN sys.tables AS mst ON mst.[object_id] = mi.[object_id]
+	INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+	INNER JOIN sys.partitions AS p ON p.[object_id] = mi.[object_id] AND p.index_id = mi.index_id
+WHERE mi.type IN (0,1,2,5,6) AND mst.is_ms_shipped = 0
+ORDER BY mst.name
+OPTION (MAXDOP 2);'
+
+	INSERT INTO #tmpIxs
+	EXECUTE sp_executesql @sqlcmd;
+
+	IF @sqlmajorver >= 12
+	BEGIN
+		SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + DB_NAME(@dbid) + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], ''' + DB_NAME(@dbid) + ''' AS database_name,
+	mst.[object_id], t.name, mst.[name], 
+	mi.index_id, mi.[name], p.partition_number,
+	mi.[type], mi.[type_desc], mi.is_primary_key, mi.is_unique_constraint, mi.is_disabled, 
+	mi.fill_factor, mi.is_unique, mi.is_padded, mi.has_filter, mi.filter_definition,[bucket_count],
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id] 
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
+		ORDER BY ic.key_ordinal
+	FOR XML PATH('''')), 2, 8000) AS KeyCols,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id] 
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS KeyColsOrdered,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
+		ORDER BY ic.key_ordinal
+	FOR XML PATH('''')), 2, 8000) AS IncludedCols,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS IncludedColsOrdered,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS AllColsOrdered,
+	(SELECT SUM(CASE sty.name WHEN ''nvarchar'' THEN sc.max_length/2 ELSE sc.max_length END) FROM sys.hash_indexes AS i
+		INNER JOIN sys.tables AS t ON t.[object_id] = i.[object_id]
+		INNER JOIN sys.schemas ss ON ss.[schema_id] = t.[schema_id]
+		INNER JOIN sys.index_columns AS sic ON sic.object_id = mst.object_id AND sic.index_id = mi.index_id
+		INNER JOIN sys.columns AS sc ON sc.object_id = t.object_id AND sc.column_id = sic.column_id
+		INNER JOIN sys.types AS sty ON sc.user_type_id = sty.user_type_id
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id) AS [KeyCols_data_length_bytes]
+FROM sys.hash_indexes AS mi
+	INNER JOIN sys.tables AS mst ON mst.[object_id] = mi.[object_id]
+	INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+	INNER JOIN sys.partitions AS p ON p.[object_id] = mi.[object_id] AND p.index_id = mi.index_id
+WHERE mi.type IN (7) AND mst.is_ms_shipped = 0
+ORDER BY mst.name
+OPTION (MAXDOP 2);'
+
+		INSERT INTO #tmpHashIxs
+		EXECUTE sp_executesql @sqlcmd;
+	END;
+	
+	UPDATE #tblDatabases
+	SET is_done = 1
+	WHERE database_id = @dbid;
+END;
+
+RAISERROR (N'Aggregating data...', 10, 1) WITH NOWAIT
+
+INSERT INTO #tmpAgg
+SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
+	si.[schema_name], si.table_name, si.index_id, si.index_name, ISNULL(ps.partition_number, si.partition_number), 
+	ps.fragmentation, si.fill_factor, ps.page_count, ps.[size_MB], ps.record_count, ps.forwarded_record_count, -- for heaps
+	os.range_scan_count, os.singleton_lookup_count, os.forwarded_fetch_count, os.row_lock_count,
+	os.row_lock_wait_count, os.row_lock_pct, os.row_lock_wait_in_ms, os.[avg_row_lock_waits_in_ms],
+	os.page_lock_count, os.page_lock_wait_count, os.page_lock_pct, os.page_lock_wait_in_ms,
+	os.[avg_page_lock_waits_in_ms], os.[page_io_latch_wait_in_ms], os.[avg_page_io_latch_wait_in_ms],
+	s.[Hits], s.[Reads_Ratio], s.[Writes_Ratio], s.user_updates, s.last_user_seek, s.last_user_scan,
+	s.last_user_lookup, s.last_user_update, si.KeyCols, si.KeyColsOrdered, si.IncludedCols,
+	si.IncludedColsOrdered, si.AllColsOrdered, si.is_unique, si.[index_type], si.[type_desc],
+	si.is_primary_key, si.is_unique_constraint, si.is_padded, si.has_filter, si.filter_definition,
+	si.is_disabled,	si.[KeyCols_data_length_bytes]
+FROM #tmpIxs AS si
+	LEFT JOIN #tmpIPS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id] AND si.partition_number = ps.partition_number
+	LEFT JOIN #tmpIOS AS os ON os.database_id = ps.database_id AND os.index_id = ps.index_id AND os.[object_id] = ps.[object_id] AND os.partition_number = ps.partition_number
+	LEFT JOIN #tmpIUS AS s ON s.database_id = ps.database_id AND s.index_id = ps.index_id and s.[object_id] = ps.[object_id]
+--WHERE si.type > 0 -- ignore heaps
+ORDER BY database_name, [table_name], fragmentation DESC, index_id
+OPTION (MAXDOP 2);
+
+IF @sqlmajorver >= 12
+BEGIN
+	INSERT INTO #tmpAggXTPHash
+	SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
+		si.[schema_name], si.table_name, si.index_id, si.index_name, ps.total_bucket_count, ps.empty_bucket_count, 
+		ps.avg_chain_length, ps.max_chain_length, ps.scans_started, ps.scans_retries, ps.rows_returned, 
+		ps.rows_touched, si.KeyCols, si.KeyColsOrdered, si.IncludedCols, si.IncludedColsOrdered,
+		si.AllColsOrdered, si.is_unique, si.[index_type], si.[type_desc], si.is_primary_key, si.is_unique_constraint,
+		si.is_padded, si.has_filter, si.filter_definition, si.is_disabled, si.[KeyCols_data_length_bytes]	
+	FROM #tmpHashIxs AS si
+		LEFT JOIN #tmpXIS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id]
+	ORDER BY database_name, [table_name], index_id
+	OPTION (MAXDOP 2);
+
+	INSERT INTO #tmpAggXTPNC
+	SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
+		si.[schema_name], si.table_name, si.index_id, si.index_name, ps.delta_pages, ps.internal_pages, 
+		ps.leaf_pages, ps.page_update_count, ps.page_update_retry_count, 
+		ps.page_consolidation_count, ps.page_consolidation_retry_count, ps.page_split_count, 
+		ps.page_split_retry_count, ps.key_split_count, ps.key_split_retry_count, ps.page_merge_count, 
+		ps.page_merge_retry_count, ps.key_merge_count, ps.key_merge_retry_count,
+		ps.scans_started, ps.scans_retries, ps.rows_returned, ps.rows_touched,
+		si.KeyCols, si.KeyColsOrdered, si.IncludedCols, si.IncludedColsOrdered, si.AllColsOrdered,
+		si.is_unique, si.[index_type], si.[type_desc], si.is_primary_key, si.is_unique_constraint,
+		si.is_padded, si.has_filter, si.filter_definition, si.is_disabled, si.[KeyCols_data_length_bytes]	
+	FROM #tmpHashIxs AS si
+		LEFT JOIN #tmpXNCIS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id]
+	ORDER BY database_name, [table_name], index_id
+	OPTION (MAXDOP 2);
+END;
+RAISERROR (N'Output index information', 10, 1) WITH NOWAIT
+
+-- All index information
+SELECT 'All_IX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
+	[partition_number], fragmentation, fill_factor, [page_count], [size_MB], record_count, range_scan_count, singleton_lookup_count, row_lock_count, row_lock_wait_count,
+	row_lock_pct, row_lock_wait_in_ms, [avg_row_lock_waits_in_ms], page_lock_count, page_lock_wait_count,
+	page_lock_pct, page_lock_wait_in_ms, [avg_page_lock_waits_in_ms], page_io_latch_wait_in_ms, [avg_page_io_latch_wait_in_ms], [Hits],
+	CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
+	user_updates, last_user_seek, last_user_scan, last_user_lookup, last_user_update, KeyCols, IncludedCols,
+	is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter, filter_definition, KeyCols_data_length_bytes
+FROM #tmpAgg
+WHERE index_id > 0 -- ignore heaps
+ORDER BY [database_name], [schema_name], table_name, [page_count] DESC, forwarded_record_count DESC;
+
+-- All XTP index information
+IF @sqlmajorver >= 12
+BEGIN
+	SELECT 'All_XTP_HashIX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
+		total_bucket_count, empty_bucket_count, FLOOR((CAST(empty_bucket_count AS FLOAT)/total_bucket_count) * 100) AS [empty_bucket_pct], avg_chain_length, max_chain_length, 
+		scans_started, scans_retries, rows_returned, rows_touched, KeyCols, IncludedCols, is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter, 
+		filter_definition, KeyCols_data_length_bytes
+	FROM #tmpAggXTPHash
+	ORDER BY [database_name], [schema_name], table_name, [total_bucket_count] DESC;
+
+	SELECT 'All_XTP_RangeIX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
+		delta_pages, internal_pages, leaf_pages, page_update_count, page_update_retry_count, page_consolidation_count, page_consolidation_retry_count, 
+		page_split_count, page_split_retry_count, key_split_count, key_split_retry_count, page_merge_count, page_merge_retry_count, key_merge_count, key_merge_retry_count,
+		scans_started, scans_retries, rows_returned, rows_touched, KeyCols, IncludedCols, is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter, 
+		filter_definition, KeyCols_data_length_bytes
+	FROM #tmpAggXTPNC
+	ORDER BY [database_name], [schema_name], table_name, [leaf_pages] DESC;
+END;
+
+-- All Heaps information
+SELECT 'All_Heaps_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [type_desc] AS index_type,
+	[partition_number], fragmentation, [page_count], [size_MB], record_count, forwarded_record_count, forwarded_fetch_count,
+	range_scan_count, singleton_lookup_count, row_lock_count, row_lock_wait_count,
+	row_lock_pct, row_lock_wait_in_ms, [avg_row_lock_waits_in_ms], page_lock_count, page_lock_wait_count,
+	page_lock_pct, page_lock_wait_in_ms, [avg_page_lock_waits_in_ms], page_io_latch_wait_in_ms, [avg_page_io_latch_wait_in_ms]
+FROM #tmpAgg
+WHERE index_id = 0 -- only heaps
+ORDER BY [database_name], [schema_name], table_name, [page_count] DESC, forwarded_record_count DESC;
+
+-- Unused indexes that can possibly be dropped or disabled
+SELECT 'Unused_IX_With_Updates' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
+	CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
+	[page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan, 
+	last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
+FROM #tmpAgg
+WHERE [Hits] = 0 
+	AND last_user_update > 0
+	AND [type] IN (2,6)				-- non-clustered and non-clustered columnstore indexes only
+	AND is_primary_key = 0			-- no primary keys
+	AND is_unique_constraint = 0	-- no unique constraints
+	AND is_unique = 0 				-- no alternate keys
+UNION ALL
+SELECT 'Unused_IX_No_Updates' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
+	CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
+	[page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan, 
+	last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
+FROM #tmpAgg
+WHERE [Hits] = 0 
+	AND (last_user_update = 0 OR last_user_update IS NULL)
+	AND [type] IN (2,6)				-- non-clustered and non-clustered columnstore indexes only
+	AND is_primary_key = 0			-- no primary keys
+	AND is_unique_constraint = 0	-- no unique constraints
+	AND is_unique = 0 				-- no alternate keys
+ORDER BY [table_name], user_updates DESC, [page_count] DESC;
+
+-- Rarely used indexes that can possibly be dropped or disabled
+SELECT 'Rarely_Used_IX' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
+	CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
+	[page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan, 
+	last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
+FROM #tmpAgg
+WHERE [Hits] > 0 AND [Reads_Ratio] < 5
+	AND [type] IN (2,6)				-- non-clustered and non-clustered columnstore indexes only
+	AND is_primary_key = 0			-- no primary keys
+	AND is_unique_constraint = 0	-- no unique constraints
+	AND is_unique = 0 				-- no alternate keys
+ORDER BY [database_name], [table_name], [page_count] DESC;
+
+-- Duplicate Indexes
+SELECT 'Duplicate_IX' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition, 
+	I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
+FROM #tmpAgg I INNER JOIN #tmpAgg I2
+	ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+	AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
+	AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
+WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[schema_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+ORDER BY I.database_name, I.[table_name], I.[index_id];
+
+/*
+Note that it is possible that a clustered index (unique or not) is among the duplicate indexes to be dropped, 
+namely if a non-clustered primary key exists on the table.
+In this case, make the appropriate changes in the clustered index (making it unique and/or primary key in this case),
+and drop the non-clustered instead.
+*/
+SELECT 'Duplicate_IX_toDrop' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition, 
+	I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
+FROM #tmpAgg I INNER JOIN #tmpAgg I2
+	ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+	AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
+	AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
+WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I.[index_id] NOT IN (
+			SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+			(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+			(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
+			))
+GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+ORDER BY I.database_name, I.[table_name], I.[index_id];
+
+RAISERROR (N'Starting index search in sql modules...', 10, 1) WITH NOWAIT
+
+DECLARE Dup_Stats CURSOR FAST_FORWARD FOR SELECT I.database_name,I.[index_name] 
+FROM #tmpAgg I INNER JOIN #tmpAgg I2
+	ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+	AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
+	AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
+WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I.[index_id] NOT IN (
+			SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+			(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+			(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
+			))
+GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+ORDER BY I.database_name, I.[table_name], I.[index_id];
+
+OPEN Dup_Stats
+FETCH NEXT FROM Dup_Stats INTO @DatabaseName,@indexName
+WHILE (@@FETCH_STATUS = 0)
+BEGIN
+	SET @sqlcmd = 'USE [' + @DatabaseName + '];
+SELECT ''' + @DatabaseName + ''' AS [database_name], ss.name AS [schema_name], so.name AS [table_name], ''' + @indexName + ''' AS [index_name], so.type_desc
+FROM sys.sql_modules sm
+INNER JOIN sys.objects so ON sm.[object_id] = so.[object_id]
+INNER JOIN sys.schemas ss ON ss.[schema_id] = so.[schema_id]
+WHERE sm.[definition] LIKE ''%' + @indexName + '%'''
+
+	INSERT INTO #tblCode
+	EXECUTE sp_executesql @sqlcmd
+
+	FETCH NEXT FROM Dup_Stats INTO @DatabaseName,@indexName
+END
+CLOSE Dup_Stats
+DEALLOCATE Dup_Stats
+
+RAISERROR (N'Ended index search in sql modules', 10, 1) WITH NOWAIT
+
+SELECT 'Duplicate_Indexes_HardCoded' AS [Category], [DatabaseName], [schemaName], [objectName] AS [referedIn_objectName], 
+	indexName AS [referenced_indexName], type_desc AS [refered_objectType]
+FROM #tblCode
+ORDER BY [DatabaseName], [objectName];
+
+-- Redundant Indexes
+SELECT 'Redundant_IX' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_unique, I.is_padded, I.has_filter, I.filter_definition,
+	I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
+FROM #tmpAgg I INNER JOIN #tmpAgg I2
+ON I.[database_id] = I2.[database_id] AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+	AND (((I.[KeyColsOrdered] <> I2.[KeyColsOrdered] OR I.IncludedColsOrdered <> I2.IncludedColsOrdered)
+		AND ((CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END) = (CASE WHEN I2.IncludedColsOrdered IS NULL THEN I2.[KeyColsOrdered] ELSE I2.[KeyColsOrdered] + ',' + I2.IncludedColsOrdered END)
+			OR I.[AllColsOrdered] = I2.[AllColsOrdered]))
+	OR (I.[KeyColsOrdered] <> I2.[KeyColsOrdered] AND I.IncludedColsOrdered = I2.IncludedColsOrdered)
+	OR (I.[KeyColsOrdered] = I2.[KeyColsOrdered] AND I.IncludedColsOrdered <> I2.IncludedColsOrdered)
+	OR ((I.[AllColsOrdered] = I2.[AllColsOrdered] AND I.filter_definition IS NULL AND I2.filter_definition IS NOT NULL) OR (I.[AllColsOrdered] = I2.[AllColsOrdered] AND I.filter_definition IS NOT NULL AND I2.filter_definition IS NULL)))
+	AND I.[index_id] NOT IN (SELECT I3.[index_id]
+		FROM #tmpIxs I3 INNER JOIN #tmpIxs I4
+		ON I3.[database_id] = I4.[database_id] AND I3.[object_id] = I4.[object_id] AND I3.[index_id] <> I4.[index_id] 
+			AND I3.[KeyCols] = I4.[KeyCols] AND (I3.IncludedCols = I4.IncludedCols OR (I3.IncludedCols IS NULL AND I4.IncludedCols IS NULL))
+		WHERE I3.[database_id] = I.[database_id] AND I3.[object_id] = I.[object_id]
+		GROUP BY I3.[index_id])
+WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I.is_unique_constraint = 0	-- no unique constraints
+	AND I2.is_unique_constraint = 0	-- no unique constraints
+GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+ORDER BY I.database_name, I.[table_name], I.[AllColsOrdered], I.[index_id];
+
+-- Large IX Keys
+SELECT 'Large_Index_Key' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], 
+	I.KeyCols, [KeyCols_data_length_bytes]
+FROM #tmpAgg I
+WHERE [KeyCols_data_length_bytes] > 900
+ORDER BY I.[database_name], I.[schema_name], I.[table_name], I.[index_id];
+
+-- Low Fill Factor
+SELECT 'Low_Fill_Factor' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], 
+	[fill_factor], I.KeyCols, I.IncludedCols, CASE WHEN I.IncludedCols IS NULL THEN I.[KeyCols] ELSE I.[KeyCols] + ',' + I.IncludedCols END AS [AllColsOrdered]
+FROM #tmpAgg I
+WHERE [fill_factor] BETWEEN 1 AND 79
+ORDER BY I.[database_name], I.[schema_name], I.[table_name], I.[index_id];
+
+--NonUnique Clustered IXs
+SELECT 'NonUnique_CIXs' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[KeyCols]
+FROM #tmpAgg I
+WHERE [is_unique] = 0 
+	AND I.[index_id] = 1
+ORDER BY I.[database_name], I.[schema_name], I.[table_name];
+
+RAISERROR (N'Generating scripts...', 10, 1) WITH NOWAIT
+
+DECLARE @strSQL NVARCHAR(4000)
+PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
+
+IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] = 0 AND last_user_update > 0) > 0
+BEGIN
+	PRINT CHAR(10) + '--############# Existing unused indexes with updates drop statements #############' + CHAR(10)
+	DECLARE Un_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10) 
+	FROM #tmpAgg
+	WHERE [Hits] = 0 AND last_user_update > 0
+	ORDER BY [database_name], [table_name], [Reads_Ratio] DESC;
+
+	OPEN Un_Stats
+	FETCH NEXT FROM Un_Stats INTO @strSQL
+	WHILE (@@FETCH_STATUS = 0)
+	BEGIN
+		PRINT @strSQL
+		FETCH NEXT FROM Un_Stats INTO @strSQL
+	END
+	CLOSE Un_Stats
+	DEALLOCATE Un_Stats
+	PRINT CHAR(10) + '--############# Ended unused indexes with updates drop statements #############' + CHAR(10)
+END;
+
+IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] = 0 AND (last_user_update = 0 OR last_user_update IS NULL)) > 0
+BEGIN
+	PRINT CHAR(10) + '--############# Existing unused indexes with no updates drop statements #############' + CHAR(10)
+	DECLARE Un_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10) 
+	FROM #tmpAgg
+	WHERE [Hits] = 0 AND (last_user_update = 0 OR last_user_update IS NULL)
+	ORDER BY [database_name], [table_name], [Reads_Ratio] DESC;
+
+	OPEN Un_Stats
+	FETCH NEXT FROM Un_Stats INTO @strSQL
+	WHILE (@@FETCH_STATUS = 0)
+	BEGIN
+		PRINT @strSQL
+		FETCH NEXT FROM Un_Stats INTO @strSQL
+	END
+	CLOSE Un_Stats
+	DEALLOCATE Un_Stats
+	PRINT CHAR(10) + '--############# Ended unused indexes with no updates drop statements #############' + CHAR(10)
+END;
+
+IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] > 0 AND [Reads_Ratio] < 5) > 0
+BEGIN
+	PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
+	PRINT CHAR(10) + '--############# Existing rarely used indexes drop statements #############' + CHAR(10)
+	DECLARE curRarUsed CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10) 
+	FROM #tmpAgg
+	WHERE [Hits] > 0 AND [Reads_Ratio] < 5
+	ORDER BY [database_name], [table_name], [Reads_Ratio] DESC
+
+	OPEN curRarUsed
+	FETCH NEXT FROM curRarUsed INTO @strSQL
+	WHILE (@@FETCH_STATUS = 0)
+	BEGIN
+		PRINT @strSQL
+		FETCH NEXT FROM curRarUsed INTO @strSQL
+	END
+	CLOSE curRarUsed
+	DEALLOCATE curRarUsed
+	PRINT '--############# Ended rarely used indexes drop statements #############' + CHAR(10)
+END;
+
+PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
+PRINT CHAR(10) + '/*
+NOTE: It is possible that a clustered index (unique or not) is among the duplicate indexes to be dropped, namely if a non-clustered primary key exists on the table.
+In this case, make the appropriate changes in the clustered index (making it unique and/or primary key in this case), and drop the non-clustered instead.
+*/'
+PRINT CHAR(10) + '--############# Existing Duplicate indexes drop statements #############' + CHAR(10)
+DECLARE Dup_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + I.[database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ I.[index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME(I.[index_name]) + ' ON ' + QUOTENAME(I.[schema_name]) + '.' + QUOTENAME(I.[table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10) 
+	FROM #tmpAgg I INNER JOIN #tmpAgg I2
+		ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+		AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
+		AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
+	WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+		AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+		AND I.[index_id] NOT IN (
+				SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+				WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+					AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+					AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
+				GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+				(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+				WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+					AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+					AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
+				GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+				(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+				WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+					AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
+				))
+	GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+	ORDER BY I.database_name, I.[table_name], I.[index_id];
+OPEN Dup_Stats
+FETCH NEXT FROM Dup_Stats INTO @strSQL
+WHILE (@@FETCH_STATUS = 0)
+BEGIN
+	PRINT @strSQL
+	FETCH NEXT FROM Dup_Stats INTO @strSQL
+END
+CLOSE Dup_Stats
+DEALLOCATE Dup_Stats
+PRINT '--############# Ended Duplicate indexes drop statements #############' + CHAR(10)
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
+DROP TABLE #tmpIPS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
+DROP TABLE #tmpIOS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
+DROP TABLE #tmpIUS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
+DROP TABLE #tmpXIS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
+DROP TABLE #tmpXNCIS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
+DROP TABLE #tmpIxs;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
+DROP TABLE #tmpHashIxs;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
+DROP TABLE #tmpAgg;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
+DROP TABLE #tmpAggXTPHash;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
+DROP TABLE #tmpAggXTPNC;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
+DROP TABLE #tblWorking;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
+DROP TABLE #tblCode;
+GO

+ 1123 - 0
Index-Information/view_IndexInformation_CurrentDB.sql

@@ -0,0 +1,1123 @@
+-- 2012-03-19 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/ezequiel)
+--
+-- All Databases index info, including duplicate, redundant, rarely used and unused indexes.
+--
+-- 4/5/2012		Simplified execution by subdividing input queries
+-- 4/5/2012		Fixed some collation issues;
+-- 4/6/2012		Split in separate listings the unused indexes from rarely used indexes; Split in separate list
+-- 6/6/2012		Fixed issue with partition aligned indexes
+-- 10/31/2012	Widened search for Redundant Indexes
+-- 12/17/2012	Fixed several issues
+-- 1/17/2013	Added several index related info
+-- 2/1/2013		Fixed issue with Heap identification
+-- 2/26/2013	Fixed issue with partition info; Removed alternate keys from search for Unused and Rarely used
+-- 4/17/2013	Added more information to duplicate and redundant indexes output, valuable when deciding which
+-- 4/19/2013	Fixed issue with potential duplicate index_ids in sys.dm_db_index_operational_stats relating t
+-- 5/6/2013		Changed data collection to minimize blocking potential on VLDBs.
+-- 5/20/2013	Fixed issue with database names with special characters.
+-- 5/29/2013	Fixed issue with large integers in aggregation.
+-- 6/20/2013	Added step to avoid entering in loop that generates dump in SQL 2005.
+-- 11/10/2013	Added index checks.
+-- 2/24/2014	Added info to Unused_IX section.
+-- 6/4/2014		Refined search for duplicate and redundant indexes.
+-- 11/12/2014	Added SQL 2014 Hash indexes support; changed scan mode to LIMITED; added search for hard coded
+-- 11/2/2016	Added support for SQL Server 2016 sys.dm_db_index_operational_stats changes; Added script creation.
+/*
+NOTE: on SQL Server 2005, be aware that querying sys.dm_db_index_usage_stats when it has large number of rows may lead to performance issues.
+URL: http://support.microsoft.com/kb/2003031
+*/
+
+SET NOCOUNT ON;
+
+DECLARE @UpTime VARCHAR(12), @StartDate DATETIME, @sqlmajorver int, @sqlcmd NVARCHAR(4000), @params NVARCHAR(500)
+DECLARE @DatabaseName sysname, @indexName sysname
+SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
+
+IF @sqlmajorver = 9
+BEGIN
+	SET @sqlcmd = N'SELECT @StartDateOUT = login_time, @UpTimeOUT = DATEDIFF(mi, login_time, GETDATE()) FROM master..sysprocesses WHERE spid = 1';
+END
+ELSE
+BEGIN
+	SET @sqlcmd = N'SELECT @StartDateOUT = sqlserver_start_time, @UpTimeOUT = DATEDIFF(mi,sqlserver_start_time,GETDATE()) FROM sys.dm_os_sys_info';
+END
+
+SET @params = N'@StartDateOUT DATETIME OUTPUT, @UpTimeOUT VARCHAR(12) OUTPUT';
+
+EXECUTE sp_executesql @sqlcmd, @params, @StartDateOUT=@StartDate OUTPUT, @UpTimeOUT=@UpTime OUTPUT;
+
+SELECT @StartDate AS Collecting_Data_Since, CONVERT(VARCHAR(4),@UpTime/60/24) + 'd ' + CONVERT(VARCHAR(4),@UpTime/60%24) + 'h ' + CONVERT(VARCHAR(4),@UpTime%60) + 'm' AS Collecting_Data_For
+
+RAISERROR (N'Starting...', 10, 1) WITH NOWAIT
+
+DECLARE @dbid int, @dbname NVARCHAR(255)--, @sqlcmd NVARCHAR(4000)
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblDatabases'))
+DROP TABLE #tblDatabases;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblDatabases'))
+CREATE TABLE #tblDatabases (database_id int PRIMARY KEY, is_done bit)
+
+SET @dbid = DB_ID()
+SELECT @dbname = DB_NAME()
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
+DROP TABLE #tblWorking;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
+CREATE TABLE #tblWorking (database_id int, [object_id] int, [object_name] NVARCHAR(255), index_id int, index_name NVARCHAR(255), [schema_name] NVARCHAR(255), partition_number int, is_done bit)
+
+RAISERROR (N'Populating support tables...', 10, 1) WITH NOWAIT
+
+SELECT @sqlcmd = 'USE [' + @dbname + '];
+SELECT DISTINCT ' + CONVERT(NVARCHAR(255), @dbid) + ', si.[object_id], mst.[name], si.index_id, si.name, t.name, sp.partition_number, 0
+FROM sys.indexes si
+INNER JOIN sys.partitions sp ON si.[object_id] = sp.[object_id] AND si.index_id = sp.index_id
+INNER JOIN sys.tables AS mst ON mst.[object_id] = si.[object_id]
+INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+WHERE mst.is_ms_shipped = 0'
+
+INSERT INTO #tblWorking
+EXEC sp_executesql @sqlcmd;
+
+--------------------------------------------------------
+-- Index physical and usage stats
+--------------------------------------------------------
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
+DROP TABLE #tmpIPS;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
+CREATE TABLE #tmpIPS (
+	[database_id] int,
+	[object_id] int,
+	[index_id] int,
+	[partition_number] int,
+	fragmentation DECIMAL(18,3),
+	[page_count] bigint,
+	[size_MB] DECIMAL(26,3),
+	record_count int,
+	forwarded_record_count int NULL,
+	CONSTRAINT PK_IPS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]))
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
+DROP TABLE #tmpIOS;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
+CREATE TABLE #tmpIOS (
+	[database_id] int,
+	[object_id] int,
+	[index_id] int,
+	[partition_number] int,
+	range_scan_count bigint NULL,
+	singleton_lookup_count bigint NULL,
+	forwarded_fetch_count bigint NULL,
+	row_lock_count bigint NULL,
+	row_lock_wait_count bigint NULL,
+	row_lock_pct NUMERIC(15,2) NULL,
+	row_lock_wait_in_ms bigint NULL,
+	[avg_row_lock_waits_in_ms] NUMERIC(15,2) NULL,
+	page_lock_count bigint NULL,
+	page_lock_wait_count bigint NULL,
+	page_lock_pct NUMERIC(15,2) NULL,
+	page_lock_wait_in_ms bigint NULL,
+	[avg_page_lock_waits_in_ms] NUMERIC(15,2) NULL,
+	page_io_latch_wait_in_ms bigint NULL,
+	[avg_page_io_latch_wait_in_ms] NUMERIC(15,2) NULL
+	CONSTRAINT PK_IOS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
+DROP TABLE #tmpIUS;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
+CREATE TABLE #tmpIUS (
+	[database_id] int,
+	[schema_name] VARCHAR(100) COLLATE database_default,
+	[object_id] int,
+	[index_id] int,
+	[Hits] bigint NULL,
+	[Reads_Ratio] DECIMAL(5,2),
+	[Writes_Ratio] DECIMAL(5,2),
+	user_updates bigint,
+	last_user_seek DATETIME NULL,
+	last_user_scan DATETIME NULL,
+	last_user_lookup DATETIME NULL,
+	last_user_update DATETIME NULL
+	CONSTRAINT PK_IUS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
+DROP TABLE #tmpIxs;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
+CREATE TABLE #tmpIxs (
+	[database_id] int, 
+	[database_name] VARCHAR(500), 
+	[object_id] int, 
+	[schema_name] VARCHAR(100) COLLATE database_default, 
+	[table_name] VARCHAR(300) COLLATE database_default, 
+	[index_id] int, 
+	[index_name] VARCHAR(300) COLLATE database_default,
+	[partition_number] int,
+	[index_type] tinyint,
+	type_desc NVARCHAR(30),
+	is_primary_key bit,
+	is_unique_constraint bit,
+	is_disabled bit,
+	fill_factor tinyint, 
+	is_unique bit, 
+	is_padded bit, 
+	has_filter bit,
+	filter_definition NVARCHAR(max),
+	KeyCols VARCHAR(4000), 
+	KeyColsOrdered VARCHAR(4000), 
+	IncludedCols VARCHAR(4000) NULL, 
+	IncludedColsOrdered VARCHAR(4000) NULL, 
+	AllColsOrdered VARCHAR(4000) NULL,
+	[KeyCols_data_length_bytes] int,
+	CONSTRAINT PK_Ixs PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
+DROP TABLE #tmpAgg;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
+CREATE TABLE #tmpAgg (
+	[database_id] int,
+	[database_name] sysname,
+	[object_id] int,
+	[schema_name] VARCHAR(100) COLLATE database_default,
+	[table_name] VARCHAR(300) COLLATE database_default,
+	[index_id] int,
+	[index_name] VARCHAR(300) COLLATE database_default,
+	[partition_number] int,
+	fragmentation DECIMAL(18,3),
+	fill_factor tinyint,
+	[page_count] bigint,
+	[size_MB] DECIMAL(26,3),
+	record_count bigint, 
+	forwarded_record_count bigint NULL,
+	range_scan_count bigint NULL,
+	singleton_lookup_count bigint NULL,
+	forwarded_fetch_count bigint NULL,
+	row_lock_count bigint NULL,
+	row_lock_wait_count bigint NULL,
+	row_lock_pct NUMERIC(15,2) NULL,
+	row_lock_wait_in_ms bigint NULL,
+	[avg_row_lock_waits_in_ms] NUMERIC(15,2) NULL,
+	page_lock_count bigint NULL,
+	page_lock_wait_count bigint NULL,
+	page_lock_pct NUMERIC(15,2) NULL,
+	page_lock_wait_in_ms bigint NULL,
+	[avg_page_lock_waits_in_ms] NUMERIC(15,2) NULL,
+	page_io_latch_wait_in_ms bigint NULL,
+	[avg_page_io_latch_wait_in_ms] NUMERIC(15,2) NULL,
+	[Hits] bigint NULL,
+	[Reads_Ratio] DECIMAL(5,2),
+	[Writes_Ratio] DECIMAL(5,2),
+	user_updates bigint,
+	last_user_seek DATETIME NULL,
+	last_user_scan DATETIME NULL,
+	last_user_lookup DATETIME NULL,
+	last_user_update DATETIME NULL,
+	KeyCols VARCHAR(4000) COLLATE database_default,
+	KeyColsOrdered VARCHAR(4000) COLLATE database_default,
+	IncludedCols VARCHAR(4000) COLLATE database_default NULL,
+	IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL, 
+	AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
+	is_unique bit,
+	[type] tinyint,
+	type_desc NVARCHAR(30),
+	is_primary_key bit,
+	is_unique_constraint bit,
+	is_padded bit, 
+	has_filter bit, 
+	filter_definition NVARCHAR(max),
+	is_disabled bit,
+	[KeyCols_data_length_bytes] int,	
+	CONSTRAINT PK_tmpIxs PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
+DROP TABLE #tblCode;
+IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
+CREATE TABLE #tblCode (
+	[DatabaseName] sysname, 
+	[schemaName] VARCHAR(100), 
+	[objectName] VARCHAR(200), 
+	[indexName] VARCHAR(200), 
+	type_desc NVARCHAR(60));
+
+IF @sqlmajorver >= 12
+BEGIN
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
+	DROP TABLE #tmpXIS;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
+	CREATE TABLE #tmpXIS (
+		[database_id] int,
+		[object_id] int,
+		[schema_name] VARCHAR(100) COLLATE database_default,
+		[table_name] VARCHAR(300) COLLATE database_default,
+		[index_id] int,
+		[index_name] VARCHAR(300) COLLATE database_default,
+		total_bucket_count bigint, 
+		empty_bucket_count bigint, 
+		avg_chain_length bigint, 
+		max_chain_length bigint, 
+		scans_started bigint, 
+		scans_retries bigint, 
+		rows_returned bigint, 
+		rows_touched bigint,
+		CONSTRAINT PK_tmpXIS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
+	DROP TABLE #tmpXNCIS;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
+	CREATE TABLE #tmpXNCIS (
+		[database_id] int,
+		[object_id] int,
+		[schema_name] VARCHAR(100) COLLATE database_default,
+		[table_name] VARCHAR(300) COLLATE database_default,
+		[index_id] int,
+		[index_name] VARCHAR(300) COLLATE database_default,
+		delta_pages bigint, 
+		internal_pages bigint, 
+		leaf_pages bigint, 
+		page_update_count bigint,
+		page_update_retry_count bigint, 
+		page_consolidation_count bigint,
+		page_consolidation_retry_count bigint, 
+		page_split_count bigint, 
+		page_split_retry_count bigint,
+		key_split_count bigint, 
+		key_split_retry_count bigint, 
+		page_merge_count bigint, 
+		page_merge_retry_count bigint,
+		key_merge_count bigint, 
+		key_merge_retry_count bigint, 
+		scans_started bigint, 
+		scans_retries bigint, 
+		rows_returned bigint, 
+		rows_touched bigint,
+		CONSTRAINT PK_tmpXNCIS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
+	DROP TABLE #tmpAggXTPHash;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
+	CREATE TABLE #tmpAggXTPHash (
+		[database_id] int,
+		[database_name] sysname,
+		[object_id] int,
+		[schema_name] VARCHAR(100) COLLATE database_default,
+		[table_name] VARCHAR(300) COLLATE database_default,
+		[index_id] int,
+		[index_name] VARCHAR(300) COLLATE database_default,
+		total_bucket_count bigint, 
+		empty_bucket_count bigint, 
+		avg_chain_length bigint, 
+		max_chain_length bigint, 
+		scans_started bigint, 
+		scans_retries bigint, 
+		rows_returned bigint, 
+		rows_touched bigint,
+		KeyCols VARCHAR(4000) COLLATE database_default,
+		KeyColsOrdered VARCHAR(4000) COLLATE database_default,
+		IncludedCols VARCHAR(4000) COLLATE database_default NULL,
+		IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL, 
+		AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
+		is_unique bit,
+		[type] tinyint,
+		type_desc NVARCHAR(30),
+		is_primary_key bit,
+		is_unique_constraint bit,
+		is_padded bit, 
+		has_filter bit, 
+		filter_definition NVARCHAR(max),
+		is_disabled bit,
+		[KeyCols_data_length_bytes] int,	
+		CONSTRAINT PK_tmpAggXTPHash PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
+	DROP TABLE #tmpAggXTPNC;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
+	CREATE TABLE #tmpAggXTPNC (
+		[database_id] int,
+		[database_name] sysname,
+		[object_id] int,
+		[schema_name] VARCHAR(100) COLLATE database_default,
+		[table_name] VARCHAR(300) COLLATE database_default,
+		[index_id] int,
+		[index_name] VARCHAR(300) COLLATE database_default,
+		delta_pages bigint, 
+		internal_pages bigint, 
+		leaf_pages bigint, 
+		page_update_count bigint,
+		page_update_retry_count bigint, 
+		page_consolidation_count bigint,
+		page_consolidation_retry_count bigint, 
+		page_split_count bigint, 
+		page_split_retry_count bigint,
+		key_split_count bigint, 
+		key_split_retry_count bigint, 
+		page_merge_count bigint, 
+		page_merge_retry_count bigint,
+		key_merge_count bigint, 
+		key_merge_retry_count bigint, 
+		scans_started bigint, 
+		scans_retries bigint, 
+		rows_returned bigint, 
+		rows_touched bigint,
+		KeyCols VARCHAR(4000) COLLATE database_default,
+		KeyColsOrdered VARCHAR(4000) COLLATE database_default,
+		IncludedCols VARCHAR(4000) COLLATE database_default NULL,
+		IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL, 
+		AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
+		is_unique bit,
+		[type] tinyint,
+		type_desc NVARCHAR(30),
+		is_primary_key bit,
+		is_unique_constraint bit,
+		is_padded bit,
+		has_filter bit,
+		filter_definition NVARCHAR(max),
+		is_disabled bit,
+		[KeyCols_data_length_bytes] int,	
+		CONSTRAINT PK_tmpAggXTPNC PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
+
+	IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
+	DROP TABLE #tmpHashIxs;
+	IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
+	CREATE TABLE #tmpHashIxs (
+		[database_id] int, 
+		[database_name] VARCHAR(500), 
+		[object_id] int, 
+		[schema_name] VARCHAR(100) COLLATE database_default, 
+		[table_name] VARCHAR(300) COLLATE database_default, 
+		[index_id] int, 
+		[index_name] VARCHAR(300) COLLATE database_default,
+		[partition_number] int,
+		[index_type] tinyint,
+		type_desc NVARCHAR(30),
+		is_primary_key bit,
+		is_unique_constraint bit,
+		is_disabled bit,
+		fill_factor tinyint, 
+		is_unique bit, 
+		is_padded bit, 
+		has_filter bit,
+		filter_definition NVARCHAR(max),
+		[bucket_count] bigint,
+		KeyCols VARCHAR(4000), 
+		KeyColsOrdered VARCHAR(4000), 
+		IncludedCols VARCHAR(4000) NULL, 
+		IncludedColsOrdered VARCHAR(4000) NULL, 
+		AllColsOrdered VARCHAR(4000) NULL,
+		[KeyCols_data_length_bytes] int,
+		CONSTRAINT PK_HashIxs PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
+END;
+
+DECLARE /*@dbid int, */@objectid int, @indexid int, @partition_nr int, /*@dbname NVARCHAR(255),*/ @oname NVARCHAR(255), @iname NVARCHAR(255), @sname NVARCHAR(255)
+
+RAISERROR (N'Gathering sys.dm_db_index_physical_stats and sys.dm_db_index_operational_stats data...', 10, 1) WITH NOWAIT
+
+WHILE (SELECT COUNT(*) FROM #tblWorking WHERE is_done = 0) > 0
+BEGIN
+	SELECT TOP 1 @objectid = [object_id], @indexid = index_id, @partition_nr = partition_number, @oname = [object_name], @iname = index_name, @sname = [schema_name]
+	FROM #tblWorking WHERE is_done = 0
+
+	INSERT INTO #tmpIPS
+	SELECT ps.database_id, 
+		ps.[object_id], 
+		ps.index_id, 
+		ps.partition_number, 
+		SUM(ps.avg_fragmentation_in_percent),
+		SUM(ps.page_count),
+		CAST((SUM(ps.page_count)*8)/1024 AS DECIMAL(26,3)) AS [size_MB],
+		SUM(ISNULL(ps.record_count,0)),
+		SUM(ISNULL(ps.forwarded_record_count,0)) -- for heaps
+	FROM sys.dm_db_index_physical_stats(@dbid, @objectid, @indexid , @partition_nr, 'SAMPLED') AS ps
+	WHERE /*ps.index_id > 0 -- ignore heaps
+		AND */ps.index_level = 0 -- leaf-level nodes only
+		AND ps.alloc_unit_type_desc = 'IN_ROW_DATA'
+	GROUP BY ps.database_id, ps.[object_id], ps.index_id, ps.partition_number
+	OPTION (MAXDOP 2);
+
+	-- Avoid entering in loop that generates dump in SQL 2005
+	IF @sqlmajorver = 9
+	BEGIN
+		SET @sqlcmd = (SELECT 'USE [' + @dbname + '];
+UPDATE STATISTICS ' + QUOTENAME(@sname) + '.' + QUOTENAME(@oname) + CASE WHEN @iname IS NULL THEN '' ELSE ' (' + QUOTENAME(@iname) + ')' END)
+		EXEC sp_executesql @sqlcmd
+	END;
+
+	SET @sqlcmd = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+WITH osCTE (database_id, [object_id], index_id, partition_number, range_scan_count, singleton_lookup_count, 
+	forwarded_fetch_count, row_lock_count, row_lock_wait_count, row_lock_wait_in_ms, page_lock_count, 
+	page_lock_wait_count, page_lock_wait_in_ms, page_io_latch_wait_count, page_io_latch_wait_in_ms)
+AS (SELECT os.database_id, 
+	os.[object_id], 
+	os.index_id,
+	os.partition_number, 
+	SUM(os.range_scan_count), 
+	SUM(os.singleton_lookup_count),
+	SUM(os.forwarded_fetch_count),
+	SUM(os.row_lock_count),
+	SUM(os.row_lock_wait_count),
+	SUM(os.row_lock_wait_in_ms),
+	SUM(os.page_lock_count),
+	SUM(os.page_lock_wait_count),
+	SUM(os.page_lock_wait_in_ms),
+	SUM(os.page_io_latch_wait_count),
+	SUM(os.page_io_latch_wait_in_ms)
+FROM sys.dm_db_index_operational_stats(' + CONVERT(NVARCHAR(20), @dbid) + ', ' + CONVERT(NVARCHAR(20), @objectid) + ', ' + CONVERT(NVARCHAR(20), @indexid) + ', ' + CONVERT(NVARCHAR(20), @partition_nr) + ') AS os
+INNER JOIN sys.objects AS o WITH (NOLOCK) ON os.[object_id] = o.[object_id]
+' + CASE WHEN @sqlmajorver >= 13 THEN 'LEFT JOIN sys.internal_partitions AS ip WITH (NOLOCK) ON os.hobt_id = ip.hobt_id AND ip.internal_object_type IN (2,3)' ELSE '' END + '
+WHERE o.[type] = ''U''
+GROUP BY os.database_id, os.[object_id], os.index_id, os.partition_number
+)
+SELECT osCTE.database_id, 
+	osCTE.[object_id], 
+	osCTE.index_id,
+	osCTE.partition_number, 
+	osCTE.range_scan_count, 
+	osCTE.singleton_lookup_count,
+	osCTE.forwarded_fetch_count,
+	osCTE.row_lock_count,
+	osCTE.row_lock_wait_count,
+	CAST(100.0 * osCTE.row_lock_wait_count / (1 + osCTE.row_lock_count) AS numeric(15,2)) AS row_lock_pct,
+	osCTE.row_lock_wait_in_ms,
+	CAST(1.0 * osCTE.row_lock_wait_in_ms / (1 + osCTE.row_lock_wait_count) AS numeric(15,2)) AS [avg_row_lock_waits_in_ms],
+	osCTE.page_lock_count,
+	osCTE.page_lock_wait_count,
+	CAST(100.0 * osCTE.page_lock_wait_count / (1 + osCTE.page_lock_count) AS numeric(15,2)) AS page_lock_pct,
+	osCTE.page_lock_wait_in_ms,
+	CAST(1.0 * osCTE.page_lock_wait_in_ms / (1 + osCTE.page_lock_wait_count) AS numeric(15,2)) AS [avg_page_lock_waits_in_ms],
+	osCTE.page_io_latch_wait_in_ms,
+	CAST(1.0 * osCTE.page_io_latch_wait_in_ms / (1 + osCTE.page_io_latch_wait_count) AS numeric(15,2)) AS [avg_page_io_latch_wait_in_ms]
+FROM osCTE
+--WHERE os.index_id > 0 -- ignore heaps
+OPTION (MAXDOP 2);'
+
+	INSERT INTO #tmpIOS
+	EXEC sp_executesql @sqlcmd
+
+	UPDATE #tblWorking
+	SET is_done = 1
+	WHERE [object_id] = @objectid AND index_id = @indexid AND partition_number = @partition_nr
+END;
+
+IF @sqlmajorver >= 12
+BEGIN
+	RAISERROR (N'Gathering sys.dm_db_xtp_hash_index_stats and sys.dm_db_xtp_nonclustered_index_stats data...', 10, 1) WITH NOWAIT
+
+	SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], xis.[object_id], t.name, o.name, xis.index_id, si.name, 
+	xhis.total_bucket_count, xhis.empty_bucket_count, xhis.avg_chain_length, xhis.max_chain_length, 
+	xis.scans_started, xis.scans_retries, xis.rows_returned, xis.rows_touched
+FROM sys.dm_db_xtp_hash_index_stats xhis
+INNER JOIN sys.dm_db_xtp_index_stats xis ON xis.[object_id] = xhis.[object_id] AND xis.[index_id] = xhis.[index_id] 
+INNER JOIN sys.indexes AS si WITH (NOLOCK) ON xis.[object_id] = si.[object_id] AND xis.[index_id] = si.[index_id]
+INNER JOIN sys.objects AS o WITH (NOLOCK) ON si.[object_id] = o.[object_id]
+INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = o.[object_id]
+INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE o.[type] = ''U'''
+
+	INSERT INTO #tmpXIS
+	EXECUTE sp_executesql @sqlcmd
+
+	SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id],
+	xis.[object_id], t.name, o.name, xis.index_id, si.name, 
+	xnis.delta_pages, xnis.internal_pages, xnis.leaf_pages, xnis.page_update_count,
+	xnis.page_update_retry_count, xnis.page_consolidation_count,
+	xnis.page_consolidation_retry_count, xnis.page_split_count, xnis.page_split_retry_count,
+	xnis.key_split_count, xnis.key_split_retry_count, xnis.page_merge_count, xnis.page_merge_retry_count,
+	xnis.key_merge_count, xnis.key_merge_retry_count,
+	xis.scans_started, xis.scans_retries, xis.rows_returned, xis.rows_touched
+FROM sys.dm_db_xtp_nonclustered_index_stats AS xnis WITH (NOLOCK)
+INNER JOIN sys.dm_db_xtp_index_stats AS xis WITH (NOLOCK) ON xis.[object_id] = xnis.[object_id] AND xis.[index_id] = xnis.[index_id]
+INNER JOIN sys.indexes AS si WITH (NOLOCK) ON xis.[object_id] = si.[object_id] AND xis.[index_id] = si.[index_id]
+INNER JOIN sys.objects AS o WITH (NOLOCK) ON si.[object_id] = o.[object_id]
+INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = o.[object_id]
+INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE o.[type] = ''U'''
+	
+	INSERT INTO #tmpXNCIS
+	EXECUTE sp_executesql @sqlcmd
+END;
+	
+RAISERROR (N'Gathering sys.dm_db_index_usage_stats data...', 10, 1) WITH NOWAIT
+
+SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT s.database_id, t.name, s.[object_id], s.index_id,
+	(s.user_seeks + s.user_scans + s.user_lookups) AS [Hits],
+	RTRIM(CONVERT(NVARCHAR(20),CAST(CASE WHEN (s.user_seeks + s.user_scans + s.user_lookups) = 0 THEN 0 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups)) * 100 /
+		CASE (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates) WHEN 0 THEN 1 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates)) END END AS DECIMAL(18,2))) COLLATE database_default) AS [Reads_Ratio],
+	RTRIM(CONVERT(NVARCHAR(20),CAST(CASE WHEN s.user_updates = 0 THEN 0 ELSE CONVERT(REAL, s.user_updates) * 100 /
+		CASE (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates) WHEN 0 THEN 1 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates)) END END AS DECIMAL(18,2))) COLLATE database_default) AS [Writes_Ratio],
+	s.user_updates,
+	MAX(s.last_user_seek) AS last_user_seek,
+	MAX(s.last_user_scan) AS last_user_scan,
+	MAX(s.last_user_lookup) AS last_user_lookup,
+	MAX(s.last_user_update) AS last_user_update
+FROM sys.dm_db_index_usage_stats AS s WITH (NOLOCK)
+INNER JOIN sys.objects AS o WITH (NOLOCK) ON s.[object_id] = o.[object_id]
+INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = s.[object_id]
+INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE o.[type] = ''U''
+	AND s.database_id = ' + CONVERT(NVARCHAR(20), @dbid) + ' 
+	--AND s.index_id > 0 -- ignore heaps
+GROUP BY s.database_id, t.name, s.[object_id], s.index_id, s.user_seeks, s.user_scans, s.user_lookups, s.user_updates
+OPTION (MAXDOP 2)'
+
+INSERT INTO #tmpIUS
+EXECUTE sp_executesql @sqlcmd
+
+SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], t.name, i.[object_id], i.index_id, 0, 0, 0, NULL, NULL, NULL, NULL, NULL
+FROM sys.indexes i WITH (NOLOCK)
+INNER JOIN sys.objects o WITH (NOLOCK) ON i.object_id = o.object_id 
+INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = i.[object_id]
+INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
+WHERE o.[type] = ''U'' 
+	AND i.index_id NOT IN (SELECT s.index_id
+	FROM sys.dm_db_index_usage_stats s WITH (NOLOCK)
+	WHERE s.object_id = i.object_id 
+		AND i.index_id = s.index_id 
+		AND database_id = ' + CONVERT(NVARCHAR(20), @dbid) + ')
+		AND i.name IS NOT NULL
+		AND i.index_id > 1'
+
+INSERT INTO #tmpIUS
+EXECUTE sp_executesql @sqlcmd
+
+RAISERROR (N'Gathering index column data...', 10, 1) WITH NOWAIT
+
+SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], ''' + @dbname + ''' AS database_name,
+	mst.[object_id], t.name, mst.[name], 
+	mi.index_id, mi.[name], p.partition_number,
+	mi.[type], mi.[type_desc], mi.is_primary_key, mi.is_unique_constraint, mi.is_disabled, 
+	mi.fill_factor, mi.is_unique, mi.is_padded, ' + CASE WHEN @sqlmajorver > 9 THEN 'mi.has_filter, mi.filter_definition,' ELSE 'NULL, NULL,' END + '
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id] 
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
+		ORDER BY ic.key_ordinal
+	FOR XML PATH('''')), 2, 8000) AS KeyCols,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id] 
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS KeyColsOrdered,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
+		ORDER BY ic.key_ordinal
+	FOR XML PATH('''')), 2, 8000) AS IncludedCols,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS IncludedColsOrdered,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS AllColsOrdered,
+	(SELECT SUM(CASE sty.name WHEN ''nvarchar'' THEN sc.max_length/2 ELSE sc.max_length END) FROM sys.indexes AS i
+		INNER JOIN sys.tables AS t ON t.[object_id] = i.[object_id]
+		INNER JOIN sys.schemas ss ON ss.[schema_id] = t.[schema_id]
+		INNER JOIN sys.index_columns AS sic ON sic.object_id = mst.object_id AND sic.index_id = mi.index_id
+		INNER JOIN sys.columns AS sc ON sc.object_id = t.object_id AND sc.column_id = sic.column_id
+		INNER JOIN sys.types AS sty ON sc.user_type_id = sty.user_type_id
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id) AS [KeyCols_data_length_bytes]
+FROM sys.indexes AS mi 
+	INNER JOIN sys.tables AS mst ON mst.[object_id] = mi.[object_id]
+	INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+	INNER JOIN sys.partitions AS p ON p.[object_id] = mi.[object_id] AND p.index_id = mi.index_id
+WHERE mi.type IN (0,1,2,5,6) AND mst.is_ms_shipped = 0
+OPTION (MAXDOP 2);'
+
+INSERT INTO #tmpIxs
+EXECUTE sp_executesql @sqlcmd;
+
+IF @sqlmajorver >= 12
+BEGIN
+	SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
+USE [' + @dbname + '];
+SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], ''' + @dbname + ''' AS database_name,
+	mst.[object_id], t.name, mst.[name], 
+	mi.index_id, mi.[name], p.partition_number,
+	mi.[type], mi.[type_desc], mi.is_primary_key, mi.is_unique_constraint, mi.is_disabled, 
+	mi.fill_factor, mi.is_unique, mi.is_padded, mi.has_filter, mi.filter_definition,[bucket_count],
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id] 
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
+		ORDER BY ic.key_ordinal
+	FOR XML PATH('''')), 2, 8000) AS KeyCols,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id] 
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS KeyColsOrdered,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
+		ORDER BY ic.key_ordinal
+	FOR XML PATH('''')), 2, 8000) AS IncludedCols,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS IncludedColsOrdered,
+	SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
+		INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
+		INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
+		INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id
+		ORDER BY ac.name
+	FOR XML PATH('''')), 2, 8000) AS AllColsOrdered,
+	(SELECT SUM(CASE sty.name WHEN ''nvarchar'' THEN sc.max_length/2 ELSE sc.max_length END) FROM sys.hash_indexes AS i
+		INNER JOIN sys.tables AS t ON t.[object_id] = i.[object_id]
+		INNER JOIN sys.schemas ss ON ss.[schema_id] = t.[schema_id]
+		INNER JOIN sys.index_columns AS sic ON sic.object_id = mst.object_id AND sic.index_id = mi.index_id
+		INNER JOIN sys.columns AS sc ON sc.object_id = t.object_id AND sc.column_id = sic.column_id
+		INNER JOIN sys.types AS sty ON sc.user_type_id = sty.user_type_id
+		WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id) AS [KeyCols_data_length_bytes]
+FROM sys.hash_indexes AS mi
+	INNER JOIN sys.tables AS mst ON mst.[object_id] = mi.[object_id]
+	INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+	INNER JOIN sys.partitions AS p ON p.[object_id] = mi.[object_id] AND p.index_id = mi.index_id
+WHERE mi.type IN (7) AND mst.is_ms_shipped = 0
+ORDER BY mst.name
+OPTION (MAXDOP 2);'
+
+	INSERT INTO #tmpHashIxs
+	EXECUTE sp_executesql @sqlcmd;
+END;
+
+RAISERROR (N'Aggregating data...', 10, 1) WITH NOWAIT
+
+INSERT INTO #tmpAgg
+SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
+	si.[schema_name], si.table_name, si.index_id, si.index_name, ISNULL(ps.partition_number, si.partition_number), 
+	ps.fragmentation, si.fill_factor, ps.page_count, ps.[size_MB], ps.record_count, ps.forwarded_record_count, -- for heaps
+	os.range_scan_count, os.singleton_lookup_count, os.forwarded_fetch_count, os.row_lock_count,
+	os.row_lock_wait_count, os.row_lock_pct, os.row_lock_wait_in_ms, os.[avg_row_lock_waits_in_ms],
+	os.page_lock_count, os.page_lock_wait_count, os.page_lock_pct, os.page_lock_wait_in_ms,
+	os.[avg_page_lock_waits_in_ms], os.[page_io_latch_wait_in_ms], os.[avg_page_io_latch_wait_in_ms],
+	s.[Hits], s.[Reads_Ratio], s.[Writes_Ratio], s.user_updates, s.last_user_seek, s.last_user_scan,
+	s.last_user_lookup, s.last_user_update, si.KeyCols, si.KeyColsOrdered, si.IncludedCols,
+	si.IncludedColsOrdered, si.AllColsOrdered, si.is_unique, si.[index_type], si.[type_desc],
+	si.is_primary_key, si.is_unique_constraint, si.is_padded, si.has_filter, si.filter_definition,
+	si.is_disabled,	si.[KeyCols_data_length_bytes]
+FROM #tmpIxs AS si
+	LEFT JOIN #tmpIPS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id] AND si.partition_number = ps.partition_number
+	LEFT JOIN #tmpIOS AS os ON os.database_id = ps.database_id AND os.index_id = ps.index_id AND os.[object_id] = ps.[object_id] AND os.partition_number = ps.partition_number
+	LEFT JOIN #tmpIUS AS s ON s.database_id = ps.database_id AND s.index_id = ps.index_id and s.[object_id] = ps.[object_id]
+--WHERE si.type > 0 -- ignore heaps
+ORDER BY database_name, [table_name], fragmentation DESC, index_id
+OPTION (MAXDOP 2);
+
+IF @sqlmajorver >= 12
+BEGIN
+	INSERT INTO #tmpAggXTPHash
+	SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
+		si.[schema_name], si.table_name, si.index_id, si.index_name, ps.total_bucket_count, ps.empty_bucket_count, 
+		ps.avg_chain_length, ps.max_chain_length, ps.scans_started, ps.scans_retries, ps.rows_returned, 
+		ps.rows_touched, si.KeyCols, si.KeyColsOrdered, si.IncludedCols, si.IncludedColsOrdered,
+		si.AllColsOrdered, si.is_unique, si.[index_type], si.[type_desc], si.is_primary_key, si.is_unique_constraint,
+		si.is_padded, si.has_filter, si.filter_definition, si.is_disabled, si.[KeyCols_data_length_bytes]	
+	FROM #tmpHashIxs AS si
+		LEFT JOIN #tmpXIS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id]
+	ORDER BY database_name, [table_name], index_id
+	OPTION (MAXDOP 2);
+
+	INSERT INTO #tmpAggXTPNC
+	SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
+		si.[schema_name], si.table_name, si.index_id, si.index_name, ps.delta_pages, ps.internal_pages, 
+		ps.leaf_pages, ps.page_update_count, ps.page_update_retry_count, 
+		ps.page_consolidation_count, ps.page_consolidation_retry_count, ps.page_split_count, 
+		ps.page_split_retry_count, ps.key_split_count, ps.key_split_retry_count, ps.page_merge_count, 
+		ps.page_merge_retry_count, ps.key_merge_count, ps.key_merge_retry_count,
+		ps.scans_started, ps.scans_retries, ps.rows_returned, ps.rows_touched,
+		si.KeyCols, si.KeyColsOrdered, si.IncludedCols, si.IncludedColsOrdered, si.AllColsOrdered,
+		si.is_unique, si.[index_type], si.[type_desc], si.is_primary_key, si.is_unique_constraint,
+		si.is_padded, si.has_filter, si.filter_definition, si.is_disabled, si.[KeyCols_data_length_bytes]	
+	FROM #tmpHashIxs AS si
+		LEFT JOIN #tmpXNCIS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id]
+	ORDER BY database_name, [table_name], index_id
+	OPTION (MAXDOP 2);
+END;
+
+RAISERROR (N'Output index information', 10, 1) WITH NOWAIT
+
+-- All index information
+SELECT 'All_IX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
+	[partition_number], fragmentation, fill_factor, [page_count], [size_MB], record_count, range_scan_count, singleton_lookup_count, row_lock_count, row_lock_wait_count,
+	row_lock_pct, row_lock_wait_in_ms, [avg_row_lock_waits_in_ms], page_lock_count, page_lock_wait_count,
+	page_lock_pct, page_lock_wait_in_ms, [avg_page_lock_waits_in_ms], page_io_latch_wait_in_ms, [avg_page_io_latch_wait_in_ms], [Hits],
+	CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
+	user_updates, last_user_seek, last_user_scan, last_user_lookup, last_user_update, KeyCols, IncludedCols,
+	is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter, filter_definition, KeyCols_data_length_bytes
+FROM #tmpAgg
+WHERE index_id > 0 -- ignore heaps
+ORDER BY [database_name], [schema_name], table_name, [page_count] DESC, forwarded_record_count DESC;
+
+-- All XTP index information
+IF @sqlmajorver >= 12
+BEGIN
+	SELECT 'All_XTP_HashIX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
+		total_bucket_count, empty_bucket_count, FLOOR((CAST(empty_bucket_count AS FLOAT)/total_bucket_count) * 100) AS [empty_bucket_pct], avg_chain_length, max_chain_length, 
+		scans_started, scans_retries, rows_returned, rows_touched, KeyCols, IncludedCols, is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter, 
+		filter_definition, KeyCols_data_length_bytes
+	FROM #tmpAggXTPHash
+	ORDER BY [database_name], [schema_name], table_name, [total_bucket_count] DESC;
+
+	SELECT 'All_XTP_RangeIX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
+		delta_pages, internal_pages, leaf_pages, page_update_count, page_update_count, page_update_retry_count, page_consolidation_count, page_consolidation_retry_count, 
+		page_split_count, page_split_retry_count, key_split_count, key_split_retry_count, page_merge_count, page_merge_retry_count, key_merge_count, key_merge_retry_count,
+		scans_started, scans_retries, rows_returned, rows_touched, KeyCols, IncludedCols, is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter, 
+		filter_definition, KeyCols_data_length_bytes
+	FROM #tmpAggXTPNC
+	ORDER BY [database_name], [schema_name], table_name, [leaf_pages] DESC;
+END;
+
+-- All Heaps information
+SELECT 'All_Heaps_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [type_desc] AS index_type,
+	[partition_number], fragmentation, [page_count], [size_MB], record_count, forwarded_record_count, forwarded_fetch_count,
+	range_scan_count, singleton_lookup_count, row_lock_count, row_lock_wait_count,
+	row_lock_pct, row_lock_wait_in_ms, [avg_row_lock_waits_in_ms], page_lock_count, page_lock_wait_count,
+	page_lock_pct, page_lock_wait_in_ms, [avg_page_lock_waits_in_ms], page_io_latch_wait_in_ms, [avg_page_io_latch_wait_in_ms]
+FROM #tmpAgg
+WHERE index_id = 0 -- only heaps
+ORDER BY [database_name], [schema_name], table_name, [page_count] DESC, forwarded_record_count DESC;
+
+-- Unused indexes that can possibly be dropped or disabled
+SELECT 'Unused_IX_With_Updates' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
+	CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
+	[page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan, 
+	last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
+FROM #tmpAgg
+WHERE [Hits] = 0 
+	AND last_user_update > 0
+	AND type IN (2,6)				-- non-clustered and non-clustered columnstore indexes only
+	AND is_primary_key = 0			-- no primary keys
+	AND is_unique_constraint = 0	-- no unique constraints
+	AND is_unique = 0 				-- no alternate keys
+UNION ALL
+SELECT 'Unused_IX_No_Updates' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
+	CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
+	[page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan, 
+	last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
+FROM #tmpAgg
+WHERE [Hits] = 0 
+	AND (last_user_update = 0 OR last_user_update IS NULL)
+	AND type IN (2,6)				-- non-clustered and non-clustered columnstore indexes only
+	AND is_primary_key = 0			-- no primary keys
+	AND is_unique_constraint = 0	-- no unique constraints
+	AND is_unique = 0 				-- no alternate keys
+ORDER BY [table_name], user_updates DESC, [page_count] DESC;
+
+-- Rarely used indexes that can possibly be dropped or disabled
+SELECT 'Rarely_Used_IX' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
+	CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
+	[page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan, 
+	last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
+FROM #tmpAgg
+WHERE [Hits] > 0 AND [Reads_Ratio] < 5
+	AND type IN (2,6)				-- non-clustered and non-clustered columnstore indexes only
+	AND is_primary_key = 0			-- no primary keys
+	AND is_unique_constraint = 0	-- no unique constraints
+	AND is_unique = 0 				-- no alternate keys
+ORDER BY [database_name], [table_name], [page_count] DESC;
+
+-- Duplicate Indexes
+SELECT 'Duplicate_IX' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition, 
+	I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
+FROM #tmpAgg I INNER JOIN #tmpAgg I2
+	ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+	AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
+	AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
+WHERE I.type IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I2.type IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+ORDER BY I.database_name, I.[table_name], I.[index_id];
+
+/*
+Note that it is possible that a clustered index (unique or not) is among the duplicate indexes to be dropped, 
+namely if a non-clustered primary key exists on the table.
+In this case, make the appropriate changes in the clustered index (making it unique and/or primary key in this case),
+and drop the non-clustered instead.
+*/
+SELECT 'Duplicate_IX_toDrop' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition, 
+	I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
+FROM #tmpAgg I INNER JOIN #tmpAgg I2
+	ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+	AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
+	AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
+WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I.[index_id] NOT IN (
+			SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+			(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+			(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
+			))
+GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+ORDER BY I.database_name, I.[table_name], I.[index_id];
+
+RAISERROR (N'Starting index search in sql modules...', 10, 1) WITH NOWAIT
+
+DECLARE Dup_Stats CURSOR FAST_FORWARD FOR SELECT I.database_name,I.[index_name] 
+FROM #tmpAgg I INNER JOIN #tmpAgg I2
+	ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+	AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
+	AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
+WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I.[index_id] NOT IN (
+			SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+			(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+			(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+			WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+				AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+			GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
+			))
+GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+ORDER BY I.database_name, I.[table_name], I.[index_id];
+
+OPEN Dup_Stats
+FETCH NEXT FROM Dup_Stats INTO @DatabaseName,@indexName
+WHILE (@@FETCH_STATUS = 0)
+BEGIN
+	SET @sqlcmd = 'USE [' + @DatabaseName + '];
+SELECT ''' + @DatabaseName + ''' AS [database_name], ss.name AS [schema_name], so.name AS [table_name], ''' + @indexName + ''' AS [index_name], so.type_desc
+FROM sys.sql_modules sm
+INNER JOIN sys.objects so ON sm.[object_id] = so.[object_id]
+INNER JOIN sys.schemas ss ON ss.[schema_id] = so.[schema_id]
+WHERE sm.[definition] LIKE ''%' + @indexName + '%'''
+
+	INSERT INTO #tblCode
+	EXECUTE sp_executesql @sqlcmd
+
+	FETCH NEXT FROM Dup_Stats INTO @DatabaseName,@indexName
+END
+CLOSE Dup_Stats
+DEALLOCATE Dup_Stats
+
+RAISERROR (N'Ended index search in sql modules', 10, 1) WITH NOWAIT
+
+SELECT 'Duplicate_Indexes_HardCoded' AS [Category], [DatabaseName], [schemaName], [objectName] AS [referedIn_objectName], 
+	indexName AS [referenced_indexName], type_desc AS [refered_objectType]
+FROM #tblCode
+ORDER BY [DatabaseName], [objectName];
+
+-- Redundant Indexes
+SELECT 'Redundant_IX' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_unique, I.is_padded, I.has_filter, I.filter_definition,
+	I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
+FROM #tmpAgg I INNER JOIN #tmpAgg I2
+ON I.[database_id] = I2.[database_id] AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+	AND (((I.[KeyColsOrdered] <> I2.[KeyColsOrdered] OR I.IncludedColsOrdered <> I2.IncludedColsOrdered)
+		AND ((CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END) = (CASE WHEN I2.IncludedColsOrdered IS NULL THEN I2.[KeyColsOrdered] ELSE I2.[KeyColsOrdered] + ',' + I2.IncludedColsOrdered END)
+			OR I.[AllColsOrdered] = I2.[AllColsOrdered]))
+	OR (I.[KeyColsOrdered] <> I2.[KeyColsOrdered] AND I.IncludedColsOrdered = I2.IncludedColsOrdered)
+	OR (I.[KeyColsOrdered] = I2.[KeyColsOrdered] AND I.IncludedColsOrdered <> I2.IncludedColsOrdered)
+	OR ((I.[AllColsOrdered] = I2.[AllColsOrdered] AND I.filter_definition IS NULL AND I2.filter_definition IS NOT NULL) OR (I.[AllColsOrdered] = I2.[AllColsOrdered] AND I.filter_definition IS NOT NULL AND I2.filter_definition IS NULL)))
+	AND I.[index_id] NOT IN (SELECT I3.[index_id]
+		FROM #tmpIxs I3 INNER JOIN #tmpIxs I4
+		ON I3.[database_id] = I4.[database_id] AND I3.[object_id] = I4.[object_id] AND I3.[index_id] <> I4.[index_id] 
+			AND I3.[KeyCols] = I4.[KeyCols] AND (I3.IncludedCols = I4.IncludedCols OR (I3.IncludedCols IS NULL AND I4.IncludedCols IS NULL))
+		WHERE I3.[database_id] = I.[database_id] AND I3.[object_id] = I.[object_id]
+		GROUP BY I3.[index_id])
+WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+	AND I.is_unique_constraint = 0	-- no unique constraints
+	AND I2.is_unique_constraint = 0	-- no unique constraints
+GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+ORDER BY I.database_name, I.[table_name], I.[AllColsOrdered], I.[index_id];
+
+-- Large IX Keys
+SELECT 'Large_Index_Key' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], 
+	I.KeyCols, [KeyCols_data_length_bytes]
+FROM #tmpAgg I
+WHERE [KeyCols_data_length_bytes] > 900
+ORDER BY I.[database_name], I.[schema_name], I.[table_name], I.[index_id];
+
+-- Low Fill Factor
+SELECT 'Low_Fill_Factor' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], 
+	[fill_factor], I.KeyCols, I.IncludedCols, CASE WHEN I.IncludedCols IS NULL THEN I.[KeyCols] ELSE I.[KeyCols] + ',' + I.IncludedCols END AS [AllColsOrdered]
+FROM #tmpAgg I
+WHERE [fill_factor] BETWEEN 1 AND 79
+ORDER BY I.[database_name], I.[schema_name], I.[table_name], I.[index_id];
+
+--NonUnique Clustered IXs
+SELECT 'NonUnique_CIXs' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[KeyCols]
+FROM #tmpAgg I
+WHERE [is_unique] = 0 
+	AND I.[index_id] = 1
+ORDER BY I.[database_name], I.[schema_name], I.[table_name];
+
+RAISERROR (N'Generating scripts...', 10, 1) WITH NOWAIT
+
+DECLARE @strSQL NVARCHAR(4000)
+PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
+
+IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] = 0 AND last_user_update > 0) > 0
+BEGIN
+	PRINT CHAR(10) + '--############# Existing unused indexes with updates drop statements #############' + CHAR(10)
+	DECLARE Un_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10) 
+	FROM #tmpAgg
+	WHERE [Hits] = 0 AND last_user_update > 0
+	ORDER BY [database_name], [table_name], [Reads_Ratio] DESC;
+
+	OPEN Un_Stats
+	FETCH NEXT FROM Un_Stats INTO @strSQL
+	WHILE (@@FETCH_STATUS = 0)
+	BEGIN
+		PRINT @strSQL
+		FETCH NEXT FROM Un_Stats INTO @strSQL
+	END
+	CLOSE Un_Stats
+	DEALLOCATE Un_Stats
+	PRINT CHAR(10) + '--############# Ended unused indexes with updates drop statements #############' + CHAR(10)
+END;
+
+IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] = 0 AND (last_user_update = 0 OR last_user_update IS NULL)) > 0
+BEGIN
+	PRINT CHAR(10) + '--############# Existing unused indexes with no updates drop statements #############' + CHAR(10)
+	DECLARE Un_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10) 
+	FROM #tmpAgg
+	WHERE [Hits] = 0 AND (last_user_update = 0 OR last_user_update IS NULL)
+	ORDER BY [database_name], [table_name], [Reads_Ratio] DESC;
+
+	OPEN Un_Stats
+	FETCH NEXT FROM Un_Stats INTO @strSQL
+	WHILE (@@FETCH_STATUS = 0)
+	BEGIN
+		PRINT @strSQL
+		FETCH NEXT FROM Un_Stats INTO @strSQL
+	END
+	CLOSE Un_Stats
+	DEALLOCATE Un_Stats
+	PRINT CHAR(10) + '--############# Ended unused indexes with no updates drop statements #############' + CHAR(10)
+END;
+
+IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] > 0 AND [Reads_Ratio] < 5) > 0
+BEGIN
+	PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
+	PRINT CHAR(10) + '--############# Existing rarely used indexes drop statements #############' + CHAR(10)
+	DECLARE curRarUsed CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10) 
+	FROM #tmpAgg
+	WHERE [Hits] > 0 AND [Reads_Ratio] < 5
+	ORDER BY [database_name], [table_name], [Reads_Ratio] DESC
+
+	OPEN curRarUsed
+	FETCH NEXT FROM curRarUsed INTO @strSQL
+	WHILE (@@FETCH_STATUS = 0)
+	BEGIN
+		PRINT @strSQL
+		FETCH NEXT FROM curRarUsed INTO @strSQL
+	END
+	CLOSE curRarUsed
+	DEALLOCATE curRarUsed
+	PRINT '--############# Ended rarely used indexes drop statements #############' + CHAR(10)
+END;
+
+PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
+PRINT CHAR(10) + '/*
+NOTE: It is possible that a clustered index (unique or not) is among the duplicate indexes to be dropped, namely if a non-clustered primary key exists on the table.
+In this case, make the appropriate changes in the clustered index (making it unique and/or primary key in this case), and drop the non-clustered instead.
+*/'
+PRINT CHAR(10) + '--############# Existing Duplicate indexes drop statements #############' + CHAR(10)
+DECLARE Dup_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + I.[database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ I.[index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME(I.[index_name]) + ' ON ' + QUOTENAME(I.[schema_name]) + '.' + QUOTENAME(I.[table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10) 
+	FROM #tmpAgg I INNER JOIN #tmpAgg I2
+		ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id] 
+		AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
+		AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
+	WHERE I.[type] IN (1,2,5,6)			-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+		AND I2.[type] IN (1,2,5,6)		-- clustered, non-clustered, clustered and non-clustered columnstore indexes only
+		AND I.[index_id] NOT IN (
+				SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+				WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+					AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+					AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
+				GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+				(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+				WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+					AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+					AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
+				GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
+				(SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
+				WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id] 
+					AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
+				GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
+				))
+	GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
+	ORDER BY I.database_name, I.[table_name], I.[index_id];
+OPEN Dup_Stats
+FETCH NEXT FROM Dup_Stats INTO @strSQL
+WHILE (@@FETCH_STATUS = 0)
+BEGIN
+	PRINT @strSQL
+	FETCH NEXT FROM Dup_Stats INTO @strSQL
+END
+CLOSE Dup_Stats
+DEALLOCATE Dup_Stats
+PRINT '--############# Ended Duplicate indexes drop statements #############' + CHAR(10)
+
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
+DROP TABLE #tmpIPS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
+DROP TABLE #tmpIOS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
+DROP TABLE #tmpIUS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
+DROP TABLE #tmpXIS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
+DROP TABLE #tmpXNCIS;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
+DROP TABLE #tmpIxs;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
+DROP TABLE #tmpHashIxs;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
+DROP TABLE #tmpAgg;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
+DROP TABLE #tmpAggXTPHash;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
+DROP TABLE #tmpAggXTPNC;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
+DROP TABLE #tblWorking;
+IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
+DROP TABLE #tblCode;
+GO

+ 43 - 0
Statistics/view_Stats_Last_Update.sql

@@ -0,0 +1,43 @@
+-- 04/01/2012 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/sqlinsights/)
+--
+-- Checks for stats last update on database in scope
+--
+-- 11/02/2016 Fixed rows col when sys.dm_db_stats_properties returns null
+--
+
+DECLARE @sqlcmd NVARCHAR(4000), @sqlmajorver int, @sqlminorver int, @sqlbuild int
+
+SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
+SELECT @sqlminorver = CONVERT(int, (@@microsoftversion / 0x10000) & 0xff);
+SELECT @sqlbuild = CONVERT(int, @@microsoftversion & 0xffff);
+
+IF (@sqlmajorver = 10 AND @sqlminorver = 50 AND @sqlbuild >= 4000) OR (@sqlmajorver = 11 AND @sqlbuild >= 3000) OR @sqlmajorver > 11
+BEGIN
+	SET @sqlcmd = 'USE ' + QUOTENAME(DB_NAME()) + ';
+SELECT DISTINCT ''' + DB_NAME() + ''' AS [DatabaseName], ''' + CONVERT(VARCHAR(12),DB_ID()) + ''' AS [databaseID], mst.[object_id] AS objectID, t.name AS schemaName, OBJECT_NAME(mst.[object_id]) AS tableName, ISNULL(sp.[rows],SUM(p.[rows])) AS [rows], sp.modification_counter, ss.[stats_id], ss.name AS [stat_name], STATS_DATE(o.[object_id], ss.[stats_id]) AS [stats_date]
+FROM sys.stats AS ss 
+	INNER JOIN sys.objects AS o ON o.[object_id] = ss.[object_id]
+	INNER JOIN sys.tables AS mst ON mst.[object_id] = o.[object_id]
+	INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+	INNER JOIN sys.partitions AS p ON p.[object_id] = ss.[object_id]
+	CROSS APPLY sys.dm_db_stats_properties(ss.[object_id], ss.[stats_id]) AS sp
+GROUP BY o.[object_id], mst.[object_id], t.name, ss.stats_id, ss.name, sp.[rows], sp.modification_counter
+ORDER BY t.name, OBJECT_NAME(mst.[object_id]), ss.name'
+END
+ELSE
+BEGIN
+	SET @sqlcmd = 'USE ' + QUOTENAME(DB_NAME()) + ';
+SELECT DISTINCT ''' + DB_NAME() + ''' AS [DatabaseName], ''' + CONVERT(VARCHAR(12),DB_ID()) + ''' AS [databaseID], mst.[object_id] AS objectID, t.name AS schemaName, OBJECT_NAME(mst.[object_id]) AS tableName, SUM(p.[rows]) AS [rows], rowmodctr AS modification_counter, ss.stats_id, ss.name AS [stat_name], STATS_DATE(o.[object_id], ss.[stats_id]) AS [stats_date]
+FROM sys.stats AS ss
+	INNER JOIN sys.sysindexes AS si ON si.id = ss.[object_id]
+	INNER JOIN sys.objects AS o ON o.[object_id] = si.id
+	INNER JOIN sys.tables AS mst ON mst.[object_id] = o.[object_id]
+	INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
+	INNER JOIN sys.partitions AS p ON p.[object_id] = ss.[object_id]
+	LEFT JOIN sys.indexes i ON si.id = i.[object_id] AND si.indid = i.index_id
+WHERE o.type <> ''S'' AND i.name IS NOT NULL
+GROUP BY o.[object_id], mst.[object_id], t.name, rowmodctr, ss.stats_id, ss.name
+ORDER BY t.name, OBJECT_NAME(mst.[object_id]), ss.name'
+END
+
+EXECUTE sp_executesql @sqlcmd