创建一个创建作业的存储过程.
Create procedure CreateJob
@jobname varchar(100),--Job Name
@sql varchar(8000),--Sql,
@freqtype varchar(5),--day week month
@frInterval int=1,--Interval
@SartDateYYYYMMDD nvarchar(8)
AS
declare @dbname sysname
if isnull(@freqtype,'')='' set @freqtype='day'
if isnull(@dbname,'')='' set @dbname=db_name()
--Job
exec msdb..sp_add_job @job_name=@jobname
--Step
exec msdb..sp_add_jobstep @job_name=@jobname,
@step_name = @jobname,
@subsystem = 'TSQL',
@database_name=@dbname,
@command = @sql,
@retry_attempts = 5,
@retry_interval = 5
--Schedule
declare @ftype int,@frfactor int,@fsubtype int,
@fsubinterval int
select @ftype=case @freqtype when 'day' then 4
when 'week' then 8
when 'month' then 16
else 4 --'day'
end
set @frfactor=case @ftype when 4 then 0 else 1 end
set @fsubtype=case @ftype when 4 then 8 else 1 end
set @fsubinterval=case @ftype when 4 then 12 else 0 end --Every 12h execute it
EXEC msdb..sp_add_jobschedule @job_name=@jobname,
@enabled=1,
@name = @jobname,
@freq_type=@ftype , --day:4,week:8,month:16
@freq_interval=@frInterval,
@freq_subday_type=@fsubtype,
@freq_subday_interval=@fsubinterval,
@freq_relative_interval=0,
@freq_recurrence_factor=@frfactor,
@active_start_date=@SartDateYYYYMMDD, --Start Date
@active_end_date=99991231, --No End Date
@active_start_time=080000, --AM 08:00:00
@active_end_time=235959 --PM 23:59:59
--Add to server
EXEC msdb.dbo.sp_add_jobserver
@job_name = @jobname,
@server_name = N'(local)'
GO
Create procedure DeleteJob
@jobname varchar(100)--JobName
as
exec msdb..sp_delete_job @job_name=@jobname
Go
Create Procedure SendMail
@Email nvarchar(100),
@Subject nvarchar(4000),
@BodyHtml nvarchar(4000)
As
set @Email = isnull(@Email,'')
set @Email=replace(SUBSTRING (@Email,0,charindex('/',@Email,0)),' ','_')
if right(@Email,12)<>
set @Email = @Email+'@com'
if (@Email<>'@com')
begin
EXEC msdb..sp_send_dbmail
@profile_name = 'ProfileConfigration',
@recipients = @Email,
@subject = @Subject,
@body = @BodyHtml,
@body_format = 'HTML'
-- EXEC msdb..sp_send_dbmail
-- @profile_name = 'ProfileConfigration',
-- @recipients = @Email,
-- @query = 'SELECT COUNT(*) FROM AdventureWorks.Production.WorkOrder
-- WHERE DueDate > ''2004-04-30''
-- AND DATEDIFF(dd, ''2004-04-30'', DueDate) < 2' ,
-- @subject = @Subject,
-- @attach_query_result_as_file = 1
end
应用场景:
在庞大的数据库中很多复杂的更新查询非常的耗时。为了避免用户长时间的等待,那些耗时的操作可以采用异步执行的方法,立刻返回执行信息给用户,同时在数据库后台执行操作,等到执行完毕再更新数据表。
开发环境:
SQL SERVER2000 .NET
解决方案:
在SQL SERVER2000中创建一个临时的Job,(或者固定的Job,根据具体的应用场景),传递需要执行的SQL batch脚本,然后启动这个Job。这样就可以在数据库获得异步调用的功能了。由于创建的是临时的Job,
SQL SERVER在该Job运行结束以后会自动删除该Job。
缺点:该存储过程必须指定数据库的名字
====================================================================================
/******************************************************************************
* Author: iret
* Desc: Create temporary job to provide asynchronously invoking SQL batch
* 在SQL SERVER 2000中创建用于执行异步调用的临时Job
* @EXECSQL: Transact-SQL batch
* Eample: EXEC dbo.AsynchronousInvoking @EXECSQL = ’UPDTAE customer SET balance = 0’
* 缺点:该存储过程必须指定数据库的名字
* Modified Date: 2004/11/03
******************************************************************************/
CREATE Procedure dbo.AsynchronousInvoking
@EXECSQL nvarchar(4000)
AS
BEGIN TRANSACTION
DECLARE @JobID BINARY(16)
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
BEGIN
-- Add the job
EXECUTE @ReturnCode = msdb.dbo.sp_add_job @job_id = @JobID OUTPUT ,
@job_name = N’temp_sqljob’,
@owner_login_name = N’’,
@description = N’description for job’, -- the description of the job
@category_name = N’[Uncategorized (Local)]’,
@enabled = 1,
@notify_level_email = 0,
@notify_level_page = 0,
@notify_level_netsend = 0,
@notify_level_eventlog = 0,
@delete_level= 3
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
-- Add the job steps
EXECUTE @ReturnCode = msdb.dbo.sp_add_jobstep @job_id = @JobID,
@step_id = 1,
@step_name = N’step1’,
@command = @EXECSQL, -- sql batch
--缺点:该存储过程必须指定数据库的名字
@database_name = N’your_database_name’, --the database name of the job to manipulate
@server = N’’,
@database_user_name = N’appuser’,
@subsystem = N’TSQL’,
@cmdexec_success_code = 0,
@flags = 0,
@retry_attempts = 0, --execute once only
@retry_interval = 0,
@output_file_name = N’’,
@on_success_step_id = 0,
@on_success_action = 1, -- on success abort
@on_fail_step_id = 0,
@on_fail_action = 2 -- on fail abort
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
--set the star step id of the job
EXECUTE @ReturnCode = msdb.dbo.sp_update_job @job_id = @JobID,
@start_step_id = 1
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
-- Add the Target Servers
EXECUTE @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @JobID,
@server_name = N’(local)’
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
END
COMMIT TRANSACTION
GOTO EndSave
QuitWithRollback:
IF (@@TRANCOUNT > 0) BEGIN
ROLLBACK TRANSACTION
RETURN 1
END
EndSave:
--star the job immediately
EXEC @ReturnCode = msdb.dbo.sp_start_job @job_id = @JobID
--return to the invoker immediately
RETURN @ReturnCode
GO
SET QUOTED_IDENTIFIER OFF
GO
SET ANSI_NULLS ON
GO