USE [msdb] GO /****** Object: StoredProcedure [dbo].[usp_ScheduleJob] Script Date: 10/18/2025 9:52:04 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE OR ALTER PROCEDURE [dbo].[usp_ScheduleJob] @JobName NVARCHAR(100), @Env CHAR(4), -- 'DEVL' | 'TEST' | 'PROD' @RunDate DATE, @RunTime TIME AS BEGIN SET NOCOUNT ON; DECLARE @JobId UNIQUEIDENTIFIER, @ScheduleName NVARCHAR(200), @dbName NVARCHAR(128), @ActiveStartDate INT, @ActiveStartTime INT, @Sql NVARCHAR(MAX), @JobExists BIT = 0, @ScheduleId INT; -- Table variable must be declared separately and at the top level DECLARE @ExistingSchedules TABLE ( schedule_id INT, schedule_name NVARCHAR(200) ); -- Map environment to actual DB name SET @dbName = CASE @Env WHEN 'DEVL' THEN 'DevlDUTASJobSchedule' WHEN 'TEST' THEN 'TestDUTASJobSchedule' WHEN 'PROD' THEN 'ProdDUTASJobSchedule' ELSE 'DevlDUTASJobSchedule' END; -- Validate parameters IF @Env NOT IN ('DEVL','TEST','PROD') BEGIN RAISERROR('Env must be one of: DEVL, TEST, PROD.', 16, 1); RETURN; END IF @RunDate < CAST(GETDATE() AS DATE) BEGIN RAISERROR('RunDate cannot be in the past.', 16, 1); RETURN; END; -- Check if job exists in JobControl table SET @Sql = N'SELECT @JobExists = 1 FROM ' + QUOTENAME(@dbName) + '.dbo.JobControl WHERE JobName = @JobNameParam'; EXEC sp_executesql @Sql, N'@JobNameParam NVARCHAR(100), @JobExists BIT OUTPUT', @JobNameParam = @JobName, @JobExists = @JobExists OUTPUT; IF @JobExists = 0 BEGIN RAISERROR('Job %s not found in JobControl table.', 16, 1, @JobName); RETURN; END; -- Activate job in control table SET @Sql = N'UPDATE ' + QUOTENAME(@dbName) + '.dbo.JobControl SET IsActive = 1 WHERE JobName = @JobNameParam'; EXEC sp_executesql @Sql, N'@JobNameParam NVARCHAR(100)', @JobNameParam = @JobName; PRINT 'Job activated in JobControl.'; -- Convert date/time to SQL Agent format SET @ActiveStartDate = CONVERT(INT, CONVERT(CHAR(8), @RunDate, 112)); SET @ActiveStartTime = DATEPART(HOUR, @RunTime) * 10000 + DATEPART(MINUTE, @RunTime) * 100 + DATEPART(SECOND, @RunTime); SET @ScheduleName = @JobName + '_MonthlySchedule'; -- Get job id SELECT @JobId = job_id FROM msdb.dbo.sysjobs WHERE name = @JobName; IF @JobId IS NULL BEGIN RAISERROR('SQL Agent job "%s" not found.', 16, 1, @JobName); RETURN; END; BEGIN TRY BEGIN TRANSACTION; -- Detach and delete all existing schedules for this job INSERT INTO @ExistingSchedules (schedule_id, schedule_name) SELECT s.schedule_id, s.name FROM msdb.dbo.sysschedules AS s INNER JOIN msdb.dbo.sysjobschedules AS js ON s.schedule_id = js.schedule_id WHERE js.job_id = @JobId; DECLARE @OldScheduleId INT, @OldScheduleName NVARCHAR(200); DECLARE cur CURSOR LOCAL FAST_FORWARD FOR SELECT schedule_id, schedule_name FROM @ExistingSchedules; OPEN cur; FETCH NEXT FROM cur INTO @OldScheduleId, @OldScheduleName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT 'Detaching old schedule: ' + @OldScheduleName; EXEC msdb.dbo.sp_detach_schedule @job_id = @JobId, @schedule_name = @OldScheduleName; PRINT 'Deleting old schedule: ' + @OldScheduleName; EXEC msdb.dbo.sp_delete_schedule @schedule_name = @OldScheduleName; FETCH NEXT FROM cur INTO @OldScheduleId, @OldScheduleName; END CLOSE cur; DEALLOCATE cur; -- Create new one-time schedule EXEC msdb.dbo.sp_add_schedule @schedule_name = @ScheduleName, @enabled = 1, @freq_type = 1, -- One-time @active_start_date = @ActiveStartDate, @active_start_time = @ActiveStartTime; -- Attach schedule to job EXEC msdb.dbo.sp_attach_schedule @job_id = @JobId, @schedule_name = @ScheduleName; COMMIT TRANSACTION; PRINT 'New schedule created for job "' + @JobName + '" on ' + CONVERT(VARCHAR(10), @RunDate, 120) + ' at ' + CONVERT(VARCHAR(8), @RunTime, 108); END TRY BEGIN CATCH IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION; DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); RAISERROR('Error creating schedule: %s', 16, 1, @ErrorMessage); END CATCH; END; GO