abstract:前言感想:一時興起,突然想寫一個關于MS SQL的巡檢系列方面的文章,因為我覺得這方面的知識分享是有價值,也是非常有意義的。一方面,很多經(jīng)驗不足的人,對于巡檢有點茫然,不知道要從哪些方面巡檢,另外一方面,網(wǎng)上關于MS SQL巡檢方面的資料好像也不是特別多。寫這個系列只是一個分享,自己的初衷是一個知識梳理、總結提煉過程,有些知識和腳本也不是原創(chuàng),文章很多地方也是融入了自己的一些想法和見解的,不足和膚
前言感想:一時興起,突然想寫一個關于MS SQL的巡檢系列方面的文章,因為我覺得這方面的知識分享是有價值,也是非常有意義的。一方面,很多經(jīng)驗不足的人,對于巡檢有點茫然,不知道要從哪些方面巡檢,另外一方面,網(wǎng)上關于MS SQL巡檢方面的資料好像也不是特別多。寫這個系列只是一個分享,自己的初衷是一個知識梳理、總結提煉過程,有些知識和腳本也不是原創(chuàng),文章很多地方也是融入了自己的一些想法和見解的,不足和膚淺之處肯定也非常多,拋磚引玉,也希望大家提意見和建議、補充,指正其中的不足之處。Stay Hungry Stay Foolish!
在SQL Server數(shù)據(jù)庫中,有可能存在重復的索引(Duplicate Indexes),這個不僅影響性能(INSERT、UPDATE、DELETE時帶來額外的IO開銷,當數(shù)據(jù)庫維護,索引重組時也會帶來額外的開銷),而且占用空間。數(shù)據(jù)庫存在重復索引(Duplicate Indexes)的原因是多方面的,很多時候、很多事情不是你所能完全掌控的,除非你所管理的數(shù)據(jù)庫非常規(guī)范,權限控制、腳本發(fā)布非常嚴格、流程化。暫且不說這些,那么怎么在數(shù)據(jù)庫巡檢過程找出這些重復的索引(Duplicate Indexes)呢? 下面分享一個我在Premier Proactive Services中發(fā)現(xiàn)一個的腳本(做了一些修改和調(diào)整)。
我們以AdventureWorks2014數(shù)據(jù)庫為例,如下所示,表[Person].[Address]下有4個索引,如下所示
假設某個二愣子在這個表的字段StateProvinceID上創(chuàng)建了下面重復索引,IX_Address_N1 與IX_Address_StateProvinceID是一個重復索引。
CREATE INDEX IX_Address_N1 ON [Person].[Address](StateProvinceID);
那么我們執(zhí)行下面腳本就能找到這個重復的索引,如下所示
;WITH IndexColumns AS ( SELECT DISTINCT SCHEMA_NAME(o.schema_id) AS SchemaName , OBJECT_NAME(o.object_id) AS TableName , i.name AS IndexName , o.object_id AS [Object_ID] , i.index_id AS Index_ID , i.type_desc AS IndexType , ( SELECT CASE key_ordinal WHEN 0 THEN NULL ELSE '[' + COL_NAME(k.object_id, column_id) + '] ' + CASE WHEN is_descending_key = 1 THEN 'Desc' ELSE 'Asc' END END AS [data()] FROM sys.index_columns k WITH(NOLOCK) WHERE k.object_id = i.object_id AND k.index_id = i.index_id ORDER BY key_ordinal , column_id FOR XML PATH('') ) AS IndexColumns , CASE WHEN i.index_id = 1 THEN ( SELECT '[' + name + ']' AS [data()] FROM sys.columns (NOLOCK) AS c WHERE c.object_id = i.object_id AND c.column_id NOT IN ( SELECT column_id FROM sys.index_columns (NOLOCK) AS kk WHERE kk.object_id = i.object_id AND kk.index_id = i.index_id ) ORDER BY column_id FOR XML PATH('') ) ELSE ( SELECT '[' + COL_NAME(k.object_id, column_id) + ']' AS [data()] FROM sys.index_columns k WITH(NOLOCK) WHERE k.object_id = i.object_id AND k.index_id = i.index_id AND is_included_column = 1 AND k.column_id NOT IN ( SELECT column_id FROM sys.index_columns kk WHERE k.object_id = kk.object_id AND kk.index_id = 1 ) ORDER BY key_ordinal , column_id FOR XML PATH('') ) END AS IndexInclude FROM sys.indexes i WITH(NOLOCK) INNER JOIN sys.objects o WITH(NOLOCK) ON i.object_id = o.object_id INNER JOIN sys.index_columns ic WITH(NOLOCK ) ON ic.object_id = i.object_id AND ic.index_id = i.index_id INNER JOIN sys.columns c WITH(NOLOCK) ON c.object_id = ic.object_id AND c.column_id = ic.column_id WHERE o.type = 'U' AND i.index_id <> 0 -- 0 = 堆 AND i.type <> 3 -- 3 = XML AND i.type <> 5 -- 5 = 聚集列存儲索引(SQL 2014~ SQL 2016) AND i.type <> 6 -- 6 = 非聚集列存儲索引(SQL 2014~ SQL 2016) AND i.type <> 7 -- 7 = 非聚集哈希索引(SQL 2014~ SQL 2016) GROUP BY o.schema_id , o.object_id , i.object_id , i.name , i.index_id , i.type_desc ), DuplicatesTable AS ( SELECT ic1.SchemaName , ic1.TableName , ic1.IndexName , ic1.[Object_ID] , ic2.IndexName AS DuplicateIndexName , ic1.IndexType , CASE WHEN ic1.index_id = 1 THEN ic1.IndexColumns + ' (Clustered)' WHEN ic1.IndexInclude = '' THEN ic1.IndexColumns WHEN ic1.IndexInclude IS NULL THEN ic1.IndexColumns ELSE ic1.IndexColumns + ' INCLUDE ' + ic1.IndexInclude END AS IndexCols , ic1.index_id FROM IndexColumns ic1 JOIN IndexColumns ic2 ON ic1.object_id = ic2.object_id AND ic1.index_id < ic2.index_id AND ic1.IndexColumns = ic2.IndexColumns AND ( ISNULL(ic1.IndexInclude, '') = ISNULL(ic2.IndexInclude, '') OR ic1.index_id = 1 ) ) SELECT SchemaName , TableName , IndexName , DuplicateIndexName , IndexType, IndexCols , Index_ID , Object_ID , 0 AS IsXML FROM DuplicatesTable dt ORDER BY 1 , 2 ,3
注意,關于重復索引(Duplicate Indexes)表示存在的索引除了名字不一樣外, 索引所在字段以及索引字段順序都是一樣的。An index is considered to be a duplicate if it references the same column and ordinal position as another index in the same database。 這個腳本是找出一模一樣的索引,如果你創(chuàng)建下面索引,索引字段一樣,但是有包含列字段不一樣,那么這個腳本會將這個索引視為不一樣的索引。有興趣可以自己試試。
CREATE INDEX IX_Address_N2 ON [Person].[Address](StateProvinceID) INCLUDE (City);
另外關于XML索引的重復索引,可以使用下面腳本檢查。
--Use the below T-SQL script to generate the complete list of duplicate XML indexes in a given database: ;WITH XMLTable AS ( SELECT OBJECT_NAME(x.object_id) AS TableName , SCHEMA_NAME(o.schema_id) AS SchemaName , x.object_id , x.name , x.index_id , x.using_xml_index_id , x.secondary_type , CONVERT(NVARCHAR(MAX), x.secondary_type_desc) AS secondary_type_desc , ic.column_id FROM sys.xml_indexes x ( NOLOCK ) JOIN sys.objects o ( NOLOCK ) ON x.object_id = o.object_id JOIN sys.index_columns (NOLOCK) ic ON x.object_id = ic.object_id AND x.index_id = ic.index_id ), DuplicatesXMLTable AS ( SELECT x1.SchemaName , x1.TableName , x1.name AS IndexName , x2.name AS DuplicateIndexName , x1.secondary_type_desc AS IndexType , x1.index_id , x1.object_id , ROW_NUMBER() OVER ( ORDER BY x1.SchemaName, x1.TableName, x1.name, x2.name ) AS seq1 , ROW_NUMBER() OVER ( ORDER BY x1.SchemaName DESC, x1.TableName DESC, x1.name DESC, x2.name DESC ) AS seq2 , NULL AS inc FROM XMLTable x1 JOIN XMLTable x2 ON x1.object_id = x2.object_id AND x1.index_id < x2.index_id AND x1.using_xml_index_id = x2.using_xml_index_id AND x1.secondary_type = x2.secondary_type ) SELECT SchemaName , TableName , IndexName , DuplicateIndexName , IndexType , Index_ID , [Object_ID] , 1 AS IsXML FROM DuplicatesXMLTable dtxml ORDER BY 1 , 2 , 3;
在每個庫跑一次這個腳本,就能將所有的重復的索引(Duplicate Indexes)全部找出,但是當手頭服務器、數(shù)據(jù)庫特別多時,這個工作也是一個體力活,可以將這個常規(guī)工作自動化,避免重復勞動,我將這個集成在MyDBA工具里面,只需要點擊一下鼠標,就可以幫助我自動處理這些工作。