USE [msdb] GO /****** Object: Job [MSDB Custom Purge] Script Date: 10/11/2012 15:51:35 ******/ BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 /****** Object: JobCategory [[Uncategorized (Local)]]] Script Date: 10/11/2012 15:51:35 ******/ 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'MSDB Custom Purge', @enabled=1, @notify_level_eventlog=0, @notify_level_email=0, @notify_level_netsend=0, @notify_level_page=0, @delete_level=0, @description=N'No description available.', @category_name=N'[Uncategorized (Local)]', @owner_login_name=N'sa', @job_id = @jobId OUTPUT IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback /****** Object: Step [Purge] Script Date: 10/11/2012 15:51:35 ******/ EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Purge', @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'DELETE FROM sysjobhistory WHERE instance_id NOT IN (SELECT final.instance_id FROM sysjobhistory final INNER JOIN (SELECT instance_id,ranked30.job_id, (CAST(run_date AS FLOAT)*1000000)+run_time AS starttime, (CAST(run_date AS FLOAT)*1000000)+run_time+run_duration AS endtime FROM (SELECT *,RANK() OVER (PARTITION BY job_id ORDER BY instance_id DESC) AS RowNum FROM sysjobhistory WHERE step_id=0 AND run_status = 1) ranked30 INNER JOIN sysjobs sj ON sj.job_id=ranked30.job_id WHERE RowNum <= 30) top30 ON final.job_id=top30.job_id AND (CAST(final.run_date AS FLOAT)*1000000)+final.run_time >= top30.starttime AND (CAST(final.run_date AS FLOAT)*1000000)+final.run_time <= top30.endtime UNION SELECT final.instance_id FROM sysjobhistory final INNER JOIN (SELECT instance_id,ranked20.job_id, (CAST(run_date AS FLOAT)*1000000)+run_time AS starttime, (CAST(run_date AS FLOAT)*1000000)+run_time+run_duration AS endtime FROM (SELECT *,RANK() OVER (PARTITION BY job_id ORDER BY instance_id DESC) AS RowNum FROM sysjobhistory WHERE step_id=0 AND run_status <> 1) ranked20 INNER JOIN sysjobs sj ON sj.job_id=ranked20.job_id WHERE RowNum <= 20) top20 ON final.job_id=top20.job_id AND (CAST(final.run_date AS FLOAT)*1000000)+final.run_time >= top20.starttime AND (CAST(final.run_date AS FLOAT)*1000000)+final.run_time <= top20.endtime)', @database_name=N'msdb', @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'Daily', @enabled=1, @freq_type=4, @freq_interval=1, @freq_subday_type=1, @freq_subday_interval=0, @freq_relative_interval=0, @freq_recurrence_factor=0, @active_start_date=20121011, @active_end_date=99991231, @active_start_time=10000, @active_end_time=235959 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)' IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback COMMIT TRANSACTION GOTO EndSave QuitWithRollback: IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION EndSave: GO