Files
DUTAS/SQLAgent/02_Test/3_Stored_Procedures/usp_CreateDailyJobSchedule.sql
2025-10-20 07:54:46 -04:00

98 lines
3.4 KiB
Transact-SQL

USE msdb;
GO
CREATE OR ALTER PROCEDURE dbo.usp_CreateDailyJobSchedule
@Env VARCHAR(10) = 'DEVL' -- Added parameter with default value
AS
BEGIN
SET NOCOUNT ON;
DECLARE
@JobID INT,
@JobName SYSNAME,
@ScheduledStartTime TIME(0),
@Frequency NVARCHAR(20),
@FrequencyPattern NVARCHAR(MAX),
@ScheduleName SYSNAME,
@StartTimeInt INT,
@FreqInterval INT,
@TimeString VARCHAR(8),
@ActiveStartDate INT,
@dbName SYSNAME; -- Added variable for database name
-- Determine database name based on environment
SET @dbName = CASE @Env
WHEN 'DEVL' THEN 'DevlDUTASJobSchedule'
WHEN 'TEST' THEN 'TestDUTASJobSchedule'
WHEN 'PROD' THEN 'ProdDUTASJobSchedule'
END;
-- Prepare active start date as INT (YYYYMMDD)
SET @ActiveStartDate = CONVERT(INT, CONVERT(CHAR(8), GETDATE(), 112));
-- Dynamic SQL to fetch jobs from the appropriate database
DECLARE @Sql NVARCHAR(MAX);
SET @Sql = N'
DECLARE job_cursor CURSOR FOR
SELECT JobID, JobName, ScheduledStartTime, Frequency, FrequencyPattern
FROM ' + QUOTENAME(@dbName) + N'.dbo.JobControl
WHERE UPPER(Frequency) = ''DAILY''
AND IsActive = 1;';
-- Execute dynamic SQL to declare cursor
EXEC sp_executesql @Sql;
OPEN job_cursor;
FETCH NEXT FROM job_cursor INTO @JobID, @JobName, @ScheduledStartTime, @Frequency, @FrequencyPattern;
WHILE @@FETCH_STATUS = 0
BEGIN
-- Step 1: Convert ScheduledStartTime (TIME) to HH:MM:SS string
SET @TimeString = CONVERT(VARCHAR(8), @ScheduledStartTime, 108);
-- Step 2: Remove colons and convert to INT (HHMMSS)
SET @StartTimeInt = CONVERT(INT, REPLACE(@TimeString, ':', ''));
-- Step 3: Prepare schedule name
SET @ScheduleName = CONCAT(@JobName, '_DailySchedule');
-- Step 4: Fixed freq_interval for Monday to Friday
SET @FreqInterval = 62; -- Mon(2)+Tue(4)+Wed(8)+Thu(16)+Fri(32) = 62
-- Step 5: Delete existing schedule if it exists (idempotency)
IF EXISTS (
SELECT 1
FROM msdb.dbo.sysschedules s
JOIN msdb.dbo.sysjobschedules js ON s.schedule_id = js.schedule_id
JOIN msdb.dbo.sysjobs j ON j.job_id = js.job_id
WHERE j.name = @JobName AND s.name = @ScheduleName
)
BEGIN
EXEC msdb.dbo.sp_delete_schedule @schedule_name = @ScheduleName;
END
-- Step 6: Create weekly schedule (Monday to Friday) running once per day
EXEC msdb.dbo.sp_add_schedule
@schedule_name = @ScheduleName,
@enabled = 1,
@freq_type = 8, -- weekly
@freq_interval = @FreqInterval,
@freq_recurrence_factor = 1, -- every week
@active_start_time = @StartTimeInt,
@active_start_date = @ActiveStartDate;
-- Step 7: Attach schedule to job
EXEC msdb.dbo.sp_attach_schedule
@job_name = @JobName,
@schedule_name = @ScheduleName;
-- Fetch next job
FETCH NEXT FROM job_cursor INTO @JobID, @JobName, @ScheduledStartTime, @Frequency, @FrequencyPattern;
END
CLOSE job_cursor;
DEALLOCATE job_cursor;
PRINT 'Daily job schedules (Monday to Friday) created successfully for ' + @dbName;
END;
GO