234 lines
18 KiB
Transact-SQL
234 lines
18 KiB
Transact-SQL
USE [msdb]
|
||
GO
|
||
/****** Object: StoredProcedure [dbo].[usp_CreateSQLAgentJob] Script Date: 10/4/2025 12:22:45 PM ******/
|
||
SET ANSI_NULLS ON
|
||
GO
|
||
SET QUOTED_IDENTIFIER ON
|
||
GO
|
||
|
||
CREATE OR ALTER PROCEDURE [dbo].[usp_CreateSQLAgentJob]
|
||
(
|
||
@JobName VARCHAR(100), -- e.g. 'DEVL_DAILY_DTSBX215'
|
||
@StartTimeHHMMSS INT, -- e.g. 40000 for 04:00:00
|
||
@Env CHAR(4), -- 'DEVL' | 'TEST' | 'PROD'
|
||
@Frequency VARCHAR(20) = 'DAILY'-- descriptive (used for category): DAILY, WEEKLY, etc.
|
||
)
|
||
AS
|
||
BEGIN
|
||
SET NOCOUNT ON;
|
||
|
||
DECLARE
|
||
@ReturnCode INT = 0,
|
||
@jobId UNIQUEIDENTIFIER,
|
||
@categoryName NVARCHAR(128),
|
||
@dbName NVARCHAR(128),
|
||
@scriptPath NVARCHAR(4000),
|
||
@step1Cmd NVARCHAR(MAX),
|
||
@step2Cmd NVARCHAR(MAX),
|
||
@step3Cmd NVARCHAR(MAX),
|
||
@active_start_date INT,
|
||
@SafeJobName SYSNAME,
|
||
@step2Name NVARCHAR(128),
|
||
@step3Name NVARCHAR(128),
|
||
@scheduleName NVARCHAR(128),
|
||
@freq_type INT,
|
||
@freq_interval INT,
|
||
@freq_subday_type INT,
|
||
@freq_subday_interval INT,
|
||
@freq_relative_interval INT,
|
||
@freq_recurrence_factor INT;
|
||
|
||
-- Basic validation
|
||
IF @JobName IS NULL OR LTRIM(RTRIM(@JobName)) = ''
|
||
BEGIN
|
||
RAISERROR('JobName is required.', 16, 1); RETURN;
|
||
END
|
||
IF @Env NOT IN ('DEVL','TEST','PROD')
|
||
BEGIN
|
||
RAISERROR('Env must be one of: DEVL, TEST, PROD.', 16, 1); RETURN;
|
||
END
|
||
IF @StartTimeHHMMSS IS NULL OR @StartTimeHHMMSS < 0
|
||
BEGIN
|
||
RAISERROR('StartTimeHHMMSS is required and must be non-negative integer (e.g. 40000).', 16, 1); RETURN;
|
||
END
|
||
|
||
-- Derived values
|
||
SET @categoryName = @Env + '_' + UPPER(ISNULL(@Frequency,'DAILY'));
|
||
|
||
-- Map environment to the actual DB name (preserve capitalization as per your DBs)
|
||
SET @dbName = CASE @Env
|
||
WHEN 'DEVL' THEN 'DevlDUTASJobSchedule'
|
||
WHEN 'TEST' THEN 'TestDUTASJobSchedule'
|
||
WHEN 'PROD' THEN 'ProdDUTASJobSchedule'
|
||
ELSE 'DevlDUTASJobSchedule'
|
||
END;
|
||
|
||
-- Map environment to script path
|
||
SET @scriptPath = CASE @Env
|
||
WHEN 'DEVL' THEN '\\DOES-RAINVM-DEV\E$\PSScript\Execute-RemoteJob.ps1'
|
||
WHEN 'TEST' THEN '\\DOES-RAINVM-TST\E$\PSScript\Execute-RemoteJob.ps1'
|
||
WHEN 'PROD' THEN '\\DOES-RAINVM-PRD\E$\PSScript\Execute-RemoteJob.ps1'
|
||
ELSE '\\DOES-RAINVM-DEV\E$\PSScript\Execute-RemoteJob.ps1'
|
||
END;
|
||
|
||
-- active_start_date as integer YYYYMMDD
|
||
SET @active_start_date = CONVERT(INT, CONVERT(CHAR(8), GETDATE(), 112));
|
||
|
||
-- Safe job name (escape single quotes)
|
||
SET @SafeJobName = REPLACE(@JobName, '''', '''''');
|
||
|
||
-- Build step names and schedule name into variables (avoids inline expression syntax issues)
|
||
SET @step2Name = N'Run ' + @JobName;
|
||
SET @step3Name = N'Update Execution Status';
|
||
SET @scheduleName = @JobName + N'_Schedule';
|
||
|
||
-- Build commands
|
||
SET @step1Cmd = N'EXEC dbo.usp_CheckJobConditions_Generic ''' + @SafeJobName + N''';';
|
||
|
||
SET @step2Cmd = N'powershell.exe -ExecutionPolicy Bypass -File "' + @scriptPath
|
||
+ N'" -JobName "' + @SafeJobName + N'" -Env "' + @Env + N'"';
|
||
|
||
SET @step3Cmd =
|
||
N'DECLARE @ExitCode INT;
|
||
DECLARE @Today DATE = CAST(GETDATE() AS DATE);
|
||
SELECT TOP 1 @ExitCode = ExitCode
|
||
FROM dbo.JobExitCodes
|
||
WHERE JobName = ''' + @SafeJobName + N''' AND RunDate = @Today
|
||
ORDER BY RecordedTime DESC;
|
||
SET @ExitCode = ISNULL(@ExitCode, 1);
|
||
PRINT ''Using exit code: '' + CAST(@ExitCode AS VARCHAR(10));
|
||
EXEC dbo.usp_UpdateJobStatus_Generic ''' + @SafeJobName + N''', @ExitCode;';
|
||
|
||
-- Set schedule parameters for Monday to Friday (Weekly)
|
||
SET @freq_type = 8; -- Weekly
|
||
SET @freq_interval = 62; -- Monday(2) + Tuesday(4) + Wednesday(8) + Thursday(16) + Friday(32) = 62
|
||
SET @freq_subday_type = 1; -- At the specified time
|
||
SET @freq_subday_interval = 0; -- Run once
|
||
SET @freq_relative_interval = 0; -- Not used for weekly
|
||
SET @freq_recurrence_factor = 1; -- Every 1 week
|
||
|
||
BEGIN TRY
|
||
BEGIN TRANSACTION;
|
||
|
||
-- Ensure category exists
|
||
IF NOT EXISTS (
|
||
SELECT 1 FROM msdb.dbo.syscategories
|
||
WHERE name = @categoryName AND category_class = 1
|
||
)
|
||
BEGIN
|
||
EXEC msdb.dbo.sp_add_category
|
||
@class = N'JOB',
|
||
@type = N'LOCAL',
|
||
@name = @categoryName;
|
||
END
|
||
|
||
-- Create job
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_job
|
||
@job_name = @JobName,
|
||
@enabled = 1,
|
||
@notify_level_eventlog = 2,
|
||
@description = N'Auto-generated DUTAS job.',
|
||
@category_name = @categoryName,
|
||
@owner_login_name = N'DOES\DUTASSQLADMINP',
|
||
@job_id = @jobId OUTPUT;
|
||
IF @ReturnCode <> 0
|
||
BEGIN
|
||
RAISERROR('sp_add_job failed with code %d', 16, 1, @ReturnCode);
|
||
END
|
||
|
||
-- Step 1: Check Conditions (T-SQL)
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep
|
||
@job_id = @jobId,
|
||
@step_name = N'Check Conditions',
|
||
@subsystem = N'TSQL',
|
||
@command = @step1Cmd,
|
||
@database_name = @dbName,
|
||
@on_success_action = 3, -- go to next step
|
||
@on_fail_action = 2; -- quit job reporting failure
|
||
IF @ReturnCode <> 0
|
||
BEGIN
|
||
RAISERROR('sp_add_jobstep (step1) failed with code %d', 16, 1, @ReturnCode);
|
||
END
|
||
|
||
-- Step 2: Run PowerShell (CmdExec)
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep
|
||
@job_id = @JobId,
|
||
@step_name = @step2Name,
|
||
@subsystem = N'CmdExec',
|
||
@command = @step2Cmd,
|
||
@on_success_action = 3, -- proceed to next step
|
||
@on_fail_action = 3; -- proceed to Step 3 (so Step 3 can capture failure)
|
||
IF @ReturnCode <> 0
|
||
BEGIN
|
||
RAISERROR('sp_add_jobstep (step2) failed with code %d', 16, 1, @ReturnCode);
|
||
END
|
||
|
||
-- Step 3: Update Execution Status (T-SQL)
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep
|
||
@job_id = @JobId,
|
||
@step_name = @step3Name,
|
||
@subsystem = N'TSQL',
|
||
@command = @step3Cmd,
|
||
@database_name = @dbName,
|
||
@on_success_action = 1, -- quit with success
|
||
@on_fail_action = 2; -- quit with failure
|
||
IF @ReturnCode <> 0
|
||
BEGIN
|
||
RAISERROR('sp_add_jobstep (step3) failed with code %d', 16, 1, @ReturnCode);
|
||
END
|
||
|
||
-- Set the job to start at step 1
|
||
EXEC @ReturnCode = msdb.dbo.sp_update_job
|
||
@job_id = @JobId,
|
||
@start_step_id = 1;
|
||
IF @ReturnCode <> 0
|
||
BEGIN
|
||
RAISERROR('sp_update_job failed with code %d', 16, 1, @ReturnCode);
|
||
END
|
||
|
||
-- Create a weekly schedule (Monday to Friday)
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule
|
||
@job_id = @JobId,
|
||
@name = @scheduleName,
|
||
@enabled = 1,
|
||
@freq_type = @freq_type, -- 8 = Weekly
|
||
@freq_interval = @freq_interval, -- 62 = Monday(2) + Tuesday(4) + Wednesday(8) + Thursday(16) + Friday(32)
|
||
@freq_subday_type = @freq_subday_type, -- 1 = At specified time
|
||
@freq_subday_interval = @freq_subday_interval, -- 0 = Run once
|
||
@freq_relative_interval = @freq_relative_interval, -- 0 = Not used
|
||
@freq_recurrence_factor = @freq_recurrence_factor, -- 1 = Every 1 week
|
||
@active_start_date = @active_start_date,
|
||
@active_end_date = 99991231,
|
||
@active_start_time = @StartTimeHHMMSS,
|
||
@active_end_time = 235959;
|
||
IF @ReturnCode <> 0
|
||
BEGIN
|
||
RAISERROR('sp_add_jobschedule failed with code %d', 16, 1, @ReturnCode);
|
||
END
|
||
|
||
-- Attach job to local server
|
||
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver
|
||
@job_id = @JobId,
|
||
@server_name = N'(local)';
|
||
IF @ReturnCode <> 0
|
||
BEGIN
|
||
RAISERROR('sp_add_jobserver failed with code %d', 16, 1, @ReturnCode);
|
||
END
|
||
|
||
COMMIT TRANSACTION;
|
||
|
||
PRINT 'Job [' + @JobName + '] created successfully under category [' + @categoryName + '].';
|
||
PRINT 'Schedule: Runs Weekly (Monday to Friday) at ' +
|
||
RIGHT('0' + CAST(@StartTimeHHMMSS/10000 AS VARCHAR(2)), 2) + ':' +
|
||
RIGHT('0' + CAST((@StartTimeHHMMSS%10000)/100 AS VARCHAR(2)), 2);
|
||
END TRY
|
||
BEGIN CATCH
|
||
IF @@TRANCOUNT > 0
|
||
ROLLBACK TRANSACTION;
|
||
|
||
DECLARE @ErrMsg NVARCHAR(4000) = ERROR_MESSAGE();
|
||
DECLARE @ErrNum INT = ERROR_NUMBER();
|
||
RAISERROR('Job creation failed. Msg=%s Num=%d', 16, 1, @ErrMsg, @ErrNum);
|
||
RETURN;
|
||
END CATCH
|
||
END; |