INDEX REBUILD

  • Here is what I did

    1. Ran the following command

    ALTER INDEX ALL ON APPOINTMENTS Rebuild;

    2. Ran the following query

    select index_id, avg_page_space_used_in_percent,

    avg_fragmentation_in_percent

    from

    sys.dm_db_index_physical_stats( DB_ID('NGDEVL'), OBJECT_ID ('appointments'),NULL, NULL, 'DETAILED' )

    WHERE

    index_id <> 0

    3. The results seems find except for one little problem ( Please see attached index.jpg)

    Why is Sql server telling me that the avg_fragmentation_in_percent for index 1 is 75 ?

    I thought after doing a rebuild it should say 0 for all indexes ?

  • How big is the index in question? How many pages?

    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
  • You will be surprised. This table does not have more than 100 rows.

  • Not surprised in the slightest, that's exactly what I expected.

    For reasons that have to do with the way the first few pages are allocated, there's virtually no point in rebuilding an index that occupies less than 24 pages. It's generally recommended not to worry about fragmentation for indexes with less than 1000 pages.

    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
  • What would be the command to use to drop a particular index and then recreate it ?

    What I mean is I'd like to build the index but not have to worry about the details ( how it was originally defined ).

    Is there a general command available ?

  • Drop/create?

    Create index ... with drop existing?

    Alter index ... disable/rebuild?

    What's the point? What are you trying to achieve?

    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
  • mw112009 (6/14/2010)


    What I mean is I'd like to build the index but not have to worry about the details

    what does it mean ?

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

  • OK here is my point.

    Lets go to the begining of this thread.

    Here is what I did

    1. Ran the following command

    ALTER INDEX ALL ON APPOINTMENTS Rebuild;

    2. Ran the following query

    select index_id, avg_page_space_used_in_percent,

    avg_fragmentation_in_percent

    from

    sys.dm_db_index_physical_stats( DB_ID('NGDEVL'), OBJECT_ID ('appointments'),NULL, NULL, 'DETAILED' )

    WHERE

    index_id <> 0

    3. The query says that the fragmentation rate is 75 on index 1 ( I mean even after doing a rebuild why do a I get a fragmentation rate of 75 only on one particular index ? )

    4. I also mentioned that the table had less than 100 rows.

    5. So then why is SQl server returning wrong information ?

    6. How else can we rebuild the indexes so that we get a fragmentation rate of 0 for all indexes. Is there another command out there that I don't know ( besides the Alter Index... Rebuild command )

  • mw112009 (6/15/2010)


    3. The query says that the fragmentation rate is 75 on index 1 ( I mean even after doing a rebuild why do a I get a fragmentation rate of 75 only on one particular index ? )

    Because the index is too small for rebuild to have much if any effect.

    4. I also mentioned that the table had less than 100 rows.

    And i mentioned that it is not worth worrying about fragmentation for indexes under about 1000 pages

    5. So then why is SQl server returning wrong information ?

    It's not, it's perfectly correct, the fragmentation of that index is 75%

    6. How else can we rebuild the indexes so that we get a fragmentation rate of 0 for all indexes. Is there another command out there that I don't know ( besides the Alter Index... Rebuild command )

    There's no guarantee that any index rebuild of any form will leave you with 0% fragmentation. Don't worry about small amounts of fragmentation and don't worry about fragmentation on very small indexes. I'm willing to bet this index is 4 pages in size, well under the size where you should start worrying.

    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
  • So is there a command out there that I can use to count the size of the index in pages ?

    You mentioned the size of the above index may be less than 4 pages ? How do we find that out ?

  • It's in the same DMV that you're using to find fragmentation - sys.dm_db_index_physical_stats. The column is called page_count.

    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
  • Please ignore my question above. I found the answer. There is a field by the name "page_count"

    that is returned by the query.

    Question: So you are saying if a index has a page_count > 4 and if the fragmentation percentage

    is above 60 ( or 75 ) it is worth doing a rebuild.

  • In one of the posts above you mentioned the following:

    There's no guarantee that any index rebuild of any form will leave you with 0% fragmentation. Don't worry about small amounts of fragmentation and don't worry about fragmentation on very small indexes. I'm willing to bet this index is 4 pages in size, well under the size where you should start worrying.

    So then at what page count should we consider rebuilding an index ?

  • Will you please read what I'm saying...

    GilaMonster (6/14/2010)


    For reasons that have to do with the way the first few pages are allocated, there's virtually no point in rebuilding an index that occupies less than 24 pages. It's generally recommended not to worry about fragmentation for indexes with less than 1000 pages.

    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
  • Just out of curiosity, is there a bulk command that I can issue that will take care of all the indexes

    in the database ( I am just wondering how those dba's do this when they have about 2000 tables in their database )

Viewing 15 posts - 1 through 15 (of 27 total)

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