auto generated script for ALTER INDEX

  • Hi,

    Fragmentation of > 30% will use this method. this is working fine in SQL 2005 and 2008 box, Could you give me script for compatible SQL 2000 version.

    --alter index Index_Name on Table_Name rebuild

    declare @PageCount bigint

    set @PageCount = 1000

    select

    [Table] = object_name(stats.[object_id])

    ,[Index]= si.[name]

    ,[Avg Fragmentation] = cast(stats.[avg_fragmentation_in_percent] as numeric (6,4))

    ,[Page Count] = stats.[page_count]

    ,[SQL script] = case

    when (stats.[avg_fragmentation_in_percent] < = 30)

    then 'alter index ['+ si.[name] +'] on ['+ object_name(stats.[object_id]) +'] reorganize'

    when (stats.[avg_fragmentation_in_percent] > 30)

    then 'alter index ['+ si.[name] +'] on ['+ object_name(stats.[object_id]) +'] rebuild'

    end

    from sys.dm_db_index_physical_stats (db_id(), null, null, null, 'LIMITED') as stats

    join sys.indexes as si on stats.object_id = si.object_id

    and stats.[index_id] = si.[index_id]

    where stats.[avg_fragmentation_in_percent] > 10.0

    and si.index_id > 0

    and stats.[page_count] >= @PageCount

    order by 3 desc, 1, 2;

    Thanks

    ananda

  • You can use DBCC SHOWCONTIG

    Here is the script that we use, it was developed by Microsoft and you can find it here

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

    T-SQL:

    /*Perform a 'USE <database name>' to select the database in which to run the script.*/

    -- Declare variables

    SET NOCOUNT ON;

    DECLARE @tablename varchar(255);

    DECLARE @execstr varchar(400);

    DECLARE @objectid int;

    DECLARE @indexid int;

    DECLARE @frag decimal;

    DECLARE @maxfrag decimal;

    -- Decide on the maximum fragmentation to allow for.

    SELECT @maxfrag = 30.0;

    -- Declare a cursor.

    DECLARE tables CURSOR FOR

    SELECT TABLE_SCHEMA + '.' + TABLE_NAME

    FROM INFORMATION_SCHEMA.TABLES

    WHERE TABLE_TYPE = 'BASE TABLE';

    -- Create the table.

    CREATE TABLE #fraglist (

    ObjectName char(255),

    ObjectId int,

    IndexName char(255),

    IndexId int,

    Lvl int,

    CountPages int,

    CountRows int,

    MinRecSize int,

    MaxRecSize int,

    AvgRecSize int,

    ForRecCount int,

    Extents int,

    ExtentSwitches int,

    AvgFreeBytes int,

    AvgPageDensity int,

    ScanDensity decimal,

    BestCount int,

    ActualCount int,

    LogicalFrag decimal,

    ExtentFrag decimal);

    -- Open the cursor.

    OPEN tables;

    -- Loop through all the tables in the database.

    FETCH NEXT

    FROM tables

    INTO @tablename;

    WHILE @@FETCH_STATUS = 0

    BEGIN

    -- Do the showcontig of all indexes of the table

    INSERT INTO #fraglist

    EXEC ('DBCC SHOWCONTIG (''' + @tablename + ''')

    WITH FAST, TABLERESULTS, ALL_INDEXES, NO_INFOMSGS');

    FETCH NEXT

    FROM tables

    INTO @tablename;

    END;

    -- Close and deallocate the cursor.

    CLOSE tables;

    DEALLOCATE tables;

    -- Declare the cursor for the list of indexes to be defragged.

    DECLARE indexes CURSOR FOR

    SELECT ObjectName, ObjectId, IndexId, LogicalFrag

    FROM #fraglist

    WHERE LogicalFrag >= @maxfrag

    AND INDEXPROPERTY (ObjectId, IndexName, 'IndexDepth') > 0;

    -- Open the cursor.

    OPEN indexes;

    -- Loop through the indexes.

    FETCH NEXT

    FROM indexes

    INTO @tablename, @objectid, @indexid, @frag;

    WHILE @@FETCH_STATUS = 0

    BEGIN

    PRINT 'Executing DBCC INDEXDEFRAG (0, ' + RTRIM(@tablename) + ',

    ' + RTRIM(@indexid) + ') - fragmentation currently '

    + RTRIM(CONVERT(varchar(15),@frag)) + '%';

    SELECT @execstr = 'DBCC INDEXDEFRAG (0, ' + RTRIM(@objectid) + ',

    ' + RTRIM(@indexid) + ')';

    EXEC (@execstr);

    FETCH NEXT

    FROM indexes

    INTO @tablename, @objectid, @indexid, @frag;

    END;

    -- Close and deallocate the cursor.

    CLOSE indexes;

    DEALLOCATE indexes;

    -- Delete the temporary table.

    DROP TABLE #fraglist;

    GO

    QUIGROUP- Need a Certified experienced DBA for a project or troubleshooting? Need help with programming, database recovery, performance tuning, ETL, SSRS or developing new databases? Contact us.. 1-786-273-9809

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

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