SQL Server如何找出數(shù)據(jù)庫(kù)中沒(méi)有索引的表
本文轉(zhuǎn)載自微信公眾號(hào)「DBA閑思雜想錄」,作者瀟湘隱者。轉(zhuǎn)載本文請(qǐng)聯(lián)系DBA閑思雜想錄公眾號(hào)。
在SQL Server數(shù)據(jù)庫(kù)的維護(hù)中,我們經(jīng)常需要巡檢,找出一些沒(méi)有索引的表,然后根據(jù)實(shí)際情況判斷是否需要增加索引。下面分享一個(gè)腳本,如何找出當(dāng)前數(shù)據(jù)庫(kù)中沒(méi)有索引的表信息。
- /**************************************************************************************************************
- --腳本名稱(chēng) : find_without_index_tables.sql
- --腳本作者 : 瀟湘隱者
- --創(chuàng)建日期 : 2016-10-27
- ***************************************************************************************************************
- 腳本功能 : 查找數(shù)據(jù)庫(kù)中沒(méi)有任何索引的表,并計(jì)算表的行數(shù),用作是否創(chuàng)建索引的一個(gè)依據(jù)
- ***************************************************************************************************************
- 注意事項(xiàng) : 需要切換到具體的用戶(hù)數(shù)據(jù)庫(kù)后執(zhí)行腳本
- ***************************************************************************************************************
- 參考資料 :
- ***************************************************************************************************************
- 更新記錄 : 2016-10-27:創(chuàng)建此腳本
- 2020-03-14: 修改腳本,新增SERVER_NAME,DB_NAME
- ***************************************************************************************************************/
- SELECT DISTINCT
- @@SERVERNAME AS [SERVER_NAME]
- ,DB_NAME() AS [DB_NAME]
- ,so.object_id AS [OBJECT_ID]
- ,SCHEMA_NAME(so.schema_id) +'.' +OBJECT_NAME(so.object_id)
- AS [TABLE_NAME]
- ,MAX(dmv.rows) AS [APPROXIMATE_ROWS]
- ,MAX(d.ColumnCount) AS [COLUMN_COUNT]
- FROM sys.objects so ( NOLOCK )
- JOIN sys.indexes si ( NOLOCK ) ON so.object_id = si.object_id
- AND so.type IN ( N'U', N'V' )
- JOIN sysindexes dmv ( NOLOCK ) ON so.object_id = dmv.id
- AND si.index_id = dmv.indid
- FULL OUTER JOIN ( SELECT object_id ,
- COUNT(1) AS ColumnCount
- FROM sys.columns (NOLOCK)
- GROUP BY object_id
- ) d ON d.object_id = so.object_id
- WHERE so.is_ms_shipped = 0
- AND so.object_id NOT IN (
- SELECT major_id
- FROM sys.extended_properties (NOLOCK)
- WHERE name = N'microsoft_database_tools_support' )
- AND INDEXPROPERTY(so.object_id, si.name, 'IsStatistics') = 0
- GROUP BY so.schema_id ,
- so.object_id
- HAVING ( CASE OBJECTPROPERTY(MAX(so.object_id), 'TableHasClustIndex')
- WHEN 0 THEN COUNT(si.index_id) - 1
- ELSE COUNT(si.index_id)
- END = 0 )
- ORDER BY [APPROXIMATE_ROWS] DESC;
上面腳本只能查詢(xún)當(dāng)前數(shù)據(jù)庫(kù)中沒(méi)有索引的表,我們知道,生產(chǎn)環(huán)境中,一個(gè)實(shí)例下面往往有多個(gè)用戶(hù)數(shù)據(jù)庫(kù),我們需要采集每個(gè)數(shù)據(jù)庫(kù)中沒(méi)有索引的表信息,那么上面腳本明顯有點(diǎn)硬傷,所以,重寫(xiě)了這個(gè)腳本。
- /**************************************************************************************************************
- --腳本名稱(chēng) : find_without_index_tables.sql
- --腳本作者 : 瀟湘隱者
- --創(chuàng)建日期 : 2016-10-27
- ***************************************************************************************************************
- 腳本功能 : 批量查找實(shí)例下面的每個(gè)數(shù)據(jù)庫(kù),找出沒(méi)有任何索引的表
- ***************************************************************************************************************
- 注意事項(xiàng) : 暫無(wú)
- ***************************************************************************************************************
- 參考資料 :
- ***************************************************************************************************************
- 更新記錄 : 2016-10-27:創(chuàng)建此腳本
- 2020-03-14: 修改腳本,新增SERVER_NAME,DB_NAME
- ***************************************************************************************************************/
- IF EXISTS (SELECT * FROM tempdb.dbo.sysobjects WHERE id = OBJECT_ID('tempdb.dbo.#Database'))
- BEGIN
- DROP TABLE #Database;
- END
- CREATE TABLE #Database (database_id INT ,database_name NVARCHAR(128) );
- INSERT INTO #Database
- SELECT database_id, name FROM sys.databases WHERE state_desc='ONLINE'
- AND name NOT IN ('master','msdb','tempdb','model', 'distribution')
- DECLARE @database_name NVARCHAR(128);
- DECLARE @database_id INT;
- DECLARE @cmdText NVARCHAR(MAX);
- SET @database_name ='';
- SET @database_id =1;
- IF EXISTS (SELECT * FROM tempdb.dbo.sysobjects WHERE id = OBJECT_ID('tempdb.dbo.#TAB_NO_INDEX_INFO'))
- BEGIN
- DROP TABLE #TAB_NO_INDEX_INFO;
- END
- CREATE TABLE #TAB_NO_INDEX_INFO(
- [SERVER_NAME] [NVARCHAR](32) NULL,
- [INSTANCE_NAME] [NVARCHAR](64) NULL,
- [DATABASE_NAME] [NVARCHAR](32) NULL,
- [TABLE_NAME] [NVARCHAR](128) NULL,
- [OBJECT_ID] [INT] NULL,
- [APPROXIMATE_ROWS] [INT] NULL,
- [COLUMN_COUNT] [INT] NULL
- );
- WHILE(1=1)
- BEGIN
- SELECT TOP 1
- @database_id = database_id ,
- @database_name = database_name
- FROM #Database
- WHERE database_id > @database_id -- next database_name greater than @database_id
- ORDER BY database_id -- database_id order
- -- exit loop if no more name greater than the last one used
- If @@rowcount = 0 Break
- SET @cmdText='USE ' + @database_name +';
- --GO
- INSERT INTO #TAB_NO_INDEX_INFO
- ( SERVER_NAME ,
- INSTANCE_NAME ,
- DATABASE_NAME ,
- TABLE_NAME ,
- OBJECT_ID ,
- APPROXIMATE_ROWS ,
- COLUMN_COUNT
- )
- SELECT DISTINCT
- CAST(SERVERPROPERTY(''MachineName'') AS NVARCHAR(32))
- AS [SERVER_NAME] ,
- @@SERVICENAME AS [INSTANCE_NAME] ,
- DB_NAME() AS [DATABASE_NAME] ,
- SCHEMA_NAME(so.schema_id)+ ''.'' +
- OBJECT_NAME(so.object_id) AS [TABLE_NAME] ,
- so.object_id AS [OBJECT_ID] ,
- MAX(dmv.rows) AS [APPROXIMATE_ROWS] ,
- MAX(d.ColumnCount) AS [COLUMN_COUNT]
- FROM sys.objects so ( NOLOCK )
- JOIN sys.indexes si ( NOLOCK ) ON so.object_id = si.object_id
- AND so.type IN ( N''U'', N''V'' )
- JOIN sysindexes dmv ( NOLOCK ) ON so.object_id = dmv.id
- AND si.index_id = dmv.indid
- FULL OUTER JOIN ( SELECT object_id ,
- COUNT(1) AS ColumnCount
- FROM sys.columns (NOLOCK)
- GROUP BY object_id
- ) d ON d.object_id = so.object_id
- WHERE so.is_ms_shipped = 0
- AND so.object_id NOT IN (
- SELECT major_id
- FROM sys.extended_properties (NOLOCK)
- WHERE name = N''microsoft_database_tools_support'' )
- AND INDEXPROPERTY(so.object_id, si.name, ''IsStatistics'') = 0
- GROUP BY so.schema_id ,
- so.object_id
- HAVING ( CASE OBJECTPROPERTY(MAX(so.object_id), ''TableHasClustIndex'')
- WHEN 0 THEN COUNT(si.index_id) - 1
- ELSE COUNT(si.index_id)
- END = 0 )
- ORDER BY [APPROXIMATE_ROWS] DESC; '
- PRINT @cmdText;
- EXEC ( @cmdText);
- --EXEC SP_EXECUTESQL @cmdText, N'@database_name NVARCHAR(32)',@database_name
- Delete Db
- From #Database Db WHERE database_id=@database_id;
- END
- SELECT *
- FROM #TAB_NO_INDEX_INFO
- ORDER BY APPROXIMATE_ROWS DESC;
- --找出數(shù)據(jù)量超過(guò)1000行沒(méi)有索引信息的表
- SELECT * FROM #TAB_NO_INDEX_INFO
- WHERE APPROXIMATE_ROWS > 1000
- ORDER BY APPROXIMATE_ROWS DESC
當(dāng)你維護(hù)了很多SQL Server數(shù)據(jù)庫(kù)時(shí),使用上面腳本到每臺(tái)SQL Server實(shí)例上跑一次,也是一件非常麻煩耗時(shí)的事情,所以還是需要自動(dòng)化作業(yè)處理,定時(shí)使用Python腳本去每臺(tái)SQL Server實(shí)例上采集數(shù)據(jù)存儲(chǔ)下來(lái),然后DBA只需做好兩件事情:監(jiān)控采集數(shù)據(jù)和分析處理數(shù)據(jù)。這里就不貼Python腳本了,其實(shí)就是循環(huán)所有SQL Server實(shí)例,運(yùn)行上面腳本,將采集到的相關(guān)數(shù)據(jù)存儲(chǔ)起來(lái)。