/*
IF FRAGMENATION < 30 THEN REORGANIZE INDEX
IF FRAGMENTATION >= 30 THEN REBUILD INDEX
*/
-- Ensure a USE 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 @Command nvarchar(4000);
-- 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
INTO #work_to_do
FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED')
WHERE avg_fragmentation_in_percent > 10.0 AND index_id > 0;
-- 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;
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;
-- 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';
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));
EXEC (@Command);
--PRINT N'Executed: ' + @command;
END;
-- Close and deallocate the cursor.
CLOSE partitions;
DEALLOCATE partitions;
-- Drop the temporary table.
DROP TABLE #work_to_do;
GO
/*
UPDATE STATISTICS IMMEDIATELY AFTER REBUILD & REORGANIZE OPERATION PERFORMED.
*/
SET NOCOUNT ON
DECLARE @columnname VARCHAR(MAX)
DECLARE @tablename SYSNAME
DECLARE @statsname SYSNAME
DECLARE @sql NVARCHAR(4000)
DECLARE @NAME VARCHAR(MAX)
declare @i INT
declare @j INT
CREATE TABLE #Temp
(
TableName VARCHAR(1000),
StatsName VARCHAR(1000),
ColumnName VARCHAR(1000)
)
insert #Temp(TableName,StatsName,ColumnName)
SELECT DISTINCT
OBJECT_NAME(s.[object_id]),
s.name AS StatName,
COALESCE(@NAME+ ', ', '')+c.name
FROM sys.stats s JOIN sys.stats_columns sc ON sc.[object_id] = s.[object_id] AND sc.stats_id = s.stats_id
JOIN sys.columns c ON c.[object_id] = sc.[object_id] AND c.column_id = sc.column_id
JOIN INFORMATION_SCHEMA.COLUMNS D ON D.[COLUMN_NAME]= C.[NAME]
JOIN sys.partitions par ON par.[object_id] = s.[object_id]
JOIN sys.objects obj ON par.[object_id] = obj.[object_id]
WHERE OBJECTPROPERTY(s.OBJECT_ID,'IsUserTable') = 1
CREATE TABLE #Temp1
(
id int identity(1,1),
TableName VARCHAR(8000),
StatsName VARCHAR(8000),
ColumnName VARCHAR(8000)
)
insert #Temp1(TableName,StatsName,ColumnName)
select TableName,StatsName,stuff(
(
select ','+ [ColumnName] FROM #temp where
StatsName = t.StatsName for XML path('')
),1,1,'')
from (select distinct TableName,StatsName from #Temp )t
SELECT @i=1
SELECT @j=MAX(ID) FROM #Temp1
WHILE(@I<=@J)
BEGIN
SELECT @statsname = statsname FROM #Temp1 where id = @i
SELECT @tablename = TableName FROM #Temp1 where id = @i
SELECT @columnname = columnname FROM #Temp1 where id = @i
SET @sql = N'UPDATE STATISTICS '+QUOTENAME(@tablename)+QUOTENAME(@statsname)
PRINT @sql
EXEC sp_executesql @sql
SET @i = @i+1
END
DROP TABLE #Temp
DROP TABLE #Temp1
IF FRAGMENATION < 30 THEN REORGANIZE INDEX
IF FRAGMENTATION >= 30 THEN REBUILD INDEX
*/
-- Ensure a USE 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 @Command nvarchar(4000);
-- 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
INTO #work_to_do
FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED')
WHERE avg_fragmentation_in_percent > 10.0 AND index_id > 0;
-- 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;
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;
-- 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';
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));
EXEC (@Command);
--PRINT N'Executed: ' + @command;
END;
-- Close and deallocate the cursor.
CLOSE partitions;
DEALLOCATE partitions;
-- Drop the temporary table.
DROP TABLE #work_to_do;
GO
/*
UPDATE STATISTICS IMMEDIATELY AFTER REBUILD & REORGANIZE OPERATION PERFORMED.
*/
SET NOCOUNT ON
DECLARE @columnname VARCHAR(MAX)
DECLARE @tablename SYSNAME
DECLARE @statsname SYSNAME
DECLARE @sql NVARCHAR(4000)
DECLARE @NAME VARCHAR(MAX)
declare @i INT
declare @j INT
CREATE TABLE #Temp
(
TableName VARCHAR(1000),
StatsName VARCHAR(1000),
ColumnName VARCHAR(1000)
)
insert #Temp(TableName,StatsName,ColumnName)
SELECT DISTINCT
OBJECT_NAME(s.[object_id]),
s.name AS StatName,
COALESCE(@NAME+ ', ', '')+c.name
FROM sys.stats s JOIN sys.stats_columns sc ON sc.[object_id] = s.[object_id] AND sc.stats_id = s.stats_id
JOIN sys.columns c ON c.[object_id] = sc.[object_id] AND c.column_id = sc.column_id
JOIN INFORMATION_SCHEMA.COLUMNS D ON D.[COLUMN_NAME]= C.[NAME]
JOIN sys.partitions par ON par.[object_id] = s.[object_id]
JOIN sys.objects obj ON par.[object_id] = obj.[object_id]
WHERE OBJECTPROPERTY(s.OBJECT_ID,'IsUserTable') = 1
CREATE TABLE #Temp1
(
id int identity(1,1),
TableName VARCHAR(8000),
StatsName VARCHAR(8000),
ColumnName VARCHAR(8000)
)
insert #Temp1(TableName,StatsName,ColumnName)
select TableName,StatsName,stuff(
(
select ','+ [ColumnName] FROM #temp where
StatsName = t.StatsName for XML path('')
),1,1,'')
from (select distinct TableName,StatsName from #Temp )t
SELECT @i=1
SELECT @j=MAX(ID) FROM #Temp1
WHILE(@I<=@J)
BEGIN
SELECT @statsname = statsname FROM #Temp1 where id = @i
SELECT @tablename = TableName FROM #Temp1 where id = @i
SELECT @columnname = columnname FROM #Temp1 where id = @i
SET @sql = N'UPDATE STATISTICS '+QUOTENAME(@tablename)+QUOTENAME(@statsname)
PRINT @sql
EXEC sp_executesql @sql
SET @i = @i+1
END
DROP TABLE #Temp
DROP TABLE #Temp1
No comments:
Post a Comment