USE AIS20220929093310; IF Object_id('tempdb..#temp_table_info') <> 0 DROP TABLE #temp_table_info IF Object_id('tempdb..#indexinfo') <> 0 DROP TABLE #indexinfo -- 创建临时表 CREATE TABLE #temp_table_info ( TABLE_NAME SYSNAME ); CREATE TABLE #indexinfo ( id INT IDENTITY(1, 1), object_name SYSNAME, fragmentpercent FLOAT, execsql SYSNAME, objsize_mb FLOAT ); go SET nocount ON DECLARE @record_log_flag BIT = 1 --记录索引重建优化的详细日志到表中,0表示false,1表示true DECLARE @log_retention_time INT = 7 --日志保留时间,单位是天 DECLARE @i INT DECLARE @icount INT DECLARE @sql AS VARCHAR(max) DECLARE @tbsize AS DECIMAL(19, 3) DECLARE @driversize AS INT DECLARE @logunusedsize INT=0 DECLARE @message VARCHAR(300) DECLARE @tbname SYSNAME DECLARE @begintime DATETIME DECLARE @tmpbegintime DATETIME DECLARE @tmpendtime DATETIME DECLARE @tmpDurationInSeconds INT DECLARE @worktime INT = 60 DECLARE @work_end_time DATETIME --任务截至时间 DECLARE @worktimeflag BIT DECLARE @exectabs VARCHAR(max) = '' DECLARE @noexectabs VARCHAR(max) = '' DECLARE @checklogsize BIT=0 DECLARE @currenttablename VARCHAR(max) DECLARE @delimiter CHAR(1) = ',' DECLARE @startindex INT = 1 DECLARE @fragmentpercent FLOAT ----------可人工调整的部分开始---------- SET @worktime = 30 ;--允许脚本执行的工作时间,单位为分钟,默认为1个小时(0表示不限制工作时间,直至所有符合条件的索引重建完成) --SET @noexectabs='T_BAS_OPERATELOGBK,T_BAS_OPERATELOGBK_S'--人工指定对某些表不进行重建索引,格式为't3,t4',默认为''(即不指定,对全库碎片率超过5的索引进行重建优化) ----------可人工调整的部分结束---------- DECLARE @noexectabslen INT = Len(@noexectabs); DECLARE @exectabslen INT = Len(@exectabs); IF @record_log_flag = 1 BEGIN IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = Object_id(N'[dbo].[KDIndexMaintenanceLog]') AND type IN ( N'U' )) --创建日志表 BEGIN CREATE TABLE [dbo].KDIndexMaintenanceLog ( ID INT IDENTITY(1, 1) PRIMARY KEY,-- 自增ID作为主键 [TableName] SYSNAME NOT NULL, objsize_mb FLOAT NOT NULL, [AvgFragmentationInPercent] [FLOAT] NOT NULL, execsql [NVARCHAR](200), [RebuildStartTime] [DATETIME] NULL, [RebuildEndTime] [DATETIME] NULL, [DurationInSeconds] [INT] NULL ); --创建索引 CREATE NONCLUSTERED INDEX IX_KDIndexMaintenanceLog ON KDIndexMaintenanceLog (TableName, RebuildStartTime); END --清理过期日志 DELETE FROM [dbo].KDIndexMaintenanceLog WHERE [RebuildStartTime] < Dateadd(DAY, -@log_retention_time, Cast (Getdate() AS DATE)) END IF @worktime > 0 BEGIN SET @work_end_time= Dateadd(MINUTE, @worktime, Getdate()) SET @worktimeflag=1 END ELSE SET @worktimeflag=0 --判断sql server版本是否高于2008 r2 IF ( Cast(Serverproperty('ProductMajorVersion') AS INT) > 10 OR ( Cast(Serverproperty('ProductMajorVersion') AS INT) = 10 AND Cast(Serverproperty('ProductMinorVersion') AS INT) >= 50 ) ) SET @checklogsize=1 IF ( @worktimeflag = 1 AND @work_end_time <= Getdate() ) BEGIN SET @message=N'停止执行。当前系统时间为:' + CONVERT(VARCHAR(30), Getdate(), 121) + N'超过了任务截至时间:' + @work_end_time RAISERROR(@message,0,1); RETURN END; SET @message=N'开始获取需要优化的表' + CONVERT(VARCHAR(30), Getdate(), 121) RAISERROR(@message,0,1); IF Len(Ltrim(Rtrim(@exectabs))) > 0 BEGIN SET @startindex=1 WHILE @startindex <= @exectabslen BEGIN SET @currenttablename = Ltrim(Rtrim(Substring(@exectabs, @startindex, CASE WHEN Charindex(@delimiter, @exectabs, @startindex) = 0 THEN 8000 ELSE Charindex(@delimiter, @exectabs, @startindex) - @startindex END))); INSERT INTO #temp_table_info (TABLE_NAME) VALUES (@currenttablename); SET @startindex = CASE WHEN Charindex(@delimiter, @exectabs, @startindex) = 0 THEN @exectabslen + 1 ELSE Charindex(@delimiter, @exectabs, @startindex) + 1 END; END; WITH t AS (SELECT SO.NAME AS object_name, SI.NAME AS index_name, IPS.avg_fragmentation_in_percent, ( page_count * 8.0 / 1024.0 ) AS size_in_mB, si.type_desc FROM sys.Dm_db_index_physical_stats(Db_id(), NULL, NULL, NULL, NULL) IPS INNER JOIN sys.indexes SI ON SI.index_id = IPS.index_id INNER JOIN sys.objects SO ON SO.object_id = SI.object_id AND IPS.object_id = SO.object_id WHERE alloc_unit_type_desc = 'IN_ROW_DATA' AND index_level = 0 AND SI.NAME IS NOT NULL AND SO.is_ms_shipped = 0 AND so.NAME NOT LIKE 'tmp%' AND so.NAME NOT LIKE 'z%' AND so.NAME NOT LIKE 'gle%' AND so.NAME IN(SELECT TABLE_NAME FROM #temp_table_info)), m AS (SELECT object_name, Max(avg_fragmentation_in_percent) fragmentpercent, CASE WHEN Max(avg_fragmentation_in_percent) >= 1 THEN 'dbcc dbreindex(' + object_name + ') with no_infomsgs' ELSE '' END execsql, Sum(size_in_mB) objsize_mb FROM t WHERE avg_fragmentation_in_percent > 0 GROUP BY object_name) INSERT INTO #indexinfo SELECT m.* FROM m WHERE m.execsql <> '' ORDER BY 2 DESC END ELSE IF Len(Ltrim(Rtrim(@noexectabs))) > 0 BEGIN SET @startindex=1 WHILE @startindex <= @noexectabslen BEGIN SET @currenttablename = Ltrim(Rtrim(Substring(@noexectabs, @startindex, CASE WHEN Charindex(@delimiter, @noexectabs, @startindex) = 0 THEN 8000 ELSE Charindex(@delimiter, @noexectabs, @startindex) - @startindex END))); INSERT INTO #temp_table_info (TABLE_NAME) VALUES (@currenttablename); SET @startindex = CASE WHEN Charindex(@delimiter, @noexectabs, @startindex) = 0 THEN @noexectabslen + 1 ELSE Charindex(@delimiter, @noexectabs, @startindex) + 1 END; END; WITH t AS (SELECT SO.NAME AS object_name, SI.NAME AS index_name, IPS.avg_fragmentation_in_percent, ( page_count * 8.0 / 1024.0 ) AS size_in_mB, si.type_desc FROM sys.Dm_db_index_physical_stats(Db_id(), NULL, NULL, NULL, NULL) IPS INNER JOIN sys.indexes SI ON SI.index_id = IPS.index_id INNER JOIN sys.objects SO ON SO.object_id = SI.object_id AND IPS.object_id = SO.object_id WHERE alloc_unit_type_desc = 'IN_ROW_DATA' AND index_level = 0 AND SI.NAME IS NOT NULL AND SO.is_ms_shipped = 0 AND so.NAME NOT LIKE 'tmp%' AND so.NAME NOT LIKE 'z%' AND so.NAME NOT LIKE 'gle%' AND so.NAME NOT IN(SELECT TABLE_NAME FROM #temp_table_info)), m AS (SELECT object_name, Max(avg_fragmentation_in_percent) fragmentpercent, CASE WHEN Max(avg_fragmentation_in_percent) >= 1 THEN 'dbcc dbreindex(' + object_name + ') with no_infomsgs' ELSE '' END execsql, Sum(size_in_mB) objsize_mb FROM t WHERE avg_fragmentation_in_percent > 0 GROUP BY object_name) INSERT INTO #indexinfo SELECT m.* FROM m WHERE m.execsql <> '' ORDER BY 2 DESC END ELSE BEGIN WITH t AS (SELECT SO.NAME AS object_name, SI.NAME AS index_name, IPS.avg_fragmentation_in_percent, ( page_count * 8.0 / 1024.0 ) AS size_in_mB, si.type_desc FROM sys.Dm_db_index_physical_stats(Db_id(), NULL, NULL, NULL, NULL) IPS INNER JOIN sys.indexes SI ON SI.index_id = IPS.index_id INNER JOIN sys.objects SO ON SO.object_id = SI.object_id AND IPS.object_id = SO.object_id WHERE alloc_unit_type_desc = 'IN_ROW_DATA' AND index_level = 0 AND SI.NAME IS NOT NULL AND SO.is_ms_shipped = 0 AND so.NAME NOT LIKE 'tmp%' AND so.NAME NOT LIKE 'z%' AND so.NAME NOT LIKE 'gle%'), m AS (SELECT object_name, Max(avg_fragmentation_in_percent) fragmentpercent, CASE WHEN Max(avg_fragmentation_in_percent) >= 1 THEN 'dbcc dbreindex(' + object_name + ') with no_infomsgs' ELSE '' END execsql, Sum(size_in_mB) objsize_mb FROM t WHERE avg_fragmentation_in_percent > 0 GROUP BY object_name) INSERT INTO #indexinfo SELECT m.* FROM m WHERE m.execsql <> '' ORDER BY 2 DESC END SET @icount=(SELECT Count(1) FROM #indexinfo); SET @message=N'结束获取需要优化的表' + CONVERT(VARCHAR(30), Getdate(), 121) RAISERROR(@message,0,1); IF @icount = 0 BEGIN SET @message=N'数据库:' + Db_name() + N'不需要优化' RAISERROR(@message,0,1); RETURN END; SET @begintime=Getdate() SET @message=N'数据库:' + Db_name() + N',开始时间: ' + CONVERT(VARCHAR(30), @begintime, 121) + N' 总共需要执行:' + Cast(@icount AS VARCHAR) + N' 条语句' RAISERROR(@message,0,1); SET @i=1 WHILE @i <= @icount BEGIN SELECT @sql = execsql, @tbsize = objsize_mb, @tbname = object_name, @fragmentpercent = fragmentpercent FROM #indexinfo WHERE id = @i IF( @checklogsize = 1 ) BEGIN SELECT @driversize = Cast(Cast(available_bytes AS DECIMAL) / ( 1024 * 1024 ) AS BIGINT) FROM sys.master_files AS f CROSS APPLY sys.Dm_os_volume_stats(f.database_id, f.file_id) WHERE f.database_id = Db_id() AND f.type_desc = 'LOG'; SELECT @logunusedsize = ( total_log_size_in_bytes - used_log_space_in_bytes ) / 1024 / 1024 FROM sys.dm_db_log_space_usage IF @i = 1 BEGIN SET @message=N'日志可用空间为(MB):' + Cast(@logunusedsize AS VARCHAR) + N';磁盘可用空间为(MB):' + Cast(@driversize AS VARCHAR) RAISERROR(@message,0,1); END; END IF ( @worktimeflag = 1 AND @work_end_time <= Getdate() ) BEGIN SET @message=N'停止执行。因为当前系统时间为:' + CONVERT(VARCHAR(30), Getdate(), 121) + N'超过了开始工作时间范围' + CONVERT(VARCHAR(30), @work_end_time, 121) + N'不允许执行优化计划' RAISERROR(@message,0,1); RETURN END IF ( @tbsize > ( @driversize + @logunusedsize ) AND @checklogsize = 1 ) BEGIN SET @message=N'磁盘可用空间和日志可用空间不足,执行终止。原因:表:' + @tbname + N'总需空间大小(MB):' + Cast(@tbsize AS VARCHAR) + N';日志可用空间为(MB):' + Cast(@logunusedsize AS VARCHAR) + N';磁盘可用空间为(MB):' + Cast(@driversize AS VARCHAR) RAISERROR(@message,16,1); RETURN END ELSE BEGIN SET @message= Cast(@i AS VARCHAR) + '/' + Cast(@icount AS VARCHAR) + N'(' + Cast(@tbsize AS VARCHAR) + 'MB):' + @tbname SET @tmpbegintime=Getdate() IF @record_log_flag = 1 BEGIN --记录日志 INSERT INTO KDIndexMaintenanceLog (TableName, objsize_mb, AvgFragmentationInPercent, execsql, RebuildStartTime) VALUES (@tbname, @tbsize, @fragmentpercent, @sql, @tmpbegintime) END EXEC(@sql) SET @tmpendtime=Getdate() SET @tmpDurationInSeconds = Datediff(second, @tmpbegintime, @tmpendtime) IF @record_log_flag = 1 BEGIN --更新日志表中索引优化完成时间 UPDATE KDIndexMaintenanceLog SET RebuildEndTime = @tmpendtime, DurationInSeconds = @tmpDurationInSeconds WHERE TableName = @tbname AND RebuildStartTime = @tmpbegintime; END SET @message=@message + N':' + Cast (@tmpDurationInSeconds AS NVARCHAR) + N'秒' RAISERROR(@message,0,1); END SET @i=@i + 1 END SET @message=N'数据库:' + Db_name() + N',结束时间: ' + CONVERT(VARCHAR(30), Getdate(), 121) + N' 总耗时(秒):' + Cast(Datediff(ss, @begintime, Getdate()) AS VARCHAR) RAISERROR(@message,0,1);