query to find missing indexes

  • Hi,

    does any one have a good script to find if there are missing indexes for the must running queries first and then all other queries with run times count?

    THX

  • Try this link.



    Lutz
    A pessimist is an optimist with experience.

    How to get fast answers to your question[/url]
    How to post performance related questions[/url]
    Links for Tally Table [/url] , Cross Tabs [/url] and Dynamic Cross Tabs [/url], Delimited Split Function[/url]

  • hi,

    I've already done that...

    beside of the missing indexes how can i see the query that runs that needs this index?

  • I find that if I have a profiler trace representative of normal activity the queries are fairly obvious if you search on the table name, the more so the higher the effect af adding the index is calculated at. If you feed the profiler trace into the DTA one of the reports identifies the queries that benefit from the suggested indexes. You can also run one of the queries in SSMS (2008 and above) requesting the actual execution plan and info on missing indexes will be returned, enabling you to confirm you have the right query.

    --This code tells you which queries are using an index

    SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED

    DECLARE @IndexName AS NVARCHAR(128);

    set @IndexName = 'your index name';

    -- Make sure the name passed is appropriately quoted

    IF (LEFT(@IndexName, 1) <> '[' AND RIGHT(@IndexName, 1) <> ']') SET @IndexName = QUOTENAME(@IndexName);

    --Handle the case where the left or right was quoted manually but not the opposite side

    IF LEFT(@IndexName, 1) <> '[' SET @IndexName = '['+@IndexName;

    IF RIGHT(@IndexName, 1) <> ']' SET @IndexName = @IndexName + ']';

    -- Dig into the plan cache and find all plans using this index

    ;WITH XMLNAMESPACES

    (DEFAULT 'http://schemas.microsoft.com/sqlserver/2004/07/showplan')

    SELECT

    stmt.value('(@StatementText)[1]', 'varchar(max)') AS SQL_Text,

    obj.value('(@Database)[1]', 'varchar(128)') AS DatabaseName,

    obj.value('(@Schema)[1]', 'varchar(128)') AS SchemaName,

    obj.value('(@Table)[1]', 'varchar(128)') AS TableName,

    obj.value('(@Index)[1]', 'varchar(128)') AS IndexName,

    obj.value('(@IndexKind)[1]', 'varchar(128)') AS IndexKind,

    cp.plan_handle,

    query_plan

    FROM sys.dm_exec_cached_plans AS cp

    CROSS APPLY sys.dm_exec_query_plan(plan_handle) AS qp

    CROSS APPLY query_plan.nodes('/ShowPlanXML/BatchSequence/Batch/Statements/StmtSimple') AS batch(stmt)

    CROSS APPLY stmt.nodes('.//IndexScan/Object[@Index=sql:variable("@IndexName")]') AS idx(obj)

    OPTION(MAXDOP 1, RECOMPILE);

    ---------------------------------------------------------------------

  • I have a query that uses the execution plans in cache to identify potential missing indexes[/url]. Just remember though, these are just potential candidates. You should thoroughly evaluate the recommendations.

    ----------------------------------------------------The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood... Theodore RooseveltThe Scary DBAAuthor of: SQL Server 2017 Query Performance Tuning, 5th Edition and SQL Server Execution Plans, 3rd EditionProduct Evangelist for Red Gate Software

  • At a minimum, you need to look at missing index stats and usage stats. (Beyond min, you would include sys.dm_db_index_operational_stats.)

    Below are queries that will list what you need. Before running, change the bolded lines to match your requirements.

    Warning: you need someone knowledgeable about indexes to interpret these results. SQL will almost always suggest many more indexes than should actually be built.

    Edit: Since the missing index query can take quite a while to run, it can be cancelled by setting "@list_missing_indexes" to 0.

    --!! chg to your db name

    USE [<your_db_name>]

    SET DEADLOCK_PRIORITY LOW --probably irrelevent, but just in case

    DECLARE @list_missing_indexes bit

    DECLARE @table_name_pattern sysname

    SET @list_missing_indexes = 1 --1=list missing index(es); 0=don't.

    --!! put your table name/name pattern here

    SET @table_name_pattern = '%' --%=all tables;.

    PRINT 'Started @ ' + CONVERT(varchar(30), GETDATE(), 120)

    --SELECT create_date FROM sys.databases WITH (NOLOCK) WHERE name = N'tempdb'

    IF @list_missing_indexes = 1

    BEGIN

    SELECT

    GETDATE() AS capture_date,

    DB_NAME(mid.database_id) AS Db_Name,

    OBJECT_NAME(mid.object_id /*, mid.database_id*/) AS Table_Name,

    mid.equality_columns, mid.inequality_columns, mid.included_columns,

    ca1.sql_up_days AS days_in_use,

    migs.*,

    mid.statement, mid.object_id, mid.index_handle

    FROM sys.dm_db_missing_index_details mid WITH (NOLOCK)

    CROSS APPLY (

    SELECT DATEDIFF(DAY, create_date, GETDATE()) AS sql_up_days FROM sys.databases WHERE name = 'tempdb'

    ) AS ca1

    LEFT OUTER JOIN sys.dm_db_missing_index_groups mig WITH (NOLOCK) ON

    mig.index_handle = mid.index_handle

    LEFT OUTER JOIN sys.dm_db_missing_index_group_stats migs WITH (NOLOCK) ON

    migs.group_handle = mig.index_group_handle

    --order by

    --DB_NAME, Table_Name, equality_columns

    WHERE

    1 = 1

    AND mid.database_id = DB_ID()

    AND OBJECT_NAME(mid.object_id) LIKE @table_name_pattern

    ORDER BY

    --avg_total_user_cost * (user_seeks + user_scans) DESC,

    Db_Name, Table_Name, equality_columns, inequality_columns

    END --IF

    -- list index usage stats (seeks, scans, etc.)

    SELECT

    ius2.row_num, DB_NAME() AS db_name,

    i.name AS index_name,

    OBJECT_NAME(i.object_id/*, DB_ID()*/) AS table_name,

    i.index_id, --ius.user_seeks + ius.user_scans AS total_reads,

    dps.row_count,

    SUBSTRING(key_cols, 3, 8000) AS key_cols, SUBSTRING(nonkey_cols, 3, 8000) AS nonkey_cols,

    ius.user_seeks, ius.user_scans, ius.user_lookups, ius.user_updates,

    ius.last_user_seek, ius.last_user_scan, ius.last_user_lookup, ius.last_user_update,

    fk.Reference_Count AS fk_ref_count,

    FILEGROUP_NAME(i.data_space_id) AS filegroup_name,

    ca1.sql_up_days AS days_in_use,

    ius.system_seeks, ius.system_scans, ius.system_lookups, ius.system_updates,

    ius.last_system_seek, ius.last_system_scan, ius.last_system_lookup, ius.last_system_update

    FROM sys.indexes i WITH (NOLOCK)

    INNER JOIN sys.objects o WITH (NOLOCK) ON

    o.object_id = i.object_id

    CROSS APPLY (

    SELECT DATEDIFF(DAY, create_date, GETDATE()) AS sql_up_days FROM sys.databases WHERE name = 'tempdb'

    ) AS ca1

    OUTER APPLY (

    SELECT

    ', ' + COL_NAME(object_id, ic.column_id)

    FROM sys.index_columns ic

    WHERE

    ic.key_ordinal > 0 AND

    ic.object_id = i.object_id AND

    ic.index_id = i.index_id

    ORDER BY

    ic.key_ordinal

    FOR XML PATH('')

    ) AS key_cols (key_cols)

    OUTER APPLY (

    SELECT

    ', ' + COL_NAME(object_id, ic.column_id)

    FROM sys.index_columns ic

    WHERE

    ic.key_ordinal = 0 AND

    ic.object_id = i.object_id AND

    ic.index_id = i.index_id

    ORDER BY

    COL_NAME(object_id, ic.column_id)

    FOR XML PATH('')

    ) AS nonkey_cols (nonkey_cols)

    LEFT OUTER JOIN sys.dm_db_partition_stats dps WITH (NOLOCK) ON

    dps.object_id = i.object_id AND

    dps.index_id = i.index_id

    LEFT OUTER JOIN sys.dm_db_index_usage_stats ius WITH (NOLOCK) ON

    ius.database_id = DB_ID() AND

    ius.object_id = i.object_id AND

    ius.index_id = i.index_id

    LEFT OUTER JOIN (

    SELECT

    database_id, object_id, MAX(user_scans) AS user_scans,

    ROW_NUMBER() OVER (ORDER BY MAX(user_scans) DESC) AS row_num --user_scans|user_seeks+user_scans

    FROM sys.dm_db_index_usage_stats WITH (NOLOCK)

    WHERE

    database_id = DB_ID()

    --AND index_id > 0

    GROUP BY

    database_id, object_id

    ) AS ius2 ON

    ius2.database_id = DB_ID() AND

    ius2.object_id = i.object_id

    LEFT OUTER JOIN (

    SELECT

    referenced_object_id, COUNT(*) AS Reference_Count

    FROM sys.foreign_keys WITH (NOLOCK)

    WHERE

    is_disabled = 0

    GROUP BY

    referenced_object_id

    ) AS fk ON

    fk.referenced_object_id = i.object_id

    WHERE

    i.object_id > 100 AND

    i.is_hypothetical = 0 AND

    i.type IN (0, 1, 2) AND

    o.type NOT IN ( 'IF', 'IT', 'TF', 'TT' ) AND

    (

    o.name LIKE @table_name_pattern AND

    o.name NOT LIKE 'dtprop%' AND

    o.name NOT LIKE 'filestream[_]' AND

    o.name NOT LIKE 'MSpeer%' AND

    o.name NOT LIKE 'MSpub%' AND

    --o.name NOT LIKE 'queue[_]%' AND

    o.name NOT LIKE 'sys%'

    )

    --AND OBJECT_NAME(i.object_id, DB_ID()) IN ('tbl1', 'tbl2', 'tbl3')

    ORDER BY

    --row_count DESC,

    --ius.user_scans DESC,

    --ius2.row_num, --user_scans+user_seeks

    -- list clustered index first, if any, then other index(es)

    db_name, table_name, CASE WHEN i.index_id IN (0, 1) THEN 1 ELSE 2 END, index_name

    PRINT 'Ended @ ' + CONVERT(varchar(30), GETDATE(), 120)

    SQL DBA,SQL Server MVP(07, 08, 09) "Money can't buy you happiness." Maybe so, but it can make your unhappiness a LOT more comfortable!

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply