IF OBJECT_ID('tempdb..#temp_index_rebuild') IS NOT NULL
DROP TABLE tempdb..#temp_index_rebuild
BEGIN TRY
--BEGIN TRAN
use DB명
SET NOCOUNT ON;
DECLARE @objectid INT;
DECLARE @indexid INT;
DECLARE @partitioncount BIGINT;
DECLARE @schemaname NVARCHAR(130);
DECLARE @objectname NVARCHAR(130);
DECLARE @indexname NVARCHAR(130);
DECLARE @partitionnum BIGINT;
DECLARE @partitions BIGINT;
DECLARE @frag FLOAT;
DECLARE @pagecount INT;
DECLARE @command NVARCHAR(4000);
DECLARE @page_count_minimum SMALLINT
SET @page_count_minimum = 10
DECLARE @fragmentation_minimum FLOAT
SET @fragmentation_minimum = 30.0
SELECT object_id AS objectid ,
index_id AS indexid ,
partition_number AS partitionnum ,
avg_fragmentation_in_percent AS frag ,
page_count AS page_count
INTO #temp_index_rebuild
FROM sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL, NULL,
'LIMITED')
WHERE avg_fragmentation_in_percent > @fragmentation_minimum
AND index_id > 0
AND page_count > @page_count_minimum;
IF CURSOR_STATUS('global', 'partitions') >= -1
BEGIN
PRINT 'partitions CURSOR DELETED' ;
CLOSE partitions
DEALLOCATE partitions
END
DECLARE partitions CURSOR LOCAL
FOR
SELECT *
FROM #temp_index_rebuild;
OPEN partitions;
WHILE ( 1 = 1 )
BEGIN;
FETCH NEXT
FROM partitions
INTO @objectid, @indexid, @partitionnum, @frag, @pagecount;
IF @@FETCH_STATUS < 0
BREAK;
SELECT @objectname = QUOTENAME(o.name) ,
@schemaname = QUOTENAME(s.name)
FROM sys.objects AS o
JOIN sys.schemas AS s ON s.schema_id = o.schema_id
WHERE o.object_id = @objectid;
SELECT @indexname = QUOTENAME(name)
FROM sys.indexes
WHERE object_id = @objectid
AND index_id = @indexid;
SELECT @partitioncount = COUNT(*)
FROM sys.partitions
WHERE object_id = @objectid
AND index_id = @indexid;
SET @command = N'ALTER INDEX ' + @indexname + N' ON '
+ @schemaname + N'.' + @objectname + N' REBUILD';
IF @partitioncount > 1
SET @command = @command + N' PARTITION='
+ CAST(@partitionnum AS NVARCHAR(10));
EXEC (@command);
--print (@command); --uncomment for testing
PRINT N'Rebuilding index ' + @indexname + ' on table '
+ @objectname;
PRINT N' Fragmentation: ' + CAST(@frag AS VARCHAR(15));
PRINT N' Page Count: ' + CAST(@pagecount AS VARCHAR(15));
PRINT N' ';
END;
CLOSE partitions;
DEALLOCATE partitions;
DROP TABLE #temp_index_rebuild;
END TRY
BEGIN CATCH
PRINT 'ERROR ENCOUNTERED:' + ERROR_MESSAGE()
END CATCH
'Develop > DB - mssql' 카테고리의 다른 글
백업 및 백업모델 조회 (0) | 2021.03.31 |
---|---|
통계정보 업데이트 (0) | 2021.03.30 |
세션상태 조회 (0) | 2021.03.30 |
실행계획 결과화면에서 텍스트로 보기 (0) | 2020.10.08 |
table 조각모음 (0) | 2020.07.03 |