Add updated SqlAgent folder

This commit is contained in:
Neeraj Kumar
2025-11-02 14:50:48 -05:00
parent 2c94b89801
commit 8fca292a50
141 changed files with 6723 additions and 0 deletions

View File

@ -0,0 +1,98 @@
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

View File

@ -0,0 +1,223 @@
USE [msdb];
GO
CREATE OR ALTER PROCEDURE dbo.usp_CreateWeeklySchedules
@Env VARCHAR(10) = 'DEVL' -- Added parameter with default value
AS
BEGIN
SET NOCOUNT ON;
DECLARE
@JobName SYSNAME,
@FrequencyPattern NVARCHAR(MAX),
@StartTime VARCHAR(50),
@ScheduleName SYSNAME,
@StartTimeInt INT,
@FreqInterval INT,
@ActiveDate INT,
@computedFreq 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;
SET @ActiveDate = CONVERT(INT, CONVERT(CHAR(8), GETDATE(), 112));
--------------------------------------------------------------------------
-- Dynamic SQL for cursor to fetch active weekly jobs from appropriate database
--------------------------------------------------------------------------
DECLARE @Sql NVARCHAR(MAX);
SET @Sql = N'
DECLARE job_cursor CURSOR FAST_FORWARD FOR
SELECT
JobName,
FrequencyPattern,
ScheduledStartTime
FROM ' + QUOTENAME(@dbName) + N'.dbo.JobControl
WHERE UPPER(Frequency) = ''WEEKLY''
AND IsActive = 1;';
-- Execute dynamic SQL to declare cursor
EXEC sp_executesql @Sql;
OPEN job_cursor;
FETCH NEXT FROM job_cursor INTO @JobName, @FrequencyPattern, @StartTime;
WHILE @@FETCH_STATUS = 0
BEGIN
BEGIN TRY
------------------------------------------------------------------
-- Reset per-job variables
------------------------------------------------------------------
SET @FreqInterval = 0;
SET @computedFreq = 0;
SET @StartTimeInt = NULL;
SET @ScheduleName = NULL;
------------------------------------------------------------------
-- Correctly format the start time (HHMMSS without extra zeros)
------------------------------------------------------------------
SET @StartTime = LTRIM(RTRIM(ISNULL(@StartTime, '00:00:00')));
-- Parse time and convert to HHMMSS integer
DECLARE @TimeParts TABLE (part NVARCHAR(10), idx INT);
INSERT INTO @TimeParts (part, idx)
SELECT value, ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) - 1
FROM STRING_SPLIT(LEFT(@StartTime, 8), ':');
DECLARE @Hours INT, @Minutes INT, @Seconds INT;
SELECT @Hours = CAST(part AS INT) FROM @TimeParts WHERE idx = 0;
SELECT @Minutes = CAST(part AS INT) FROM @TimeParts WHERE idx = 1;
SELECT @Seconds = CAST(part AS INT) FROM @TimeParts WHERE idx = 2;
-- Ensure valid time ranges
SET @Hours = ISNULL(@Hours, 0);
SET @Minutes = ISNULL(@Minutes, 0);
SET @Seconds = ISNULL(@Seconds, 0);
IF @Hours < 0 OR @Hours > 23 SET @Hours = 0;
IF @Minutes < 0 OR @Minutes > 59 SET @Minutes = 0;
IF @Seconds < 0 OR @Seconds > 59 SET @Seconds = 0;
SET @StartTimeInt = (@Hours * 10000) + (@Minutes * 100) + @Seconds;
SET @ScheduleName = CONCAT(@JobName, '_WeeklySchedule');
------------------------------------------------------------------
-- Parse JSON days using a local temporary table
------------------------------------------------------------------
CREATE TABLE #Days (DayName NVARCHAR(10));
INSERT INTO #Days (DayName)
SELECT TRIM(value)
FROM OPENJSON(ISNULL(@FrequencyPattern, '{}'), '$.Days');
------------------------------------------------------------------
-- Compute bitmask correctly (values should be 1-127)
------------------------------------------------------------------
SELECT @computedFreq = ISNULL(SUM(
CASE UPPER(DayName)
WHEN 'SUN' THEN 1
WHEN 'MON' THEN 2
WHEN 'TUE' THEN 4
WHEN 'WED' THEN 8
WHEN 'THU' THEN 16
WHEN 'FRI' THEN 32
WHEN 'SAT' THEN 64
ELSE 0
END
), 0)
FROM #Days;
DROP TABLE #Days; -- Explicitly drop the temp table
SET @FreqInterval = ISNULL(@computedFreq, 0);
------------------------------------------------------------------
-- Validate freq_interval (must be 1..127)
------------------------------------------------------------------
IF @FreqInterval < 1 OR @FreqInterval > 127
BEGIN
PRINT 'Warning: Weekly job ' + @JobName +
' has invalid freq_interval (' + ISNULL(CAST(@FreqInterval AS VARCHAR(10)), 'NULL') +
'). Days found: ' + ISNULL(@FrequencyPattern, 'None') + '. Skipping.';
FETCH NEXT FROM job_cursor INTO @JobName, @FrequencyPattern, @StartTime;
CONTINUE;
END
------------------------------------------------------------------
-- Debug output to verify calculations
------------------------------------------------------------------
PRINT 'Job: ' + @JobName +
', Days: ' + @FrequencyPattern +
', FreqInterval: ' + CAST(@FreqInterval AS VARCHAR(3)) +
', StartTime: ' + CAST(@StartTimeInt AS VARCHAR(6));
------------------------------------------------------------------
-- Safely detach and delete any existing schedule with this name
-- Use TRY/CATCH for schedule operations since non-existence is expected
------------------------------------------------------------------
BEGIN TRY
DECLARE @schedule_id INT;
DECLARE @attach_count INT;
-- Check if schedule exists and get its ID
SELECT @schedule_id = s.schedule_id
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;
IF @schedule_id IS NOT NULL
BEGIN
-- Detach from this job (if attached)
EXEC msdb.dbo.sp_detach_schedule
@job_name = @JobName,
@schedule_name = @ScheduleName;
-- Check if schedule still attached to other jobs
SELECT @attach_count = COUNT(*)
FROM msdb.dbo.sysjobschedules js
WHERE js.schedule_id = @schedule_id;
IF @attach_count = 0
BEGIN
EXEC msdb.dbo.sp_delete_schedule
@schedule_name = @ScheduleName;
PRINT 'Existing schedule deleted: ' + @ScheduleName;
END
ELSE
BEGIN
PRINT 'Notice: schedule ' + @ScheduleName + ' could not be deleted because it is still attached to other jobs.';
END
END
END TRY
BEGIN CATCH
-- Schedule operations might fail if schedule doesn't exist, which is fine
PRINT 'Notice: ' + ERROR_MESSAGE() + ' - proceeding with new schedule creation.';
END CATCH
------------------------------------------------------------------
-- Create the unified weekly schedule with subday config
------------------------------------------------------------------
EXEC msdb.dbo.sp_add_schedule
@schedule_name = @ScheduleName,
@enabled = 1,
@freq_type = 8, -- Weekly
@freq_interval = @FreqInterval, -- Bitmask of weekdays
@freq_recurrence_factor = 1, -- Every week
@freq_subday_type = 1, -- Once per day
@freq_subday_interval = 1,
@active_start_time = @StartTimeInt,
@active_start_date = @ActiveDate;
------------------------------------------------------------------
-- Attach the schedule to the job
------------------------------------------------------------------
EXEC msdb.dbo.sp_attach_schedule
@job_name = @JobName,
@schedule_name = @ScheduleName;
PRINT 'Weekly schedule created for job: ' + @JobName +
' (Days=' + CAST(@FreqInterval AS VARCHAR(10)) +
', Time=' + RIGHT('000000' + CAST(@StartTimeInt AS VARCHAR(6)), 6) + ')';
END TRY
BEGIN CATCH
PRINT 'Error scheduling job ' + ISNULL(@JobName, 'Unknown') + ': ' + ERROR_MESSAGE();
END CATCH;
FETCH NEXT FROM job_cursor INTO @JobName, @FrequencyPattern, @StartTime;
END
CLOSE job_cursor;
DEALLOCATE job_cursor;
PRINT 'All weekly job schedules processed for ' + @dbName;
END;
GO

View File

@ -0,0 +1,261 @@
USE [DevlDUTASJobSchedule];
GO
CREATE OR ALTER PROCEDURE dbo.usp_GenerateJobSchedule
@Year INT
AS
BEGIN
SET NOCOUNT ON;
-------------------------------------------------------------------------
-- 1. Cleanup existing schedule data for this year
-------------------------------------------------------------------------
DELETE FROM dbo.JobSchedule WHERE YearOfSchedule = @Year;
-------------------------------------------------------------------------
-- 2. Variable declarations
-------------------------------------------------------------------------
DECLARE
@JobName VARCHAR(100),
@Frequency VARCHAR(20),
@Pattern NVARCHAR(2000),
@ScheduledTime TIME,
@RuleName NVARCHAR(100),
@Month INT,
@BaseDate DATE,
@ScheduledDate DATE,
@AdjustedDate DATE,
@FailSafeDate DATE = '9999-12-31';
-------------------------------------------------------------------------
-- 3. Temporary table to process jobs more efficiently
-------------------------------------------------------------------------
CREATE TABLE #JobProcessing (
JobName VARCHAR(100),
Frequency VARCHAR(20),
Pattern NVARCHAR(2000),
ScheduledTime TIME,
RuleName NVARCHAR(100),
MonthsJSON NVARCHAR(MAX),
DayNum INT,
HasExplicitSchedule BIT
);
-- Populate temporary table with parsed JSON data
INSERT INTO #JobProcessing (JobName, Frequency, Pattern, ScheduledTime, RuleName, MonthsJSON, DayNum, HasExplicitSchedule)
SELECT
jc.JobName,
jc.Frequency,
jc.FrequencyPattern,
jc.ScheduledStartTime,
JSON_VALUE(jc.FrequencyPattern, '$.Rule'),
JSON_QUERY(jc.FrequencyPattern, '$.Months'),
JSON_VALUE(jc.FrequencyPattern, '$.Day'),
CASE WHEN JSON_QUERY(jc.FrequencyPattern, '$.Schedule') IS NOT NULL THEN 1 ELSE 0 END
FROM dbo.JobControl jc
WHERE UPPER(jc.Frequency) IN ('MONTHLY','QUARTERLY')
AND jc.IsActive = 1;
-------------------------------------------------------------------------
-- 4. Process MONTHLY jobs
-------------------------------------------------------------------------
INSERT INTO dbo.JobSchedule (JobName, Frequency, ScheduledRule, ScheduledDate, AdjustedRunDate, MonthOfSchedule, YearOfSchedule, CreatedOn, CreatedBy)
SELECT
jp.JobName,
jp.Frequency,
jp.Pattern,
CASE
WHEN jp.RuleName = 'FirstWorkday' THEN dbo.fn_GetNextWorkday(DATEFROMPARTS(@Year, m.MonthNum, 1))
WHEN jp.RuleName = 'LastWorkday' THEN dbo.fn_GetPreviousWorkday(EOMONTH(DATEFROMPARTS(@Year, m.MonthNum, 1)))
ELSE @FailSafeDate
END AS ScheduledDate,
CASE
WHEN jp.RuleName = 'FirstWorkday' THEN dbo.fn_GetNextWorkday(DATEFROMPARTS(@Year, m.MonthNum, 1))
WHEN jp.RuleName = 'LastWorkday' THEN dbo.fn_GetPreviousWorkday(EOMONTH(DATEFROMPARTS(@Year, m.MonthNum, 1)))
ELSE @FailSafeDate
END AS AdjustedRunDate,
FORMAT(DATEFROMPARTS(@Year, m.MonthNum, 1), 'yyyy-MM'),
@Year,
GETDATE(),
SYSTEM_USER
FROM #JobProcessing jp
CROSS JOIN (VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12)) m(MonthNum)
WHERE jp.Frequency = 'MONTHLY'
AND jp.RuleName IN ('FirstWorkday', 'LastWorkday');
-- Handle monthly jobs with unknown rules
INSERT INTO dbo.JobSchedule (JobName, Frequency, ScheduledRule, ScheduledDate, AdjustedRunDate, MonthOfSchedule, YearOfSchedule, CreatedOn, CreatedBy)
SELECT
jp.JobName,
jp.Frequency,
jp.Pattern,
@FailSafeDate,
@FailSafeDate,
FORMAT(DATEFROMPARTS(@Year, m.MonthNum, 1), 'yyyy-MM'),
@Year,
GETDATE(),
SYSTEM_USER
FROM #JobProcessing jp
CROSS JOIN (VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12)) m(MonthNum)
WHERE jp.Frequency = 'MONTHLY'
AND jp.RuleName NOT IN ('FirstWorkday', 'LastWorkday');
-------------------------------------------------------------------------
-- 5. Process QUARTERLY jobs - FirstWorkdayOfQuarter
-------------------------------------------------------------------------
INSERT INTO dbo.JobSchedule (JobName, Frequency, ScheduledRule, ScheduledDate, AdjustedRunDate, MonthOfSchedule, YearOfSchedule, CreatedOn, CreatedBy)
SELECT
jp.JobName,
jp.Frequency,
jp.Pattern,
dbo.fn_GetNextWorkday(DATEFROMPARTS(@Year, q.StartMonth, 1)),
dbo.fn_GetNextWorkday(DATEFROMPARTS(@Year, q.StartMonth, 1)),
FORMAT(DATEFROMPARTS(@Year, q.StartMonth, 1), 'yyyy-MM'),
@Year,
GETDATE(),
SYSTEM_USER
FROM #JobProcessing jp
CROSS JOIN (VALUES (1),(4),(7),(10)) q(StartMonth)
WHERE jp.Frequency = 'QUARTERLY'
AND jp.RuleName = 'FirstWorkdayOfQuarter';
-------------------------------------------------------------------------
-- 6. Process QUARTERLY jobs - Months array with Day number
-------------------------------------------------------------------------
;WITH QuarterlyMonths AS (
SELECT
jp.JobName,
jp.Frequency,
jp.Pattern,
CAST(m.[value] AS INT) AS MonthNum,
jp.DayNum
FROM #JobProcessing jp
CROSS APPLY OPENJSON(jp.MonthsJSON) m
WHERE jp.Frequency = 'QUARTERLY'
AND jp.MonthsJSON IS NOT NULL
AND jp.DayNum IS NOT NULL
AND jp.RuleName IS NULL
AND jp.HasExplicitSchedule = 0
),
QuarterlyDates AS (
SELECT
qm.JobName,
qm.Frequency,
qm.Pattern,
qm.MonthNum,
qm.DayNum,
CASE
WHEN qm.DayNum <= DAY(EOMONTH(DATEFROMPARTS(@Year, qm.MonthNum, 1)))
THEN DATEFROMPARTS(@Year, qm.MonthNum, qm.DayNum)
ELSE EOMONTH(DATEFROMPARTS(@Year, qm.MonthNum, 1))
END AS BaseDate
FROM QuarterlyMonths qm
)
INSERT INTO dbo.JobSchedule (JobName, Frequency, ScheduledRule, ScheduledDate, AdjustedRunDate, MonthOfSchedule, YearOfSchedule, CreatedOn, CreatedBy)
SELECT
qd.JobName,
qd.Frequency,
qd.Pattern,
qd.BaseDate,
CASE
WHEN DATENAME(WEEKDAY, qd.BaseDate) IN ('Saturday','Sunday')
OR EXISTS (SELECT 1 FROM dbo.FederalHolidays WHERE HolidayDate = qd.BaseDate)
THEN dbo.fn_GetPreviousWorkday(qd.BaseDate)
ELSE qd.BaseDate
END AS AdjustedRunDate,
FORMAT(qd.BaseDate, 'yyyy-MM'),
@Year,
GETDATE(),
SYSTEM_USER
FROM QuarterlyDates qd;
-------------------------------------------------------------------------
-- 7. Process QUARTERLY jobs - Explicit Schedule array
-------------------------------------------------------------------------
;WITH ExplicitSchedules AS (
SELECT
jp.JobName,
jp.Frequency,
jp.Pattern,
s.[Month] AS MonthNum,
s.[Day] AS DayNum
FROM #JobProcessing jp
CROSS APPLY OPENJSON(jp.Pattern, '$.Schedule')
WITH (
[Month] INT '$.Month',
[Day] INT '$.Day'
) s
WHERE jp.Frequency = 'QUARTERLY'
AND jp.HasExplicitSchedule = 1
),
ExplicitScheduleDates AS (
SELECT
es.JobName,
es.Frequency,
es.Pattern,
es.MonthNum,
es.DayNum,
CASE
WHEN es.DayNum <= DAY(EOMONTH(DATEFROMPARTS(@Year, es.MonthNum, 1)))
THEN DATEFROMPARTS(@Year, es.MonthNum, es.DayNum)
ELSE EOMONTH(DATEFROMPARTS(@Year, es.MonthNum, 1))
END AS BaseDate
FROM ExplicitSchedules es
)
INSERT INTO dbo.JobSchedule (JobName, Frequency, ScheduledRule, ScheduledDate, AdjustedRunDate, MonthOfSchedule, YearOfSchedule, CreatedOn, CreatedBy)
SELECT
esd.JobName,
esd.Frequency,
esd.Pattern,
esd.BaseDate,
CASE
WHEN DATENAME(WEEKDAY, esd.BaseDate) IN ('Saturday','Sunday')
OR EXISTS (SELECT 1 FROM dbo.FederalHolidays WHERE HolidayDate = esd.BaseDate)
THEN dbo.fn_GetPreviousWorkday(esd.BaseDate)
ELSE esd.BaseDate
END AS AdjustedRunDate,
FORMAT(esd.BaseDate, 'yyyy-MM'),
@Year,
GETDATE(),
SYSTEM_USER
FROM ExplicitScheduleDates esd;
-------------------------------------------------------------------------
-- 8. Handle any quarterly jobs that didn't match the patterns above
-------------------------------------------------------------------------
INSERT INTO dbo.JobSchedule (JobName, Frequency, ScheduledRule, ScheduledDate, AdjustedRunDate, MonthOfSchedule, YearOfSchedule, CreatedOn, CreatedBy)
SELECT
jp.JobName,
jp.Frequency,
jp.Pattern,
@FailSafeDate,
@FailSafeDate,
FORMAT(DATEFROMPARTS(@Year, 1, 1), 'yyyy-MM'),
@Year,
GETDATE(),
SYSTEM_USER
FROM #JobProcessing jp
WHERE jp.Frequency = 'QUARTERLY'
AND NOT EXISTS (
SELECT 1 FROM dbo.JobSchedule js
WHERE js.JobName = jp.JobName AND js.YearOfSchedule = @Year
);
-------------------------------------------------------------------------
-- 9. Cleanup and output
-------------------------------------------------------------------------
DROP TABLE #JobProcessing;
-- Update any NULL dates to fail-safe date
UPDATE dbo.JobSchedule
SET ScheduledDate = @FailSafeDate,
AdjustedRunDate = @FailSafeDate
WHERE YearOfSchedule = @Year
AND (ScheduledDate IS NULL OR AdjustedRunDate IS NULL);
DECLARE @RecordCount INT = (SELECT COUNT(*) FROM dbo.JobSchedule WHERE YearOfSchedule = @Year);
PRINT 'Job schedule generation completed for year ' + CAST(@Year AS VARCHAR(4)) +
'. Total records created: ' + CAST(@RecordCount AS VARCHAR(10));
END;
GO

View File

@ -0,0 +1,160 @@
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

View File

@ -0,0 +1,39 @@
USE DevlDUTASJobSchedule;
GO
CREATE OR ALTER PROCEDURE dbo.usp_ScheduleJobsForMonth
AS
BEGIN
SET NOCOUNT ON;
DECLARE @MonthKey CHAR(7) = FORMAT(GETDATE(), 'yyyy-MM');
DECLARE @Year INT = YEAR(GETDATE());
DECLARE @JobName VARCHAR(100);
DECLARE @RunDate DATE;
DECLARE @RunTime TIME;
DECLARE @Env VARCHAR(10) = 'DEVL'; -- configurable per environment
DECLARE job_cursor CURSOR FOR
SELECT js.JobName, js.AdjustedRunDate, jc.ScheduledStartTime
FROM dbo.JobSchedule js
INNER JOIN dbo.JobControl jc ON js.JobName = jc.JobName
WHERE js.MonthOfSchedule = @MonthKey
AND jc.IsActive = 1;
OPEN job_cursor;
FETCH NEXT FROM job_cursor INTO @JobName, @RunDate, @RunTime;
WHILE @@FETCH_STATUS = 0
BEGIN
EXEC msdb.dbo.usp_ScheduleJob
@JobName = @JobName,
@Env = @Env,
@RunDate = @RunDate,
@RunTime = @RunTime;
FETCH NEXT FROM job_cursor INTO @JobName, @RunDate, @RunTime;
END
CLOSE job_cursor;
DEALLOCATE job_cursor;
END