By: Greg Robidoux | Updated: 2007-01-25 | Comments (14) | Related: > Fragmentation and Index Maintenance
Problem
There are several things that should be done on a regular basis and one of these things is to manage database fragmentation. Depending on the tables, queries and indexes that are being used fragmentation can cause performance issues as well as using unnecessary space in the database. Database fragmentation is similar to disk fragmentation in that the data is stored in various places in the database file instead of sequentially or next to like data within the database. This often occurs where you have non-sequential keys and the constant inserting, updating and deleting of data causes the data to become fragmented as well as the use of additional data pages to store the data. So what steps should be taken?
Solution
The first step in managing fragmentation is to better understand what tables and indexes are fragmented and then to determine what steps to take for rebuilding indexes.
For small databases the normal practice is to use a Maintenance Plan to rebuild indexes across the board for all indexes. With SQL Server 2005 Maintenance Plans you have the option to specify which indexes to rebuild at a table level, but not at an individual index level. This is a great option if the database is not that large or if you have primarily small tables, but as the database and tables get larger this could become an issue because of the time that it will take to complete the operation. In addition, when using Maintenance Plans for SQL Server 2000 the only option is to rebuild the index, but with SQL Server 2005 you have the option to either do an index rebuild or an index reorganize.
To rebuild or reorganize indexes you can use the DBCC DBEREINDEX or DBCC INDEXDEFRAG statements. In addition, you can use the ALTER INDEX statement for SQL 2005 and later versions.
The differences between an index reorganize and an index rebuild are as follows:
Option | DBCC DBREINDEX (SQL 2000) ALTER INDEX REBUILD (SQL 2005 and later) |
DBCC INDEXDEFRAG (SQL 2000) ALTER INDEX REORGANIZE (SQL 2005 and later) |
---|---|---|
Rebuild All Indexes | Yes | Need to run for each index. In SQL 2005 using the ALTER INDEX you can specify ALL indexes. |
Online Operation | No, users will be locked out until complete. In SQL Server 2005 Enterprise Edition you can build indexes online. | Yes, users can still use the table |
Transaction Log Impact | Depends on the recovery model of the database | Fully logged operation regardless of the database recovery model |
Transaction Log Impact | If set to the full recovery model can consume a lot of space for operation to complete. | If index is very fragmented this could potentially take up more transaction log space. |
Can run in parallel (uses multiple threads) | Yes | No |
When tables get larger and larger and some indexes get fragmented and others do not it is better to understand what is occurring prior to selecting which indexes to rebuild. The primary reason for this is the time it takes to rebuild indexes and also if you do an index rebuild versus an index defrag the index will not be available as well as the potential for blocking until the index rebuild is complete.
So where is the information stored?
With both SQL 2000 and SQL 2005 and later versions you can get the fragmentation information by using the DBCC SHOWCONTIG command. In addition, you can use the dynamic management view sys.dm_db_index_physical_stats in SQL Server 2005 and later. These commands are great, but you really need to collect the information and then analyze the data to determine which indexes should be rebuilt versus which indexes should be defragmented.
With the management view the data is displayed like a regular query result, so this data can be easily written to a database table. With the DBCC SHOWCONTIG command the data is not written in a table format, but by using the WITH TABLERESULTS option you can get the data in a table format instead of a report format which is the default.
Now what?
So once you have decided which method to use to collect the data DBCC SHOWCONTIG WITH TABLERESULTS or sys.dm_db_index_physical_stats you should create a table to load this data. Depending on your database usage this data should be collected on a weekly basis. From there you can start to analyze the data to see which tables and indexes are becoming fragmented and by how much. From this you can then experiment with the index defrag versus index rebuild to determine which process makes the most sense for your environment. Here is a quick sample to collect the data using DBCC SHOWCONTIG.
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) INSERT INTO fraglist EXEC ('DBCC SHOWCONTIG WITH FAST, TABLERESULTS, ALL_INDEXES, NO_INFOMSGS')
Here is another sample of T-SQL statements from SQL Server 2000 Books Online which allows you to determine which indexes to defrag. This could be modified to either do an index rebuild or an index defrag. This also uses the DBCC SHOWCONTIG versus sys.dm_db_index_physical_stats.
/*Perform a 'USE <database name>' to select the database in which to run the script.*/ -- Declare variables SET NOCOUNT ON DECLARE @tablename VARCHAR (128) DECLARE @execstr VARCHAR (255) DECLARE @objectid INT DECLARE @indexid INT DECLARE @frag DECIMAL DECLARE @maxfrag DECIMAL -- Decide on the maximum fragmentation to allow SELECT @maxfrag = 30.0 -- Declare cursor DECLARE tables CURSOR FOR SELECT 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 cursor for 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
Next Steps
- Build a table to start collecting the data
- Build a scheduled job to collect the data on a weekly basis
- Experiment with rebuilds versus defrags
- Establish a process to either rebuild or defrag your selected indexes based on the information you have collected
- Take a look at these other tips about this process:
About the author
This author pledges the content of this article is based on professional experience and not AI generated.
View all my tips
Article Last Updated: 2007-01-25