sqlschool.gr logo

articles

Articles of SQLschool.gr Team

Scripts for rebuild or reorganize indexes in a database

Antonios Chatzipavlis
Saturday 11 July 2015

Επανέρχομαι σε ένα αρχέγονο ερώτημα απαντώντας με ένα πρακτικό τρόπο σε σχέση με το πώς έχω απαντήσει στο παρελθόν.

Ο λόγος δεν είναι για να αναθεωρήσω αυτά που έχω ήδη πει (δείτε εδώ) αλλά για να ενισχύσω αυτά με πρακτικό τρόπο καθώς έχω καταλάβει ότι το πρόβλημα είναι στην εφαρμογή τους.

Σε αυτό το άρθρο σας εξοπλίζω με δύο scripts τα οποία μπορείτε να χρησιμοποιήσετε σε ένα schedule job που μπορείτε να το βάλετε σε χρόνους που δεν έχετε φόρτο στα συστήματα σας πχ. Σαββατοκύριακο.

Ίσως στην πρώτη εκτέλεση του το impact να είναι λίγο μεγάλο, ιδιαίτερα αν δεν έχετε ποτέ ασχοληθεί με την συντήρηση των indexes που υπάρχουν σε μια database.  Στην πορεία όμως αυτό θα είναι ελάχιστο.

Και τα δύο κάνουν την ίδια δουλειά και η διαφορά είναι ότι το δεύτερο γράφει στα SQL Server logs. Διαλέξτε ποιο από τα δύο ταιριάζει σε εσάς και απλά χρησιμοποιήστε το.

Script χωρίς logging

declare @stm nvarchar(max) = '';
SELECT    @stm+=
        + 'ALTER INDEX ' + QUOTENAME(IDX.name) 
        + ' ON ' 
        + QUOTENAME(OBJECT_SCHEMA_NAME(idx.object_id)) 
        + '.' 
        + QUOTENAME(OBJECT_NAME(idx.object_id)) 
        + IIF ( S.avg_fragmentation_in_percent < 30.0 ,' REORGANIZE ', ' REBUILD ' ) 
        + IIF ( (SELECT COUNT(*) FROM sys.partitions AS p WHERE (p.object_id = idx.object_id) AND (p.index_id = s.index_id) ) > 1  
        , ' PARTITION = ' + cast(s.partition_number as nvarchar(10)), '') 
        + IIF ( S.avg_fragmentation_in_percent < 30.0 ,'', ' WITH (MAXDOP=1,ONLINE=ON) ' ) 
        + ';' 
        + char(13) 
FROM    sys.dm_db_index_physical_stats(DB_ID(), DEFAULT, DEFAULT, DEFAULT, 'LIMITED') AS S
        JOIN sys.indexes AS IDX ON IDX.OBJECT_ID = S.OBJECT_ID AND IDX.index_id = S.index_id
WHERE    s.page_count > 1000
    AND 
    s.avg_fragmentation_in_percent > 5.00
    AND
    s.index_id > 0 
ORDER BY OBJECT_SCHEMA_NAME(idx.object_id),OBJECT_NAME(idx.object_id),s.index_id,IDX.name,s.partition_number ;
if ( LEN(@stm) > 0 ) exec (@stm);

Script με logging

DECLARE idx CURSOR READ_ONLY FOR 
SELECT    'ALTER INDEX ' + QUOTENAME(IDX.name) 
    + ' ON ' 
    + QUOTENAME(OBJECT_SCHEMA_NAME(idx.object_id)) 
    + '.' 
    + QUOTENAME(OBJECT_NAME(idx.object_id)) 
    + IIF ( S.avg_fragmentation_in_percent < 30.0 ,' REORGANIZE ', ' REBUILD ' ) 
    + IIF ( (SELECT COUNT(*) FROM sys.partitions AS p WHERE (p.object_id = idx.object_id) AND (p.index_id = s.index_id) ) > 1  
        , ' PARTITION = ' + cast(s.partition_number as nvarchar(10)), '') 
    + IIF ( S.avg_fragmentation_in_percent < 30.0 ,'', ' WITH (MAXDOP=1,ONLINE=ON) ' ) 
    + ';' 
    + char(13) 
FROM    sys.dm_db_index_physical_stats(DB_ID(), DEFAULT, DEFAULT, DEFAULT, 'LIMITED') AS S
        JOIN sys.indexes AS IDX ON IDX.OBJECT_ID = S.OBJECT_ID AND IDX.index_id = S.index_id
WHERE    s.page_count > 1000
    AND 
    s.avg_fragmentation_in_percent > 5.00
    AND
    s.index_id > 0 
ORDER BY OBJECT_SCHEMA_NAME(idx.object_id),OBJECT_NAME(idx.object_id),s.index_id,IDX.name,s.partition_number ;

DECLARE @msg nvarchar(max);
DECLARE @stm nvarchar(max);
OPEN idx

FETCH NEXT FROM idx INTO @stm
WHILE (@@fetch_status <> -1)
BEGIN
    IF (@@fetch_status <> -2)
    BEGIN
        SET @msg = 'Starting '+ @stm  
        RAISERROR (@msg,10,1) WITH LOG;
        
        EXEC (@stm); 

        SET @msg = 'Finished '+ @stm  
        RAISERROR (@msg,10,1) WITH LOG;
    END
    FETCH NEXT FROM idx INTO @stm
END

CLOSE idx;

DEALLOCATE idx;

/*antonch*/

Antonios Chatzipavlis

Antonios Chatzipavlis

Antonios is a Data Solutions Consultant and Trainer. He has been working in IT since 1988. In his career, he has worked as senior developer, IT Manager, Solutions Architect and IT Consultant. Since 1995 he has been devoted on new technologies and software development tools, mainly by Microsoft, either by training company staff and colleagues or assisting them in design, development and implementation as a consultant or chief developer. He has focused in Databases and Data Science since 1995. He specialized in Microsoft SQL Server since version 6.0 in areas like SQL Server Internals, Database Design and Development, Business Intelligence and in 2010 he has started working with Azure Data Platform, NoSQL databases, Big Data Technologies and Machine Learning. He is an active member of many IT communities in Greece, answering colleagues' questions and writing articles in his web site. He is the owner of SQLschool.gr which is a community portal with a lot of information about Microsoft SQL Server. He has been a Microsoft Certified Trainer (MCT) since 2000. Microsoft honored him as MVP on Data Platform due to his activities in SQL Server since 2010. He holds a large number of Microsoft Certifications and Microsoft SQL Server Certifications since version 6.5.

Episode

First look: SQL Database in Microsoft Fabric

image

More Episodes...

Tip

What's New in SQL Server 2022 - Episodes

More Tips...

Become a member

If you want to receive updates from us become a member to our community.

Connect

Explore

Learn


sqlschool.gr © 2010-2024 All rights reserved

This site uses cookies for operational and analytics purposes only. By continuing to browse this site, you agree to their use.