Index rebuild fragmentation criteria confusion

  • There is tons of info regarding selective index rebuild/reorganize (with magic numbers 10-30%) depending on output of DMV sys.dm_db_index_physical_stats. But I confused with what particular values from this DMV I should use for my index rebuild

    procedure?

    I mean some sources (BOL script example, etc) suggest to use avg_fragmentation_in_percent only (i.e. external fragmentation- EF), others- to add internal fragmentation (IF) value also- if avg_page_space_used_in_percent is less than 75%- it's bad.

    Let say I consider only indexes with size 1000+ pages

    Really appreciate help in clarifying this issue- EF or EF + IF?

    Mainly I am interested in- Why?

    Thanks

  • You should consider the page density (Internal Frag) in addition to the External Fragmentation. And the value to consider for internal frag depends on your data and page density settings. If you have not altered your fillfactor from the default and you have avg_page_space_used of 75% and 1000 pages, you have incurred about an extra 250 pages. If you then need to scan the table you can be looking at that much more processing that needs to be done.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • It makes sense to consider internal fragmentation while making decision to rebuild indexes- why in this case majority scripts/advices (including mentioned BOL sample) do not care about it (only external one)? Thanks

  • what i think here , external fragmentation is basically handled by sql server internally and data get inserted in mixed extent initially (i think we can keep "table having identity col's PK" out here ) later on data moves into contigous extent. this could be reason why external fragmentation get avoided.

    I welcome comments here 🙂

    -------Bhuvnesh----------
    I work only to learn Sql Server...though my company pays me for getting their stuff done;-)

  • Yuri55 (1/5/2013)


    It makes sense to consider internal fragmentation while making decision to rebuild indexes- why in this case majority scripts/advices (including mentioned BOL sample) do not care about it (only external one)? Thanks

    Because it's easier.

    Because most of the recommendations (which date back years if not decades) look at logical fragmentation only.

    p.s. Internal and External fragmentation can be confusing terms, depending what the internal and external refer to. Easier and less prone to misunderstandings to call them logical fragmentation and low page density.

    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
  • Bhuvnesh (1/6/2013)


    external fragmentation is basically handled by sql server internally

    No, it's not. Fixing 'external fragmentation' requires an index rebuild or index reorganise.

    and data get inserted in mixed extent initially (i think we can keep "table having identity col's PK" out here ) later on data moves into contigous extent. this could be reason why external fragmentation get avoided.

    The external fragmentation he's talking about is not extent fragmentation. It's logical fragmentation, pages having their physical order not matching their logical order.

    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
  • Thanks guys for all your answers-

    just to summarize- for index maintenance we need to take into account both logical fragmentation and page density. Still have couple questions left: 1) index size 1000+ pages recommendation for any action- valid for ReBuild and ReOrganize? 2) page density below 75%- index Rebuild or Reorganize?

    Thanks

  • Yuri55 (1/6/2013)


    Thanks guys for all your answers-

    just to summarize- for index maintenance we need to take into account both logical fragmentation and page density. Still have couple questions left:

    1) index size 1000+ pages recommendation for any action- valid for ReBuild and ReOrganize?

    If it is below 1000 pages chances are index maintenance will not make much difference so most of the scripts out there skip those smaller indexes regardless of the fragmentation level.

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • 2) page density below 75%- index Rebuild or Reorganize?

    It depends on the fillfactor. If you chose 80% you may not want to perform maintenance if page density is at 75%.

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

Viewing 9 posts - 1 through 8 (of 8 total)

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