USE [msdb]
GO
/****** Object:
Job [Rebuild Indexes] Script
Date: 02/18/2010 10:40:16 ******/
BEGIN TRANSACTION
DECLARE
@ReturnCode INT
DECLARE
@YourDatabaseName sysname
DECLARE
@YourServerName sysname
-- set your server and database names here
!!!!!!!!
SELECT
@YourDatabaseName = 'QA
5mil',@YourServername = 'NOGINLAPTOP\yn_sql2008'
--important step !!!!!!!!!
SELECT
@ReturnCode = 0
/****** Object:
JobCategory [[Uncategorized (Local)]]]
Script Date: 02/18/2010 10:40:16 ******/
IF NOT
EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE
name=N'[Uncategorized
(Local)]' AND category_class=1)
BEGIN
EXEC
@ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
IF (@@ERROR <> 0 OR @ReturnCode <>
0) GOTO
QuitWithRollback
END
DECLARE @jobId BINARY(16)
EXEC
@ReturnCode =
msdb.dbo.sp_add_job @job_name=N'Rebuild Indexes',
@enabled=1,
@notify_level_eventlog=0,
@notify_level_email=0,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'Defragment Indexes.',
@category_name=N'[Uncategorized (Local)]',
@owner_login_name=N'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <>
0) GOTO
QuitWithRollback
/****** Object:
Step [Rebuild Indexes] Script
Date: 02/18/2010 10:40:17 ******/
EXEC
@ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Rebuild Indexes',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=1,
@on_success_step_id=0,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
@command=N'--Step 1 - rebuild all
fragmented indexes
SET NOCOUNT ON ;
DECLARE cur CURSOR FOR
SELECT t.NAME FROM sys.tables t WHERE name LIKE
''x%'' ;
DECLARE @tablename NVARCHAR(255) ;
IF OBJECT_ID(''tempdb.dbo.#tmp'') > 0
DROP
TABLE #tmp
CREATE TABLE #tmp
(
tablename NVARCHAR(255) ,
indexname NVARCHAR(255) ,
avg_fragmentation_percent NUMERIC(10, 2) ,
page_count INT
)
OPEN cur ;
FETCH NEXT FROM cur INTO @tablename ;
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO #tmp
( tablename ,
indexname ,
avg_fragmentation_percent ,
page_count
)
SELECT @tablename AS TABLENAME ,
b.name AS INDEXNAME ,
avg_fragmentation_in_percent ,
si.dpages
FROM sys.dm_db_index_physical_stats(DB_ID(),
OBJECT_ID(@tablename),
NULL, NULL, NULL) AS a
JOIN sys.indexes AS b
ON a.object_id = b.object_id
AND a.index_id = b.index_id
INNER JOIN sys.tables t
ON a.object_id = t.object_id
INNER JOIN SYSINDEXES
si ON si.id = t.object_id
AND si.indid =
b.index_id ;
FETCH
NEXT FROM cur INTO @tablename ;
END ;
CLOSE cur ;
DEALLOCATE cur ;
DECLARE cur_exec CURSOR FOR
SELECT DISTINCT ''alter index all on '' + tablename
+ '' REBUILD WITH (FILLFACTOR = 80); '' FROM #tmp WHERE
avg_fragmentation_percent > 20
AND page_count > 10 ;
DECLARE @SQLExec NVARCHAR(600) ;
OPEN cur_exec ;
FETCH NEXT FROM cur_exec INTO @SQLExec ;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT
''altering index: '' + @SQLExec
EXEC sp_executesql @SQLExec ;
--PRINT @SQLExec;
FETCH
NEXT FROM cur_exec INTO @SQLExec ;
END ;
CLOSE cur_exec ;
DEALLOCATE cur_exec ;
IF OBJECT_ID(''tempdb.dbo.#tmp'') > 0
DROP
TABLE #tmp
',
@database_name=@YourDatabaseName,
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <>
0) GOTO
QuitWithRollback
EXEC
@ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
IF (@@ERROR <> 0 OR @ReturnCode <>
0) GOTO
QuitWithRollback
EXEC
@ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'RebuildIndexes',
@enabled=1,
@freq_type=8,
@freq_interval=1,
@freq_subday_type=1,
@freq_subday_interval=0,
@freq_relative_interval=0,
@freq_recurrence_factor=1,
@active_start_date=20100108,
@active_end_date=99991231,
@active_start_time=40000,
@active_end_time=235959,
@schedule_uid=N'5dc98bca-9240-4157-843f-a9c48d92f38d'
IF (@@ERROR <> 0 OR @ReturnCode <>
0) GOTO
QuitWithRollback
EXEC
@ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name =
@YourServerName
IF (@@ERROR <> 0 OR @ReturnCode <>
0) GOTO
QuitWithRollback
COMMIT TRANSACTION
GOTO EndSave
QuitWithRollback:
IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
EndSave:
GO
Related Topics
The DBA steps (somewhat manual)