Home Forums SQL Server 2008 T-SQL (SS2K8) how to find duplicate indexes in all the tables in a database RE: how to find duplicate indexes in all the tables in a database

  • dwain.c (9/17/2012)


    Perhaps I should have noted that the query I provided was just something I threw together.

    The two points you mention are probably valid for consideration. I wouldn't want to use the results of the query to simply DROP indexes that the script says are duplicates. A little analysis should be performed on the results to decide what is appropriate to DROP and what not.

    Having said that though, the INCLUDEs can probably be resolved. An interesting point that I may look into, as I happen to need this for something else anyway.

    Hi,

    By no means I meant to question your query.. just wanted to alert to the fact that the include columns aren't considered as include but as normal columns.

    I took the liberty to change the query so it does that.

    WITH IndexColumns AS (

    SELECT DISTINCT a.object_id, a.name, a.type_desc, b.column_id, TABLE_NAME=c.name, [COL NAME]=d.name, b.is_included_column

    FROM sys.indexes a

    INNER JOIN sys.index_columns b ON a.object_id = b.object_id AND a.index_id = b.index_id

    INNER JOIN sys.tables c ON b.object_id = c.object_id

    INNER JOIN sys.columns d ON c.object_id = d.object_id AND b.column_id = d.column_id

    WHERE is_hypothetical = 0

    ),

    CombineCols AS (

    SELECT object_id, name, type_desc, table_name

    ,columns=STUFF((

    SELECT ',' + [COL NAME]

    FROM IndexColumns b

    WHERE a.object_id = b.object_id AND

    a.name = b.name AND

    a.type_desc = b.type_desc AND

    a.TABLE_NAME = b.TABLE_NAME AND b.is_included_column = 0

    ORDER BY [COL NAME]

    FOR XML PATH(''), TYPE).value('.', 'VARCHAR(MAX)'), 1, 1, '')

    ,include_columns=ISNULL(STUFF((

    SELECT ',' + [COL NAME]

    FROM IndexColumns b

    WHERE a.object_id = b.object_id AND

    a.name = b.name AND

    a.type_desc = b.type_desc AND

    a.TABLE_NAME = b.TABLE_NAME AND b.is_included_column = 1

    ORDER BY [COL NAME]

    FOR XML PATH(''), TYPE).value('.', 'VARCHAR(MAX)'), 1, 1, ''), '')

    FROM IndexColumns a

    GROUP BY object_id, name, type_desc, table_name)

    SELECT b.type_desc, a.table_name, a.columns, a.include_columns, b.name

    FROM (

    SELECT table_name, columns, include_columns

    FROM CombineCols

    GROUP BY table_name, columns, include_columns

    HAVING COUNT(name) > 1) a

    INNER JOIN CombineCols b

    ON a.table_name = b.table_name AND

    a.columns = b.columns AND

    a.include_columns = b.include_columns

    ORDER BY a.table_name, a.columns

    dwain.c (9/17/2012)


    I believe in the second case, the two indexes would not be considered duplicates (by my script). I believe I would call that a case of "overlapping indexes" rather than identical ones. A case that could probably be handled if needed.

    They are not considered duplicates, my question is completely out of this "subject"... A table with an index with (col1, col2) and another index with (col1, col2, col3) according to the execution plan always uses the 2nd index... Shouldn't "sub-indexes" be considered also duplicates?!

    Thanks,

    Pedro



    If you need to work better, try working less...