/****************************************************** XX_MasterJob ******************************************************/ USE [msdb] GO BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 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'XX_MasterJob', @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 EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'XX_MasterJob_Start', @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=N'INSERT dbo.Demo (JobStep) VALUES (''XX_MasterJob_Start'')', @database_name=N'SQLAgentWorkflows', @flags=0 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Start_XX_Subjob_Async01', @step_id=2, @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=N'EXEC dbo.sp_start_job N''XX_Subjob_Async01''; GO ', @database_name=N'msdb', @flags=0 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Start_XX_Subjob_Async02_Will_Fail', @step_id=3, @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=N'EXEC dbo.sp_start_job N''XX_Subjob_Async02_Will_Fail''; GO ', @database_name=N'msdb', @flags=0 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Start_XX_Subjob_Async03', @step_id=4, @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=N'EXEC dbo.sp_start_job N''XX_Subjob_Async03''; GO ', @database_name=N'msdb', @flags=0 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Start_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03', @step_id=5, @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=N'EXEC dbo.sp_start_job N''XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03''; GO ', @database_name=N'msdb', @flags=0 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Start_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success', @step_id=6, @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'EXEC dbo.sp_start_job N''XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success''; GO ', @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_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 /****************************************************** XX_Subjob_Async01 ******************************************************/ USE [msdb] GO BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 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'XX_Subjob_Async01', @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 EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'XX_Subjob_Async01', @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'WAITFOR DELAY ''00:00:05'' INSERT dbo.Demo (JobStep) VALUES (''XX_Subjob_Async01'')', @database_name=N'SQLAgentWorkflows', @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_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 /****************************************************** XX_Subjob_Async02_Will_Fail ******************************************************/ USE [msdb] GO BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 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'XX_Subjob_Async02_Will_Fail', @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 EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'XX_Subjob_Async02_Will_Fail', @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'WAITFOR DELAY ''00:00:05'' GO INSERT dbo.Demo (JobStep_XX) VALUES (''XX_Subjob_Async02_Will_Fail'')', @database_name=N'SQLAgentWorkflows', @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_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 /****************************************************** XX_Subjob_Async03 ******************************************************/ USE [msdb] GO BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 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'XX_Subjob_Async03', @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 EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'XX_Subjob_Async03', @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'WAITFOR DELAY ''00:00:05'' INSERT dbo.Demo (JobStep) VALUES (''XX_Subjob_Async03'')', @database_name=N'SQLAgentWorkflows', @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_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 /****************************************************** XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03 ******************************************************/ USE [msdb] GO BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 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'XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03', @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'EURO\toli71', @job_id = @jobId OUTPUT IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03', @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'IF OBJECT_ID(''tempdb..#tmp_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03'') IS NOT NULL DROP TABLE #tmp_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03 CREATE TABLE #tmp_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03 ( job_id UNIQUEIDENTIFIER NOT NULL ,last_run_date INT NOT NULL ,last_run_time INT NOT NULL ,next_run_date INT NOT NULL ,next_run_time INT NOT NULL ,next_run_schedule_id INT NOT NULL ,requested_to_run INT NOT NULL ,request_source INT NOT NULL ,request_source_id NVARCHAR(256) NULL ,running INT NOT NULL ,current_step INT NOT NULL ,current_retry_attempt INT NOT NULL ,job_state INT NOT NULL ) INSERT INTO #tmp_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03 EXEC master.dbo.xp_sqlagent_enum_jobs @is_sysadmin = 1, @job_owner = '''' /*************************************************** If the job we depend on is executing ... wait ... ***************************************************/ WHILE EXISTS ( SELECT TMP.* FROM msdb.dbo.sysjobs SJ JOIN #tmp_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03 TMP ON SJ.job_id = TMP.job_id WHERE SJ.name = ''XX_Subjob_Async03'' AND TMP.current_step <> 0 ) BEGIN WAITFOR DELAY ''00:00:10'' DELETE FROM #tmp_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03 INSERT INTO #tmp_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03 EXEC master.dbo.xp_sqlagent_enum_jobs @is_sysadmin = 1, @job_owner = '''' END DROP TABLE #tmp_XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03 INSERT dbo.Demo (JobStep) VALUES (''XX_Subjob_Sync01_Waits_for_XX_Subjob_Async03'')', @database_name=N'SQLAgentWorkflows', @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_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 /****************************************************** XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success ******************************************************/ USE [msdb] GO /****** Object: Job [XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success] Script Date: 2015-02-25 09:44:29 ******/ BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 /****** Object: JobCategory [[Uncategorized (Local)]] Script Date: 2015-02-25 09:44:29 ******/ 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'XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success', @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 [XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success] Script Date: 2015-02-25 09:44:29 ******/ EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success', @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'IF OBJECT_ID(''tempdb..#tmp_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success'') IS NOT NULL DROP TABLE #tmp_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success CREATE TABLE #tmp_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success ( job_id UNIQUEIDENTIFIER NOT NULL ,last_run_date INT NOT NULL ,last_run_time INT NOT NULL ,next_run_date INT NOT NULL ,next_run_time INT NOT NULL ,next_run_schedule_id INT NOT NULL ,requested_to_run INT NOT NULL ,request_source INT NOT NULL ,request_source_id NVARCHAR(256) NULL ,running INT NOT NULL ,current_step INT NOT NULL ,current_retry_attempt INT NOT NULL ,job_state INT NOT NULL ) INSERT INTO #tmp_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success EXEC master.dbo.xp_sqlagent_enum_jobs @is_sysadmin = 1, @job_owner = '''' /*************************************************** If the job we depend on is executing ... wait ... ***************************************************/ WHILE EXISTS ( SELECT TMP.* FROM msdb.dbo.sysjobs SJ JOIN #tmp_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success TMP ON SJ.job_id = TMP.job_id WHERE SJ.name = ''XX_Subjob_Async02_Will_Fail'' AND TMP.current_step <> 0 ) BEGIN WAITFOR DELAY ''00:00:10'' DELETE FROM #tmp_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success INSERT INTO #tmp_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success EXEC master.dbo.xp_sqlagent_enum_jobs @is_sysadmin = 1, @job_owner = '''' END DROP TABLE #tmp_XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success /*************************************************** If the last execution of the job we depend on was anything else but success, raise an error and quit. ***************************************************/ IF EXISTS ( SELECT * FROM msdb.dbo.sysjobs AS SJ JOIN msdb.dbo.sysjobhistory SH_Latest ON SJ.job_id = SH_Latest.job_id AND SH_Latest.step_id = 0 AND SH_Latest.instance_id = (SELECT MAX(instance_id) FROM msdb.dbo.sysjobhistory SH_Max WHERE SH_Max.job_id = SH_Latest.job_id) AND SH_Latest.run_status <> 1 AND SJ.name = ''XX_Subjob_Async02_Will_Fail'' ) BEGIN THROW 50000, ''The XX_Subjob_Async02_Will_Fail failed!'', 1 END ELSE INSERT dbo.Demo (JobStep) VALUES (''XX_Subjob_Sync02_Waits_for_XX_Subjob_Async02_to_complete_with_success'') ', @database_name=N'SQLAgentWorkflows', @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_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