How to Generate Index Creation Scripts for all Tables in a Database using T-SQL

How to Generate Index Creation Scripts for all Tables in a Database using T-SQL

The need often arises to create or recreate the indexes for all tables in a database, especially in development and testing scenarios. This article presents a script to generate Index Creation Scripts for all tables in a database using Transact-SQL (T-SQL).

The code block below will generate Index Creation Scripts for all tables in a database:

SELECT ' CREATE ' +  
    CASE WHEN I.is_unique = 1 THEN ' UNIQUE ' ELSE '' END  +   
    I.type_desc COLLATE DATABASE_DEFAULT +' INDEX ' +    
    I.name  + ' ON '  +   
    Schema_name(T.Schema_id)+'.'+T.name + ' ( ' +  
    KeyColumns + ' )  ' +  
    ISNULL(' INCLUDE ('+IncludedColumns+' ) ','') +  
    ISNULL(' WHERE  '+I.Filter_definition,'') + ' WITH ( ' +  
    CASE WHEN I.is_padded = 1 THEN ' PAD_INDEX = ON ' ELSE ' PAD_INDEX = OFF ' END + ','  +  
    'FILLFACTOR = '+CONVERT(CHAR(5),CASE WHEN I.Fill_factor = 0 THEN 100 ELSE I.Fill_factor END) + ','  +  
    -- default value  
    'SORT_IN_TEMPDB = OFF '  + ','  +  
    CASE WHEN I.ignore_dup_key = 1 THEN ' IGNORE_DUP_KEY = ON ' ELSE ' IGNORE_DUP_KEY = OFF ' END + ','  +  
    CASE WHEN ST.no_recompute = 0 THEN ' STATISTICS_NORECOMPUTE = OFF ' ELSE ' STATISTICS_NORECOMPUTE = ON ' END + ','  +  
    -- default value   
    ' DROP_EXISTING = ON '  + ','  +  
    -- default value   
    ' ONLINE = OFF '  + ','  +  
   CASE WHEN I.allow_row_locks = 1 THEN ' ALLOW_ROW_LOCKS = ON ' ELSE ' ALLOW_ROW_LOCKS = OFF ' END + ','  +  
   CASE WHEN I.allow_page_locks = 1 THEN ' ALLOW_PAGE_LOCKS = ON ' ELSE ' ALLOW_PAGE_LOCKS = OFF ' END  + ' ) ON [' +  
   DS.name + ' ] '  [CreateIndexScript]  
FROM sys.indexes I    
 JOIN sys.tables T ON T.Object_id = I.Object_id     
 JOIN sys.sysindexes SI ON I.Object_id = SI.id AND I.index_id = SI.indid    
 JOIN (SELECT * FROM (   
    SELECT IC2.object_id , IC2.index_id ,   
        STUFF((SELECT ' , ' + C.name + CASE WHEN MAX(CONVERT(INT,IC1.is_descending_key)) = 1 THEN ' DESC ' ELSE ' ASC ' END 
    FROM sys.index_columns IC1   
    JOIN Sys.columns C    
       ON C.object_id = IC1.object_id    
       AND C.column_id = IC1.column_id    
       AND IC1.is_included_column = 0   
    WHERE IC1.object_id = IC2.object_id    
       AND IC1.index_id = IC2.index_id    
    GROUP BY IC1.object_id,C.name,index_id   
    ORDER BY MAX(IC1.key_ordinal)   
       FOR XML PATH('')), 1, 2, '') KeyColumns    
    FROM sys.index_columns IC2    
    --WHERE IC2.Object_id = object_id('Person.Address') --Comment for all tables   
    GROUP BY IC2.object_id ,IC2.index_id) tmp3 )tmp4    
  ON I.object_id = tmp4.object_id AND I.Index_id = tmp4.index_id   
 JOIN sys.stats ST ON ST.object_id = I.object_id AND ST.stats_id = I.index_id    
 JOIN sys.data_spaces DS ON I.data_space_id=DS.data_space_id    
 JOIN sys.filegroups FG ON I.data_space_id=FG.data_space_id    
 LEFT JOIN (SELECT * FROM (    
    SELECT IC2.object_id , IC2.index_id ,    
        STUFF((SELECT ' , ' + C.name  
    FROM sys.index_columns IC1    
    JOIN Sys.columns C     
       ON C.object_id = IC1.object_id     
       AND C.column_id = IC1.column_id     
       AND IC1.is_included_column = 1    
    WHERE IC1.object_id = IC2.object_id     
       AND IC1.index_id = IC2.index_id     
    GROUP BY IC1.object_id,C.name,index_id    
       FOR XML PATH('')), 1, 2, '') IncludedColumns     
   FROM sys.index_columns IC2     
   --WHERE IC2.Object_id = object_id('Person.Address') --Comment for all tables    
   GROUP BY IC2.object_id ,IC2.index_id) tmp1    
   WHERE IncludedColumns IS NOT NULL ) tmp2     
ON tmp2.object_id = I.object_id AND tmp2.index_id = I.index_id    
WHERE I.is_primary_key = 0 AND I.is_unique_constraint = 0  
--AND I.Object_id = object_id('Person.Address') --Comment for all tables  
--AND I.name = 'IX_Address_PostalCode' --comment for all indexes  



See also

Read suggested related topics:

Sort by: Published Date | Most Recent | Most Useful
Comments
  • Please include your T-SQL articles into this parent article social.technet.microsoft.com/.../17785.sql-server-query-language-transact-sql.aspx and make a reference to it in yours in See Also section

  • TNJMAN edited Revision 5. Comment: More cleanup

  • Interesting - this is not really a "wiki;" it is a "script submission," but we can turn it into a wiki...

  • I believe this script is not creating Partitioned Indexes. I tried using this script and it is missing indexes associated with partition schema. Do we have a script to create these kind of indexes or we need to modify that.

    Thanks

    Ashish

  • I have removed this piece of code from source and now it is working fine. Why we have used it in script.

    JOIN sys.filegroups FG ON I.data_space_id=FG.data_space_id  

    Any idea?

  • I've used below UDF to wrap keycolumns and includedcolumns and get quotename formatted list of columns.

    Might need improvement as it corrupts field "Description"

    CREATE FUNCTION dbo.fn_quotecolumnlist(@input as varchar(1000))

    RETURNS varchar(1000)

    AS

    BEGIN

       Declare @iSpaces int

           Declare @part varchar(50)

    declare @result varchar(1000)

    declare @deliminator varchar(10)

    select @deliminator=',',@result=''

    select @input = @input + @deliminator

           --initialize spaces

           Select @iSpaces = charindex(@deliminator,@input,0)

           While @iSpaces > 0

           Begin

               Select @part = substring(@input,0,charindex(@deliminator,@input))

    IF @result <> ''

    select @result=@result+', '

    IF CHARINDEX('ASC',@part)> 0

    select @result=@result+QUOTENAME(LTRIM(RTRIM(REPLACE(@part,'ASC',''))))+' ASC'

    ELSE IF CHARINDEX('DESC',@part)> 0

    select @result=@result+QUOTENAME(LTRIM(RTRIM(REPLACE(@part,'DESC',''))))+' DESC'

    ELSE

    select @result=@result+QUOTENAME(LTRIM(RTRIM(REPLACE(@part,'DESC',''))))

       Select @input= substring(@input,charindex(@deliminator,@input)+ len(@deliminator),len(@input)

    --- charindex(' ',@input,0)

    )

               Select @iSpaces = charindex(@deliminator,@input,0)

           end

    RETURN @result

    END

  • Good one!

  • If the field-, table- or indexname has got characters eg '-' you have to use brackets [ and ]. I think this should be implemented everywhere

Page 1 of 1 (8 items)