Self Deleting Job
I am a Production DBA, and my team supports several thousands instances of MS SQL.
Frequently, we get a request to grant temporary access to server XYZ, either sysadmin or DBO to certain databases.
It has become a challenge to remember to go back and remove the privileges, so I devised a little script to take care of it.
It's nothing really new, it is just a job with a self deleting feature, where I add a step to delete the job.
What do you need to do?
Give the Job a name, a schedule, and the TSQL command that you want to run. That simple!
After the job runs, it will self-destruct.
Error Handling:
Since the Job is deleting it self before it finish executing, there will be an entry on your SQL Agent log that would say:
[180] Job SelfDeletingJob was deleted while it was executing: the outcome was (Unknown)
/*
Autor: Miguel Quintana
Email: mig.qui@gmail.com
*/BEGIN TRANSACTION
USE [msdb]
GO
DECLARE @JOBNAME nvarchar(10)
DECLARE @SQLCMD nvarchar(100)
DECLARE @STARTDATE nvarchar(8)
DECLARE @STARTTIME nvarchar(6)
DECLARE @SQLCMD2 nvarchar(100)
SET @JOBNAME='SelfDeletingJob'-- Name your job appropiately
SET @STARTDATE='201112311'-- Date format: YYYYMMDD
SET @STARTTIME='120000'-- Time format: hhmmss (military time)
-- Below Enter the command that you want to schedule. In this case, it is removing a login from the sysadmin role
SET @SQLCMD='EXEC master..sp_dropsrvrolemember @loginame = N''temp_sysadmin'', @rolename = N''sysadmin'''
-- Do not change below this line
SET @SQLCMD2 ='EXEC msdb.dbo.sp_delete_job @job_name='+@JOBNAME+', @delete_unused_schedule=1'
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object: JobCategory [[Uncategorized (Local)]]] Script Date: 12/29/2011 09:50:28 ******/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=@JOBNAME,
@enabled=1,
@notify_level_eventlog=0,
@notify_level_email=0,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'Self Deleting Job',
@category_name=N'[Uncategorized (Local)]',
@owner_login_name=N'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [step] ******/EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'step',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=3,
@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=@SQLCMD,
@database_name=N'master',
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [step2] ******/EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'step2',
@step_id=2,
@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=@SQLCMD2,
@database_name=N'master',
@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'test',
@enabled=1,
@freq_type=1,
@freq_interval=0,
@freq_subday_type=0,
@freq_subday_interval=0,
@freq_relative_interval=0,
@freq_recurrence_factor=0,
@active_start_date=@STARTDATE,
@active_end_date=99991231,
@active_start_time=@STARTTIME,
@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