Index fragmentation Script

  • Hi,

    Could someone has any script to suit following requirement

    Need to create Store Procedure which will first look into sys.dm_db_index_physical_stats view and cretae script for

    1) REORGANIZE when avg_fragmentation_in_percent value <30%

    2) REBUILD when avg_fragmentation_in_percent value >30%

    3) Incase if index is clustered in 2'nd case then create REBUILD TSQL Command for all noncluster index in that table.

    It should not automatically run but just need to create a Script with these TSQL Command.

    Thanks in advance

  • I'm not sure I understand your request entirely. Are you looking for a script to create the TSQL commands for you to use elsewhere or are you looking for a script to actually execute the commands?

    If you are just looking to generate the TSQL, you should be able to adapt this script to your needs by playing with the output in the CASE statement. In other words, you could change:

    when stats.avg_fragmentation_in_percent < 30 then 'Reorganize'

    to something like

    when stats.avg_fragmentation_in_percent < 30 then 'ALTER INDEX ' + i.name + ' REORGANIZE...'

    I've read that reorganizing/reindexing doesn't make much difference if the index is in the 5k to 10k page range. So this script doesn't look for anything under 5k pages.

    use AdventureWorks

    SELECT

    stats.object_id AS objectid,

    QUOTENAME(o.name) AS objectname,

    QUOTENAME(s.name) AS schemaname,

    stats.index_id AS indexid,

    i.name AS index_name,

    stats.partition_number AS partitionnum,

    stats.avg_fragmentation_in_percent AS frag,

    stats.page_count,

    CASE

    when stats.avg_fragmentation_in_percent < 30 then 'Reorganize'

    when stats.avg_fragmentation_in_percent > 30 then 'Rebuild'

    END AS 'action_to_take'

    FROM

    sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL , NULL, 'LIMITED') as stats,

    sys.objects AS o,

    sys.schemas AS s,

    sys.indexes AS i

    WHERE

    o.object_id = stats.object_id

    AND

    s.schema_id = o.schema_id

    AND

    i.object_id = stats.object_id

    AND

    i.index_id = stats.index_id

    AND

    stats.avg_fragmentation_in_percent >= 10.0

    AND

    stats.page_count >= 5000

    AND

    stats.index_id > 0

    ORDER BY

    action_to_take

  • I have a stored procedure that could help you with this. It is using the DMV

    sys.dm_db_index_physical_stats to dynamically rebuild / reorganize indexes based on the fragmentation levels.

    http://ola.hallengren.com/sql-server-index-and-statistics-maintenance.html

    Regarding 3) about rebuilding non clustered indexes based on the fragmentation of the clustered index. Is this a best practice? The stored procedure does not support this.

    Ola Hallengren

    http://ola.hallengren.com

  • Regarding 3) about rebuilding non clustered indexes based on the fragmentation of the clustered index. Is this a best practice? The stored procedure does not support this.

    Ola :- If clustered index need to be rebuild then don't we need to rebuild all non-clusted index on same table... I am not sure but i think rebuilding clustered index will not rebuild non-clustered automatically..

  • Rob Symonds

    Thanks for script ..

    This work fine but actually I need all ALTER TSQL will be in output so I just copy and then run .

    I just modified your script and now in action column I am getting all ALTER Script but it is difficult to take one by one and then run insted of this what I want is that I need all these TSQL Command in one output so i just need to run this once.

    SELECT

    stats.object_id AS objectid,

    QUOTENAME(o.name) AS objectname,

    QUOTENAME(s.name) AS schemaname,

    stats.index_id AS indexid,

    i.name AS index_name,

    stats.partition_number AS partitionnum,

    stats.avg_fragmentation_in_percent AS frag,

    stats.page_count,

    CASE

    when stats.avg_fragmentation_in_percent < 30 then 'ALTER INDEX ' + i.name + ' ON ' +o.name +' REORGANIZE'

    when stats.avg_fragmentation_in_percent > 30 then 'ALTER INDEX ' + i.name + ' ON ' +o.name +' REBUILD'

    END AS 'action_to_take'

    FROM

    sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL , NULL, 'LIMITED') as stats,

    sys.objects AS o,

    sys.schemas AS s,

    sys.indexes AS i

    WHERE

    o.object_id = stats.object_id

    AND

    s.schema_id = o.schema_id

    AND

    i.object_id = stats.object_id

    AND

    i.index_id = stats.index_id

    AND

    stats.avg_fragmentation_in_percent > 20.0

    AND

    stats.index_id > 0

    ORDER BY

    objectname

    Thanks in advance...

    example :- I need output like that

    ALTER INDEX PK__ACH_TRANSFER_DTL__00551192 ON ACH_TRANSFER_DTLS REBUILD

    ALTER INDEX PK__CONFIG_AUDIT_LOG__269AB60B ON CONFIG_AUDIT_LOG REBUILD

    ALTER INDEX PK__CUSTOMER_ACCOUNT__0425A276 ON CUSTOMER_ACCOUNT_VER_LOG REBUILD

    .... like all ALTER coomand which generated from this will be in output.

    Thanks!

  • >I am not sure but i think rebuilding clustered index will not rebuild non-clustered automatically..

    You're right on this. Please see Books Online.

    "Rebuilding a clustered index does not rebuild associated nonclustered indexes unless the keyword ALL is specified."

    http://msdn.microsoft.com/en-us/library/ms188388.aspx

    >If clustered index need to be rebuild then don't we need to rebuild all non-clusted index on same table

    As I understand it we only need to rebuild non clustered indexes if they are fragmented.

    Ola Hallengren

    http://ola.hallengren.com

  • >As I understand it we only need to rebuild non clustered indexes if they are fragmented.

    As what I understand is that Noncluster index will be pointing to cluster key so if we have to reuild Cluster index then we have to rebuild noncluster index also to point correct cluster key value and page.

    could you please clarify that what i think is right or it is not necessary to rebuild noncluste index even though cluster inde has been reuild.

    Thanks!

  • Ken Hendersen has a blog post about this.

    "If you think about it, it makes perfect sense—the clustered keys, which are the record locators in the NC indexes, aren’t changed merely because you rebuild the index. All rebuilding the index does is lay the pages back down. The rows may move around on the clustered index pages, but we don’t care because the NC indexes don’t use a RID to reference the data; they use the clustered key and have since SQL Server 7.0. "

    http://blogs.msdn.com/khen1234/archive/2007/02/27/does-rebuilding-a-clustered-index-rebuild-nonclustered-indexes.aspx

    Ola Hallengren

    http://ola.hallengren.com

  • Ola Hallengren

    Thanks Ola.. I was confused about rebuilding indexs..

    Could you suggest me any post where I can get info about Cluster and Non cluster index as how they work and how value are stored in non cluster so will be having better understanding about indexes..

    Thanks again

  • Paul Randal has a good blog post about this.

    http://blogs.msdn.com/sqlserverstorageengine/archive/2007/06/07/what-happens-to-non-clustered-indexes-when-the-table-structure-is-changed.aspx

    About the index optimization stored procedure it outputs things like this to the output file.

    DateTime: 2008-03-05 21:58:59

    Command: ALTER INDEX [IX_Address_StateProvinceID] ON

    [AdventureWorks].[Person].[Address] REORGANIZE

    Comment: IndexType: 2, LOB: 0, PageCount: 1001, Fragmentation: 7.40741

    DateTime: 2008-03-05 21:59:10

    Please try it out and let me know if you have any questions.

    http://ola.hallengren.com/sql-server-index-and-statistics-maintenance.html

    Ola Hallengren

    http://ola.hallengren.com

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

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