- Backups
- Consistency Checks
- Index Maintenance
- Updating Statistics
Index Maintenance
In general terms, indexes are database objects that provide pointers to the data. If SQL Server can use indexes to read the data from a table, data retrieval will be considerably faster than when scanning the entire table. It's extremely important to build appropriate indexes for each table. I'll discuss indexing strategies in another article. For now, let's talk about how we need to maintain indexes.
As data is added, modified, or removed from the table, indexes get fragmented. As the level of index fragmentation grows, the effectiveness of the index decreases proportionately. To keep your data-retrieval operations as efficient as possible, it's crucial to keep index fragmentation to a minimum. There are a couple of ways of removing fragmentation:
Drop and re-create an index. If multiple indexes are affected on the same table, you can drop and re-create the clustered index, which will cause all non-clustered indexes to be rebuilt as well. You can use DBCC DBREINDEX with a table name to rebuild one or multiple indexes on the specified table. Alternatively, you can use CREATE INDEX ... WITH DROP EXISTING syntax to rebuild an index. All three of these methods provide comparable performance.
Run the DBCC INDEXDEFRAG statement against the affected index. This statement reorders the leaf-level pages of the index to remove fragmentation. DBCC INDEXDEFRAG is an online operationin other words, it doesn't prevent users from reading and writing to a table. On the other hand, dropping and re-creating an index locks the table and prevents anyone else from using it. The drawback of DBCC INDEXDEFRAG is that it doesn't do as good a job as the complete rebuild of an index.
As you might guess from the discussion above, it's not always prudent to rebuild an index if you can get away with using DBCC INDEXDEFRAG, especially if you need to provide 100% uptime. A handy tool is the DBCC SHOWCONTIG statement, which shows you the fragmentation level of a specific index or all indexes in the specified table. In fact, you can run DBCC SHOWCONTIG without any parameters to show the fragmentation level for all tables. I don't recommend doing so in the production environment, since DBCC SHOWCONTIG has to scan a table/index to determine the fragmentation level and is therefore a time-consuming operation. Here's the type of output you get when executing DBCC SHOWCONTIG:
DBCC SHOWCONTIG scanning 'authors' table... Table: 'authors' (1977058079); index ID: 1, database ID: 5 TABLE level scan performed. - Pages Scanned................................: 1 - Extents Scanned..............................: 1 - Extent Switches..............................: 0 - Avg. Pages per Extent........................: 1.0 - Scan Density [Best Count:Actual Count].......: 100.00% [1:1] - Logical Scan Fragmentation ..................: 0.00% - Extent Scan Fragmentation ...................: 0.00% - Avg. Bytes Free per Page.....................: 6009.0 - Avg. Page Density (full).....................: 25.76% DBCC execution completed. If DBCC printed error messages, contact your system administrator.
Of course, if you want to automate your index maintenance, the output above is somewhat difficult to decipher. Fortunately, SQL Server can return the results of DBCC SHOWCONTIG in a table; all you have to do is add the TABLERESULTS clause:
DBCC SHOWCONTIG (authors) WITH TABLERESULTS
Figure 1 shows the results. (I broke up the output to make it easier to read. SQL Server returns results in a single row.)
Figure 1 Results of adding the TABLERESULTS clause to DBCC SHOWCONTIG.
Please check out Books On Line for explanation of each returned value. The most important values are logical fragmentation and scan density. The scan density value shows the ratio of best count of pages (the ideal scenario) over the actual count of pages in all extents (an extent is a group of eight data or index pages). Therefore, if the scan density returns 100%, there is no fragmentation. The logical fragmentation value, on the other hand, returns the percentage of pages that are out of order in the leaf level of the index. I won't to go into details of what this can mean, but the short version is that if logical fragmentation is other than zero or scan density is less than 100%, your index has some level of fragmentation and needs help.
As I mentioned earlier, there are few ways to get rid of fragmentation. Some environments allow the luxury of a maintenance window in which you can drop and re-create indexes on a regular basis. In a 24/7 shop you try to avoid such activities, since dropping and re-creating indexes takes a long time and uses much transaction log space. Instead I recommend re-creating only those indexes that have a high level of fragmentation (over 40%), defragmenting the ones that are moderately fragmented (1540%) and not touching those that are less than 15% fragmented. These recommended fragmentation levels come from my own experience. In your environment, the cutoff points may differ slightly. To automate the process of index maintenance, write a procedure that does the following:
Populate a temporary table with all user table names.
Loop over the temp table with a cursor to get a table name.
Get the names and keys of each index on this table.
Run DBCC SHOWCONTIG ... WITH TABLERESULTS on each index and store the results of this statement in a second temporary table.
Examine the values of scan density and logical fragmentation in the second temporary table.
Apply the logic in the paragraph above to rebuild or defragment each index.
This procedure will save tons of transaction log space and much maintenance time versus rebuilding all indexes from scratch.