Files
DUTAS/SQLAgent/03_Prod/3_Stored_Procedures/usp_CheckJobConditions.sql
2025-10-20 07:54:46 -04:00

124 lines
7.5 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 [ProdDUTASJobSchedule]
GO
/****** Object: StoredProcedure [dbo].[usp_CheckJobConditions] Script Date: 10/4/2025 1:13:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER PROCEDURE [dbo].[usp_CheckJobConditions]
@JobName VARCHAR(50),
@CanRun BIT OUTPUT,
@Message VARCHAR(200) OUTPUT
AS
BEGIN
SET NOCOUNT ON;
DECLARE @CurrentTime TIME = CAST(GETDATE() AS TIME);
DECLARE @Today DATE = CAST(GETDATE() AS DATE);
DECLARE @IsHoliday BIT;
-- Check if today is a Federal Holiday
IF EXISTS (SELECT 1 FROM dbo.FederalHolidays WHERE HolidayDate = @Today)
BEGIN
SET @CanRun = 0;
SET @Message = 'Today is a Federal Holiday';
RETURN;
END
-- Get job details
DECLARE @ScheduledStartTime TIME;
DECLARE @SchedulerAction VARCHAR(10);
SELECT
@ScheduledStartTime = jc.ScheduledStartTime,
@SchedulerAction = jc.SchedulerAction
FROM dbo.JobControl jc
WHERE jc.JobName = @JobName AND jc.IsActive = 1;
IF @ScheduledStartTime IS NULL
BEGIN
SET @CanRun = 0;
SET @Message = 'Job not found or inactive';
RETURN;
END
-- Check scheduled start time
IF @CurrentTime < @ScheduledStartTime
BEGIN
SET @CanRun = 0;
SET @Message = 'Current time is before scheduled start time: ' + CAST(@ScheduledStartTime AS VARCHAR);
RETURN;
END
-- Check all predecessors
DECLARE @PredecessorJobName VARCHAR(50);
DECLARE cur CURSOR LOCAL FAST_FORWARD FOR
SELECT PredecessorJobName
FROM dbo.JobDependencies
WHERE JobName = @JobName
AND PredecessorJobName IS NOT NULL; -- skip NULLs
OPEN cur;
FETCH NEXT FROM cur INTO @PredecessorJobName;
WHILE @@FETCH_STATUS = 0
BEGIN
DECLARE @PredecessorStatus VARCHAR(20);
DECLARE @PredecessorAction VARCHAR(10);
-- Get latest status and scheduler action for the predecessor
SELECT TOP 1
@PredecessorStatus = jeh.Status,
@PredecessorAction = jc.SchedulerAction
FROM dbo.JobExecutionHistory jeh
INNER JOIN dbo.JobControl jc ON jeh.JobName = jc.JobName
WHERE jeh.JobName = @PredecessorJobName
AND jeh.RunDate = @Today
ORDER BY jeh.ExecutionID DESC;
-- Predecessor has not run
IF @PredecessorStatus IS NULL
BEGIN
SET @CanRun = 0;
SET @Message = 'Predecessor job ''' + @PredecessorJobName + ''' has not run today';
CLOSE cur; DEALLOCATE cur;
RETURN;
END
-- Predecessor still running
IF @PredecessorStatus = 'Running'
BEGIN
SET @CanRun = 0;
SET @Message = 'Predecessor job ''' + @PredecessorJobName + ''' is still running';
CLOSE cur; DEALLOCATE cur;
RETURN;
END
-- Predecessor failed with STOP
IF @PredecessorStatus = 'Failed' AND @PredecessorAction = 'STOP'
BEGIN
SET @CanRun = 0;
SET @Message = 'Predecessor job ''' + @PredecessorJobName + ''' failed with STOP action';
CLOSE cur; DEALLOCATE cur;
RETURN;
END
-- Other statuses are OK (Success, ForceComplete, Failed with CONTINUE)
FETCH NEXT FROM cur INTO @PredecessorJobName;
END
CLOSE cur; DEALLOCATE cur;
-- All conditions met
SET @CanRun = 1;
SET @Message = 'All conditions met - job can run';
-- Final safeguard (never return NULL message)
IF @Message IS NULL
BEGIN
SET @CanRun = 0;
SET @Message = 'Unknown failure: conditions check did not complete correctly';
END
END