Files
DUTAS/SQLAgent/01_Devl/3_Stored_Procedures/usp_TriggerMissedJobs.sql
2025-10-20 07:54:46 -04:00

77 lines
4.6 KiB
Transact-SQL
Raw Blame History

This file contains invisible Unicode characters

This file contains invisible Unicode characters that are indistinguishable to humans but may be processed differently by a computer. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

USE [DevlDUTASJobSchedule]
GO
/****** Object: StoredProcedure [dbo].[usp_TriggerMissedJobs] Script Date: 10/4/2025 7:33:54 AM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER PROCEDURE [dbo].[usp_TriggerMissedJobs]
@DryRun BIT = 1 -- Default: preview only (no actual trigger)
AS
BEGIN
SET NOCOUNT ON;
DECLARE @Today DATE = CAST(GETDATE() AS DATE);
-- Collect jobs that should be considered "missed"
;WITH MissedJobs AS (
SELECT
jc.JobName,
jc.ScheduledStartTime,
jeh.Status AS LastStatus
FROM dbo.JobControl jc
LEFT JOIN dbo.JobExecutionHistory jeh
ON jc.JobName = jeh.JobName
AND jeh.RunDate = @Today
WHERE jc.IsActive = 1
AND jc.ScheduledStartTime <= CAST(GETDATE() AS TIME) -- scheduled time passed
AND NOT EXISTS ( -- exclude jobs already successful/overridden
SELECT 1
FROM dbo.JobExecutionHistory jeh2
WHERE jeh2.JobName = jc.JobName
AND jeh2.RunDate = @Today
AND jeh2.Status IN ('Success','ManualOverride')
)
)
SELECT JobName, ScheduledStartTime, LastStatus
INTO #JobsToTrigger
FROM MissedJobs;
-- Show the list (always, even if DryRun=0)
PRINT 'Jobs eligible to be triggered:';
SELECT * FROM #JobsToTrigger ORDER BY ScheduledStartTime;
-- Only trigger if DryRun = 0
IF @DryRun = 0
BEGIN
DECLARE @JobName VARCHAR(50);
DECLARE cur CURSOR LOCAL FAST_FORWARD FOR
SELECT JobName FROM #JobsToTrigger;
OPEN cur;
FETCH NEXT FROM cur INTO @JobName;
WHILE @@FETCH_STATUS = 0
BEGIN
BEGIN TRY
PRINT 'Triggering missed job: ' + @JobName;
EXEC msdb.dbo.sp_start_job @job_name = @JobName;
END TRY
BEGIN CATCH
PRINT 'Failed to trigger job: ' + @JobName + ' - ' + ERROR_MESSAGE();
END CATCH;
FETCH NEXT FROM cur INTO @JobName;
END
CLOSE cur;
DEALLOCATE cur;
END
ELSE
BEGIN
PRINT 'Dry run mode - no jobs were started.';
END
END