Percentage of fragmented indexes

| 0 comments | 17,523 views
Categories: ,

VN:F [1.9.17_1161]
Rating: 5.0/5 (3 votes cast)

Explanation: This is a general indicator of performance problems. Index fragmentation can affect the rate of return for moderate to large tables. If multiple indexes are fragmented throughout the database, then an index maintenance strategy needs to be evaluated.

Guideline values:The ideal value for this metric is less than 5%; this metric counts the number of moderate to large indexes (page values > 100) with fragmentation levels greater than 5%, and then divides that number by the number of indexes in the database. This percentage may increase throughout the day as data is loaded into your database, but it will shrink when indexes are rebuilt or reorganized. This metric does not identify specific performance problems with a specific index, but should be used to obtain a general idea of how well your index maintenance strategy addresses overall problems.

Possible solutions: If this value indicates an increased amount of index fragmentation throughout your database, you may need to fine-tune your index maintenance plans. Indexes may need to be redesigned or rebuilt more frequently.

More information:

sys.dm_db_index_physical_stats (Transact-SQL)

Reorganize and Rebuild Indexes

Percentage of fragmented indexes, 5.0 out of 5 based on 3 ratings

Metric definition

Metric Name:
Percentage of fragmented indexes
Description:

Explanation: This is a general indicator of performance problems. Index fragmentation can affect the rate of return for moderate to large tables. If multiple indexes are fragmented throughout the database, then an index maintenance strategy needs to be evaluated.

Guideline values: The ideal value for this metric is less than 5%; this metric counts the number of moderate to large indexes (page values > 100) with fragmentation levels greater than 5%, and then divides that number by the number of indexes in the database. This percentage may increase throughout the day as data is loaded into your database, but it will shrink when indexes are rebuilt or reorganized. This metric does not identify specific performance problems with a specific index, but should be used to obtain a general idea of how well your index maintenance strategy addresses overall problems.

Possible solutions: If this value indicates an increased amount of index fragmentation throughout your database, you may need to fine-tune your index maintenance plans. Indexes may need to be redesigned, or rebuilt more frequently.

More information:

sys.dm_db_index_physical_stats (Transact-SQL)

Reorganize and Rebuild Indexes

Enter the T-SQL query that will collect data:
DECLARE @frag DECIMAL(10, 2) ,
    @tot INT;
  
SELECT  @frag = COUNT(*)
FROM    sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL,
                                       NULL, 'LIMITED') ps
WHERE   ps.avg_fragmentation_in_percent >= 5
        AND ps.page_count > 100
        AND OBJECTPROPERTY(ps.[object_id], 'IsUserTable') = 1;
 
SELECT  @tot = COUNT(*)
FROM    sys.indexes i
WHERE   OBJECTPROPERTY(i.[object_id], 'IsUserTable') = 1;
 
SELECT  @tot = CASE WHEN @tot = 0 THEN 1
                    ELSE @tot
               END;
 
SELECT  CAST(( @frag / @tot ) AS DECIMAL(10, 2)) * 100;
Select instances to collect from:
Select all
Choose databases to collect from:
All databases
Set collection frequency:
Collect data every day
Note: Excessively large databases may not return data within an acceptable time frame, so you may need to adjust the collection frequency of this metric from 1 minute to 5 or 10 minutes.
Use collected or calculated values:
Leave the Use a calculated rate of change between collections check box turned off
Metric collection is:
Enabled

Alert definition

Alert name:
Increased % of fragmented indexes
Description:

Explanation: This alert is raised when index fragmentation goes above the threshold specified. This is a general indicator of performance problems. Index fragmentation can affect the rate of return for moderate to large tables. If multiple indexes are fragmented throughout the database, then an index maintenance strategy needs to be evaluated.

The ideal value for the metric on which this alert is based is less than 5%; the metric counts the number of moderate to large indexes (page values > 100) with fragmentation levels greater than 5%, and then divides that number by the number of indexes in the database. This percentage may increase throughout the day as data is loaded into your database, but it will shrink when indexes are rebuilt or reorganized. This metric does not identify specific performance problems with a specific index, but should be used to obtain a general idea of how well your index maintenance strategy addresses overall problems.

Possible solutions: If this value indicates an increased amount of index fragmentation throughout your database, you may need to fine-tune your index maintenance plans. Indexes may need to be redesigned or rebuilt more frequently.

More information:

sys.dm_db_index_physical_stats (Transact-SQL)

Reorganize and Rebuild Indexes

Raise an alert when the metric value goes:
Above the defined thresholds
Default threshold values:
Set the thresholds as follows:
High:15
Medium:10
Low:5
Note: These thresholds are intended as guideline values. If they seem too high or too low for your environment, replace them with values more suited to your server performance.
Raise an alert when the threshold is passed for:
Enter 1 collection
This alert is:
Enabled
VN:F [1.9.17_1161]
Rating: 5.0/5 (3 votes cast)