新增 SQL Server Agent Job

  1. 新增每十分鐘排程 執行 SP
  2. 查看排程執行紀錄

新增每十分鐘排程 執行 SP

設定作業名稱

新增步驟

設定排程觸發時間

下圖 為 每10分鐘排程 為範例

設定完成後 取得建立Job的SQL腳本

微調 刪除Job 邏輯 (在不同環境執行時job_id 會不同, 所以需要重新撈取job_id再刪除)

USE [msdb]
GO

-- 刪除Job
/****** Object:  Job [TestJob]    Script Date: 2021/5/14 下午 04:51:13 ******/
DECLARE @job_id uniqueidentifier
SELECT  @job_id = job_id
FROM msdb.dbo.sysjobs_view
where name = N'TestJob'

IF  EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = N'TestJob')
EXEC msdb.dbo.sp_delete_job @job_id=@job_id, @delete_unused_schedule=1
GO

-- 刪除Job

/****** Object:  Job [TestJob]    Script Date: 2022/5/3 下午 04:30:44 ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object:  JobCategory [[Uncategorized (Local)]]    Script Date: 2022/5/3 下午 04:30:44 ******/
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

END

DECLARE @jobId BINARY(16)
EXEC @ReturnCode =  msdb.dbo.sp_add_job @job_name=N'TestJob', 
        @enabled=1, 
        @notify_level_eventlog=0, 
        @notify_level_email=0, 
        @notify_level_netsend=0, 
        @notify_level_page=0, 
        @delete_level=0, 
        @description=N'測試排程', 
        @category_name=N'[Uncategorized (Local)]', 
        @owner_login_name=N'sqlserver', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object:  Step [Job1]    Script Date: 2022/5/3 下午 04:30:44 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Job1', 
        @step_id=1, 
        @cmdexec_success_code=0, 
        @on_success_action=1, 
        @on_success_step_id=0, 
        @on_fail_action=2, 
        @on_fail_step_id=0, 
        @retry_attempts=0, 
        @retry_interval=0, 
        @os_run_priority=0, @subsystem=N'TSQL', 
        @command=N'EXEC Exam.dbo.SP_Query_TestTable @QueryParam = ''1''', 
        @database_name=N'Exam', 
        @flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Testschedule', 
        @enabled=1, 
        @freq_type=4, 
        @freq_interval=1, 
        @freq_subday_type=4, 
        @freq_subday_interval=10, 
        @freq_relative_interval=0, 
        @freq_recurrence_factor=0, 
        @active_start_date=20220503, 
        @active_end_date=99991231, 
        @active_start_time=0, 
        @active_end_time=235959, 
        @schedule_uid=N'56fea05f-1843-4a53-9d31-9afea83bd469'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
COMMIT TRANSACTION
GOTO EndSave
QuitWithRollback:
    IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
EndSave:
GO

查看排程執行紀錄



轉載請註明來源,若有任何錯誤或表達不清楚的地方,歡迎在下方評論區留言,也可以來信至 leozheng0621@gmail.com
如果文章對您有幫助,歡迎斗內(donate),請我喝杯咖啡

斗內💰

×

歡迎斗內

github