Managing SQL Server Database Fragmentation

By:   |   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


sql server categories

sql server webinars

subscribe to mssqltips

sql server tutorials

sql server white papers

next tip



About the author
MSSQLTips author Greg Robidoux Greg Robidoux is the President and founder of Edgewood Solutions, a technology services company delivering services and solutions for Microsoft SQL Server. He is also one of the co-founders of MSSQLTips.com. Greg has been working with SQL Server since 1999, has authored numerous database-related articles, and delivered several presentations related to SQL Server. Before SQL Server, he worked on many data platforms such as DB2, Oracle, Sybase, and Informix.

This author pledges the content of this article is based on professional experience and not AI generated.

View all my tips



Comments For This Article




Thursday, June 5, 2014 - 10:18:11 AM - Greg Robidoux Back To Top (32095)

Graeme, take a look at this tip for space used per table: http://www.mssqltips.com/sqlservertip/1177/determining-space-used-for-each-table-in-a-sql-server-database/

Check out the comments section as well for alternative options.


Thursday, June 5, 2014 - 9:58:58 AM - Graeme Back To Top (32094)

Thanks Greg.  I'm new to all this SQL stuff.  Is there a way to check the size of a table instead of just counting the number of rows?

 

I'll read the other link you provided.  I have been getting a few calls of our users experiencing slow performances on some databases, especially when using SQL Reporting Services.

 

Thanks.

 

Graeme


Wednesday, June 4, 2014 - 1:40:01 PM - Greg Robidoux Back To Top (32082)

Hi Graeme,

it is possible that the tables are very small and do not have many pages therefore the index fragmentation will not decrease.

Also, take a look at this tip that has a newer way to rebuild and reorganize indexes.  The approach in this tip is from SQL Server 2000 days.

Here is a newer way of doing this using ALTER INDEX commands:

http://www.mssqltips.com/sqlservertip/1791/fixing-index-fragmentation-in-sql-server-2005-and-sql-server-2008/

Thanks
Greg


Wednesday, June 4, 2014 - 11:40:37 AM - Graeme Back To Top (32079)

Hi

I don't think I clearly understand how the IndexDefrag works.  I ran the Idera free tool SQL Fragmentation Analyzer and it returned each index and the % fragmented.  Some of where were pretty high.  I then ran your script.  Once that finished, I re-ran SQL Fragmentation Analyzer but each index is showing the same % as before I ran your script.  Am I missing something obvious here?

Thanks.

Graeme


Monday, August 12, 2013 - 8:43:04 AM - Greg Robidoux Back To Top (26246)

@David - yes this applies to both Clustered and Non-clustered indexes.  Both types of indexes can become fragmented.


Sunday, August 11, 2013 - 8:00:44 PM - David Pierson Back To Top (26233)

Does this apply to Clustered Indexes too? If pushed, I would not have thought so, because the index and the data are together.


Tuesday, January 27, 2009 - 7:30:43 AM - aprato Back To Top (2616)

 Yes, it should be neutral to both SQL 2000 and 2005


Monday, January 26, 2009 - 9:15:27 AM - cjmorgant110 Back To Top (2612)

That worked great.  Will this work on pretty much any database then? 

 Thanks again for all your help.

C.J.


Monday, January 19, 2009 - 2:04:14 PM - aprato Back To Top (2582)

I cobbled something together to work with AW database

/*Perform a 'USE <database name>' to select the database in which to run the script.*/
-- Declare variables
IF OBJECT_ID('TEMPDB..#fraglist') IS NOT NULL
   DROP TABLE #fraglist
GO
   
SET NOCOUNT ON
DECLARE @tablename VARCHAR (128)
DECLARE @tableschema VARCHAR (128)
DECLARE @execstr   VARCHAR (255)
DECLARE @objectid  INT
DECLARE @IndexName VARCHAR (255)
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, TABLE_SCHEMA
   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, @tableschema

WHILE @@FETCH_STATUS = 0
BEGIN
-- Do the showcontig of all indexes of the table
   SELECT @tablename = @tableschema + '.' + @tablename
   INSERT INTO #fraglist
   EXEC ('DBCC SHOWCONTIG (''' + @tablename + ''')
      WITH FAST, TABLERESULTS, ALL_INDEXES, NO_INFOMSGS')
   FETCH NEXT
      FROM tables
      INTO @tablename, @tableschema
END
 
-- Close and deallocate the cursor
CLOSE tables
DEALLOCATE tables

-- Declare cursor for list of indexes to be defragged
DECLARE indexes CURSOR FOR
   SELECT I.TABLE_SCHEMA, F.ObjectName, F.ObjectId, F.IndexName, F.LogicalFrag
   FROM #fraglist F
   JOIN INFORMATION_SCHEMA.TABLES I ON I.TABLE_NAME = F.ObjectName COLLATE SQL_Latin1_General_CP1_CI_AS
   WHERE TABLE_TYPE = 'BASE TABLE'
   AND LogicalFrag >= @maxfrag
      AND INDEXPROPERTY (ObjectId, IndexName, 'IndexDepth') > 0

-- Open the cursor
OPEN indexes

-- loop through the indexes
FETCH NEXT
   FROM indexes
   INTO @tableschema, @tablename, @objectid, @IndexName, @frag

WHILE @@FETCH_STATUS = 0
BEGIN
   SELECT @tablename = @tableschema + '.' + @tablename
   PRINT 'Executing DBCC DBREINDEX (' + RTRIM(@tablename) + ',
      ' + RTRIM(@IndexName) + ') - fragmentation currently '
       + RTRIM(CONVERT(VARCHAR(15),@frag)) + '%'
   SELECT @execstr = 'DBCC DBREINDEX ([' + @tablename + '],
       ' + RTRIM(@IndexName) + ')'
   EXEC (@execstr)

   FETCH NEXT
      FROM indexes
      INTO @tableschema, @tablename, @objectid, @IndexName, @frag
END

-- Close and deallocate the cursor
CLOSE indexes
DEALLOCATE indexes

-- Delete the temporary table
DROP TABLE #fraglist
GO


Monday, January 19, 2009 - 12:31:12 PM - cjmorgant110 Back To Top (2581)

Ok, thanks.  Unfortunately that is a bit beyond my skill set.;-)

 Thanks for the help I do appreciate it.

C.J.


Monday, January 19, 2009 - 11:53:41 AM - aprato Back To Top (2580)

 This database has multiple schema owners defined.  You'd have to modify the script to incorporate the schema owner when referring to a table


Monday, January 19, 2009 - 10:06:26 AM - cjmorgant110 Back To Top (2579)

Aprato,

Thanks so much for the modified script.  I ran it against the Adventureworks DB on my test system and receive the following errors:

 

Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductProductPhoto". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "StoreContact". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Address". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductReview". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "TransactionHistory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "AddressType". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductSubcategory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "TransactionHistoryArchive". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductVendor". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "BillOfMaterials". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "UnitMeasure". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Vendor". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "PurchaseOrderDetail". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Contact". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "VendorAddress". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "VendorContact". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "PurchaseOrderHeader". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ContactCreditCard". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "WorkOrder". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ContactType". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "CountryRegionCurrency". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "WorkOrderRouting". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "CountryRegion". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "CreditCard". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Culture". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Currency". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesOrderDetail". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "CurrencyRate". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Customer". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesOrderHeader". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "CustomerAddress". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Department". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Document". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Employee". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesOrderHeaderSalesReason". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesPerson". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "EmployeeAddress". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "EmployeeDepartmentHistory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "EmployeePayHistory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesPersonQuotaHistory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Illustration". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesReason". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Individual". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesTaxRate". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "JobCandidate". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Location". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesTerritory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Product". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SalesTerritoryHistory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ScrapReason". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Shift". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductCategory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ShipMethod". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductCostHistory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductDescription". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ShoppingCartItem". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductDocument". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductInventory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SpecialOffer". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductListPriceHistory". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "SpecialOfferProduct". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductModel". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "StateProvince". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductModelIllustration". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductModelProductDescriptionCulture". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "Store". Check the system catalog.
Msg 2501, Level 16, State 45, Line 1
Cannot find a table or object with the name "ProductPhoto". Check the system catalog.

Thanks in advance for the help.

C.J.

 


Saturday, January 17, 2009 - 7:52:29 AM - aprato Back To Top (2574)

 Here's a modified version that uses DBREINDEX... note that as-of SQL 2005, this has been marked for future deprecation

 

/*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 @IndexName VARCHAR (255)
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, IndexName, 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, @IndexName, @frag

WHILE @@FETCH_STATUS = 0
BEGIN
   PRINT 'Executing DBCC DBREINDEX (' + RTRIM(@tablename) + ',
      ' + RTRIM(@IndexName) + ') - fragmentation currently '
       + RTRIM(CONVERT(VARCHAR(15),@frag)) + '%'
   SELECT @execstr = 'DBCC DBREINDEX (' + @tablename + ',
       ' + RTRIM(@IndexName) + ')'
   EXEC (@execstr)

   FETCH NEXT
      FROM indexes
      INTO @tablename, @objectid, @IndexName, @frag
END

-- Close and deallocate the cursor
CLOSE indexes
DEALLOCATE indexes

-- Delete the temporary table
DROP TABLE #fraglist
GO


Friday, January 16, 2009 - 2:14:52 PM - cjmorgant110 Back To Top (2571)

In this article it states this can be used with DBCC DBREINDEX.  Can someone show me the syntax that I need to replace in this to get it to work?

 

Thanks,

C.J.















get free sql tips
agree to terms