Is it right way to add filtered column as main column for creating filtered index

  • Hi

    I have a query like below. table contains 70 million records

    select MIN(createtime) _time_ from tablename

    where status <> 20 and type_id = 44

    and createtime > GETDATE() -3

    I want to create index like below

    CREATE NONCLUSTERED INDEX indexname ON table_name

    ( status, type_id , createtime) WHERE status<>(20)

    since status column is a filter condition is it good way to add status column as main column list also for the index.

    Can any one suggest me how it will make difference.

  • dudekula.kareemulla (12/9/2016)


    Hi

    I have a query like below. table contains 70 million records

    select MIN(createtime) _time_ from tablename

    where status <> 20 and type_id = 44

    and createtime > GETDATE() -3

    I want to create index like below

    CREATE NONCLUSTERED INDEX indexname ON table_name

    ( status, type_id , createtime) WHERE status<>(20)

    since status column is a filter condition is it good way to add status column as main column list also for the index.

    Can any one suggest me how it will make difference.

    type-id is an equality filter, so I would add it as the leading edge of the index.

    status is simply a filter, and not used in the sample query, so I would exclude it.

    CREATE NONCLUSTERED INDEX indexname

    ON table_name ( type_id, createtime )

    WHERE status <> 20

    Then again how many statuses are there? It may be beneficial to not filter the index and just use

    CREATE NONCLUSTERED INDEX indexname

    ON table_name ( type_id, createtime, status )

  • DesNorton (12/9/2016)


    Then again how many statuses are there? It may be beneficial to not filter the index and just use

    CREATE NONCLUSTERED INDEX indexname

    ON table_name ( type_id, createtime, status )

    I'd go with this, unless status 20 is 90% or so of the table. Filtered indexes get a little finicky sometimes.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass

Viewing 3 posts - 1 through 2 (of 2 total)

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