Skip to content

Instantly share code, notes, and snippets.

@lionofdezert
Created November 29, 2013 18:50
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save lionofdezert/7710270 to your computer and use it in GitHub Desktop.
Save lionofdezert/7710270 to your computer and use it in GitHub Desktop.
Stored Procedure, to create missing indexes on tables values at target database by comparing both source and target databases.
--DROP IF ALREADY EXISTS
IF EXISTS ( SELECT 1
FROM SYS.PROCEDURES
WHERE NAME = 'SYNC_Indexes' )
DROP PROCEDURE SYNC_Indexes
GO
--CREATE PROCEDURE
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
/*
Note: Must create on source database
Stored Procedure, to create missing indexes on tables values at target database by comparing both source and target databases.
EXEC [dbo].[SYNC_Indexes] 'AventureWork_Target'
*/
CREATE PROCEDURE [dbo].[SYNC_Indexes]
(
@SyncToDB VARCHAR(200) --Target database name
)
AS
BEGIN
CREATE TABLE #AlterStatements ( TSQLStmt VARCHAR(max) )
DECLARE @idxTableName SYSNAME
DECLARE @idxTableID INT
DECLARE @idxname SYSNAME
DECLARE @idxid INT
DECLARE @colCount INT
DECLARE @IxColumn SYSNAME
DECLARE @IxFirstColumn BIT
DECLARE @ColumnIDInTable INT
DECLARE @ColumnIDInIndex INT
DECLARE @IsIncludedColumn INT
DECLARE @sIncludeCols VARCHAR(4000)
DECLARE @sIndexCols VARCHAR(4000)
DECLARE @sSQL VARCHAR(4000)
DECLARE @rowcnt INT
DECLARE @sParamSQL VARCHAR(4000)
DECLARE @location SYSNAME
DECLARE @fillfactor INT
DECLARE @SchemaName varchar(200)
-- Get all the index info
DECLARE curidx CURSOR
FOR SELECT object_name(si.object_id), si.object_id, si.NAME,
si.index_id, SC.name
FROM sys.indexes si
LEFT JOIN information_schema.table_constraints tc ON si.NAME = tc.constraint_name
AND object_name(si.object_id) = tc.table_name
INNER JOIN SYS.tables T ON SI.object_id = T.object_id
INNER JOIN SYS.SCHEMAS SC ON SC.SCHEMA_ID = T.SCHEMA_ID
WHERE objectproperty(si.object_id, 'IsUserTable') = 1
and si.is_primary_key = 0
ORDER BY object_name(si.object_id), si.index_id
OPEN curidx
FETCH NEXT FROM curidx INTO @idxTableName, @idxTableID, @idxname,
@idxid, @SchemaName
--loop
WHILE ( @@FETCH_STATUS = 0 )
BEGIN
SET @sSQL = 'IF NOT EXISTS (SELECT 1 FROM [' + @SyncToDB
+ '].SYS.INDEXES WHERE name = ''' + @idxname + ''')'
+ CHAR(13)
SET @sSQL = @sSQL + 'BEGIN' + CHAR(13)
SET @sSQL = @sSQL + 'CREATE '
-- Check if the index is unique
IF ( INDEXPROPERTY(@idxTableID, @idxname, 'IsUnique') = 1 )
SET @sSQL = @sSQL + ' UNIQUE NONCLUSTERED '
-- Check if the index is clustered
ELSE
IF ( INDEXPROPERTY(@idxTableID, @idxname, 'IsClustered') = 1 )
SET @sSQL = @sSQL + 'CLUSTERED '
ELSE
IF ( INDEXPROPERTY(@idxTableID, @idxname,
'IsClustered') = 0 )
SET @sSQL = @sSQL + ' NONCLUSTERED '
SET @sSQL = @sSQL + 'INDEX ' + @idxname + ' ON [' + @SyncToDB
+ '].[' + @SchemaName + '].[' + @idxTableName + ']'
+ CHAR(13) + '('
SET @sSQL = @sSQL + CHAR(13)
SET @colCount = 0
SELECT @fillfactor = fill_factor
FROM sys.indexes
WHERE name = @idxname
IF ISNULL(@fillfactor, 0) = 0
SET @fillfactor = 90
-- Get the number of cols in the index
SELECT @colCount = COUNT(*)
FROM sys.index_columns ic
INNER JOIN sys.columns sc ON ic.object_id = sc.object_id
AND ic.column_id = sc.column_id
WHERE ic.object_id = @idxtableid
AND index_id = @idxid
AND ic.is_included_column = 0
-- Get the file group info
SELECT @location = f.[name]
FROM sys.indexes i
INNER JOIN sys.filegroups f ON i.data_space_id = f.data_space_id
INNER JOIN sys.all_objects o ON i.[object_id] = o.[object_id]
WHERE o.object_id = @idxTableID
AND i.index_id = @idxid
-- Get all columns of the index
DECLARE curidxcolumn CURSOR
FOR SELECT sc.column_id AS columnidintable, sc.NAME,
ic.index_column_id columnidinindex,
ic.is_included_column AS isincludedcolumn
FROM sys.index_columns ic
INNER JOIN sys.columns sc ON ic.object_id = sc.object_id
AND ic.column_id = sc.column_id
WHERE ic.object_id = @idxTableID
AND index_id = @idxid
ORDER BY ic.index_column_id
SET @IxFirstColumn = 1
SET @sIncludeCols = ''
SET @sIndexCols = ''
SET @rowcnt = 0
OPEN curidxColumn
FETCH NEXT FROM curidxColumn INTO @ColumnIDInTable, @IxColumn,
@ColumnIDInIndex, @IsIncludedColumn
--loop
WHILE ( @@FETCH_STATUS = 0 )
BEGIN
IF @IsIncludedColumn = 0
BEGIN
SET @rowcnt = @rowcnt + 1
SET @sIndexCols = CHAR(9) + @sIndexCols + '['
+ @IxColumn + ']'
-- Check the sort order of the index cols
IF ( INDEXKEY_PROPERTY(@idxTableID, @idxid,
@ColumnIDInIndex,
'IsDescending') ) = 0
SET @sIndexCols = @sIndexCols + ' ASC '
ELSE
SET @sIndexCols = @sIndexCols + ' DESC '
IF @rowcnt < @colCount
SET @sIndexCols = @sIndexCols + ', '
END
ELSE
BEGIN
-- Check for any include columns
IF len(@sIncludeCols) > 0
SET @sIncludeCols = @sIncludeCols + ','
SET @sIncludeCols = @sIncludeCols + '['
+ @IxColumn + ']'
END
FETCH NEXT FROM curidxColumn INTO @ColumnIDInTable,
@IxColumn, @ColumnIDInIndex, @IsIncludedColumn
END
CLOSE curidxColumn
DEALLOCATE curidxColumn
IF LEN(@sIncludeCols) > 0
SET @sIndexCols = @sSQL + @sIndexCols + CHAR(13) + ') '
+ ' INCLUDE ( ' + @sIncludeCols + ' ) '
ELSE
SET @sIndexCols = @sSQL + @sIndexCols + CHAR(13) + ') '
SET @sParamSQL = ' WITH (FILLFACTOR = '
+ cast(isnull(@fillfactor, 90) AS VARCHAR(3)) + ', '
IF ( INDEXPROPERTY(@idxTableID, @idxname, 'IsPadIndex') = 1 )
SET @sParamSQL = @sParamSQL + ' PAD_INDEX = ON, '
ELSE
SET @sParamSQL = @sParamSQL + ' PAD_INDEX = OFF, '
IF ( INDEXPROPERTY(@idxTableID, @idxname,
'IsPageLockDisallowed') = 1 )
SET @sParamSQL = @sParamSQL + ' ALLOW_PAGE_LOCKS = ON, '
ELSE
SET @sParamSQL = @sParamSQL + ' ALLOW_PAGE_LOCKS = ON, '
IF ( INDEXPROPERTY(@idxTableID, @idxname,
'IsRowLockDisallowed') = 1 )
SET @sParamSQL = @sParamSQL + ' ALLOW_ROW_LOCKS = ON, '
ELSE
SET @sParamSQL = @sParamSQL + ' ALLOW_ROW_LOCKS = on, '
IF ( INDEXPROPERTY(@idxTableID, @idxname, 'IsStatistics') = 1 )
SET @sParamSQL = @sParamSQL
+ ' STATISTICS_NORECOMPUTE = ON, '
ELSE
SET @sParamSQL = @sParamSQL
+ ' STATISTICS_NORECOMPUTE = OFF, '
SET @sParamSQL = @sParamSQL + ' DROP_EXISTING = off ) '
SET @sIndexCols = @sIndexCols + CHAR(13) + @sParamSQL
+ ' ON [' + @location + ']' + CHAR(13) + 'END ' + CHAR(10)
+ '' + CHAR(13)
INSERT INTO #AlterStatements
SELECT @sIndexCols
FETCH NEXT FROM curidx INTO @idxTableName, @idxTableID,
@idxname, @idxid, @SchemaName
END
CLOSE curidx
DEALLOCATE curidx
----CURSOR TO EXECUTE/PRINT EACH STATEMENT SEPARATELY-----
DECLARE MY_CURSOR CURSOR READ_ONLY
FOR SELECT TSQLStmt
FROM #AlterStatements
OPEN My_Cursor
DECLARE @SQLstmt VARCHAR(MAX)
Fetch NEXT FROM MY_Cursor INTO @SQLstmt
While ( @@FETCH_STATUS <> -1 )
BEGIN
SELECT @SQLstmt = 'set NUMERIC_ROUNDABORT off
set ANSI_NULLS,
ANSI_PADDING,
ANSI_WARNINGS,
ARITHABORT,
CONCAT_NULL_YIELDS_NULL,
QUOTED_IDENTIFIER on '
+ @SQLstmt
EXEC ( @SQLstmt
)
-- PRINT ( @SQLstmt)
FETCH NEXT FROM MY_CURSOR INTO @SQLstmt
END
CLOSE MY_CURSOR
DEALLOCATE MY_CURSOR
DROP TABLE #AlterStatements
END
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment