摘要:[SQL] SQL Server 索引重建或索引重組
針對資料庫的索引重建跟重組,最近在找一些維護的方法,剛好看到保哥這篇文章 讓 SQL Server 告訴你有哪些索引應該被重建或重組,就順便在此記錄一下。
範例
查詢索引的碎裂狀態T-SQL 語法
SELECT OBJECT_NAME(dt.object_id) ,
si.name ,
dt.avg_fragmentation_in_percent,
dt.avg_page_space_used_in_percent
FROM
(SELECT object_id ,
index_id ,
avg_fragmentation_in_percent,
avg_page_space_used_in_percent
FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL, NULL, 'DETAILED')
WHERE index_id <> 0
) AS dt --does not return information about heaps
INNER JOIN sys.indexes si
ON si.object_id = dt.object_id
AND si.index_id = dt.index_id
索引重組的時機
-
檢查 External fragmentation 部分
- 當 avg_fragmentation_in_percent 的值介於 10 到 15 之間
-
檢查 Internal fragmentation 部分
- 當 avg_page_space_used_in_percent 的值介於 60 到 75 之間
索引重建的時機
-
檢查 External fragmentation 部分
- 當 avg_fragmentation_in_percent 的值大於 15
-
檢查 Internal fragmentation 部分
- 當 avg_page_space_used_in_percent 的值小於 60
保哥調整過的自動幫你算出哪些索引需要被重建或重組T-SQL 語法
SELECT 'ALTER INDEX [' + ix.name + '] ON [' + s.name + '].[' + t.name + '] ' +
CASE
WHEN ps.avg_fragmentation_in_percent > 15
THEN 'REBUILD'
ELSE 'REORGANIZE'
END +
CASE
WHEN pc.partition_count > 1
THEN ' PARTITION = ' + CAST(ps.partition_number AS nvarchar(MAX))
ELSE ''
END,
avg_fragmentation_in_percent
FROM sys.indexes AS ix
INNER JOIN sys.tables t
ON t.object_id = ix.object_id
INNER JOIN sys.schemas s
ON t.schema_id = s.schema_id
INNER JOIN
(SELECT object_id ,
index_id ,
avg_fragmentation_in_percent,
partition_number
FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL, NULL, NULL)
) ps
ON t.object_id = ps.object_id
AND ix.index_id = ps.index_id
INNER JOIN
(SELECT object_id,
index_id ,
COUNT(DISTINCT partition_number) AS partition_count
FROM sys.partitions
GROUP BY object_id,
index_id
) pc
ON t.object_id = pc.object_id
AND ix.index_id = pc.index_id
WHERE ps.avg_fragmentation_in_percent > 10
AND ix.name IS NOT NULL
參考資料
以上文章敘述如有錯誤及觀念不正確,請不吝嗇指教
如有侵權內容也請您與我反應~謝謝您 :)