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