I found a while ago a SQL script which will do a custom rebuild/reorganize based on the fragmentation level of each table. which seems more intelligent than just rebuilding all indexes which can be quite time consuming on large databases.
however I also found out recently that the loop stopped because it was the victim of a deadlock, and therefore the command failed, and it did not continue. so I have added now a try catch block around the execution of the command.
the other part is that it does only select those with more than 1000 pages, so now I am running nearly the same commands, but now I select those with less than 1000 pages and more than 20% fragmentation and I just always rebuild them. the 20% is just a random picked number, and can be changed/updated to meet your requirements
however I also found out recently that the loop stopped because it was the victim of a deadlock, and therefore the command failed, and it did not continue. so I have added now a try catch block around the execution of the command.
the other part is that it does only select those with more than 1000 pages, so now I am running nearly the same commands, but now I select those with less than 1000 pages and more than 20% fragmentation and I just always rebuild them. the 20% is just a random picked number, and can be changed/updated to meet your requirements
use OperationsManager
-- Ensure a USE <databasename> statement has been executed first.
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 @pagecnt bigint
DECLARE @command nvarchar(4000);
DECLARE @pagelock int;
-- Conditionally select tables and indexes from the sys.dm_db_index_physical_stats function
-- and convert object and index IDs to names.
SELECT
object_id AS objectid,
index_id AS indexid,
partition_number AS partitionnum,
avg_fragmentation_in_percent AS frag,
page_count as pagecnt
INTO #work_to_do
FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED')
WHERE avg_fragmentation_in_percent > 5.0 AND index_id > 0 AND page_count > 1000;
-- Declare the cursor for the list of partitions to be processed.
DECLARE partitions CURSOR FOR SELECT * FROM #work_to_do;
-- Open the cursor.
OPEN partitions;
-- Loop through the partitions.
WHILE (1=1)
BEGIN;
FETCH NEXT
FROM partitions
INTO @objectid, @indexid, @partitionnum, @frag, @pagecnt;
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;
SELECT @pagelock = allow_page_locks
FROM sys.indexes
WHERE object_id = @objectid AND index_id = @indexid;
-- Only process indexes where page locks are allowed
IF @pagelock = 1
BEGIN;
-- 30 is an arbitrary decision point at which to switch between reorganizing and rebuilding.
IF @frag < 30.0
SET @command = N'ALTER INDEX ' + @indexname + N' ON ' + @schemaname + N'.' + @objectname + N' REORGANIZE; ' +
N'UPDATE STATISTICS ' + @schemaname + N'.' + @objectname + N' ' + @indexname +';'
IF @frag >= 30.0
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));
begin try
EXEC (@command);
PRINT N'Executed: ' + @command;
end try
begin catch
PRINT N'Command failed: ' + @command;
end catch
END;
END;
-- Close and deallocate the cursor.
CLOSE partitions;
DEALLOCATE partitions;
-- Drop the temporary table.
DROP TABLE #work_to_do;
SELECT
object_id AS objectid,
index_id AS indexid,
partition_number AS partitionnum,
avg_fragmentation_in_percent AS frag,
page_count as pagecnt
INTO #work_to_do1
FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED')
WHERE avg_fragmentation_in_percent > 20.0 AND index_id > 0 AND page_count < 1000;
-- Declare the cursor for the list of partitions to be processed.
DECLARE partitions CURSOR FOR SELECT * FROM #work_to_do1;
-- Open the cursor.
OPEN partitions;
-- Loop through the partitions.
WHILE (1=1)
BEGIN;
FETCH NEXT
FROM partitions
INTO @objectid, @indexid, @partitionnum, @frag, @pagecnt;
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;
SELECT @pagelock = allow_page_locks
FROM sys.indexes
WHERE object_id = @objectid AND index_id = @indexid;
-- Only process indexes where page locks are allowed
IF @pagelock = 1
BEGIN;
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));
begin try
EXEC (@command);
PRINT N'Executed (small): ' + @command;
end try
begin catch
PRINT N'Command failed (small): ' + @command;
end catch
END;
END;
-- Close and deallocate the cursor.
CLOSE partitions;
DEALLOCATE partitions;
-- Drop the temporary table.DROP TABLE #work_to_do1;GO
No comments:
Post a Comment