xml地图|网站地图|网站标签 [设为首页] [加入收藏]

解决发布订阅中订阅库丢失数据的问题,内附脚

  数据库运维中盛传一个小段子,我误删除了数据库,改怎么办?有备份还原备份,没有备份就准备简历!听起来有趣但发生在谁身上,谁都笑不起来。接触了很多的客户发现90%客户的运维策略都不是很完善。本篇就分享一些常规的运维脚本,本篇没有涉及到的或不足的也请大家留言无私贡献深藏多年的脚本,谢谢!

最近给客户做了基于SQLServer的发布订阅的“读写分离”功能,但是某些表数据很大,经常发生某几条数据丢失的问题,导致订阅无法继续进行。但是每次发现问题重新做一次发布订阅又非常消耗时间,所以还得根据“复制监视器”的提示,找到丢失的数据,手工处理。

邮件

  邮件主要用来监控作业是否运行成功,如果您已经配置了类似zabbix等软件请忽略。

定位缺失数据

首先,找到出问题的同步语句,在发布服务器的“复制监视器”上事务订阅的详细信息里面,找到出错的信息

尝试的命令:
if @@trancount > 0 rollback tran
(事务序列号: 0x0000992600000D09007F00000000,命令 ID: 19)

错误消息:
应用复制的命令时在订阅服务器上找不到该行。 (源: MSSQLServer,错误号: 20598)
获取帮助: http://help/20598
应用复制的命令时在订阅服务器上找不到该行。 (源: MSSQLServer,错误号: 20598)

 

然后在分发服务器上执行下面的SQL语句,

use distribution
go
sp_browsereplcmds '0x0000992600000D09007F00000000' ,'0x0000992600000D09007F00000000'
go

根据命令ID(如上面的ID:19),找到具体的同步命令(Command列),类似于这样的:

{CALL [dbo].[sp_MSdel_dboT_TODO] ('697e7cacf5354a36be1ae4cf50dcdaa6')}

这里是 订阅库上的 sp_MSdel_dboT_TODO 存储过程,查看存储过程定义知道参数是ID的值,这里说找不到要删除的数据,那么我们在订阅库里面模拟增加这个ID的记录即可。添加数据,

配置邮件服务

  

--SQL Server 并没有内置邮件服务器(Mail Server),它跟我们发送邮件一样,需要用户名和密码通过 SMTP(Simple Message Transfer Protocol)去连接邮件服务器。我们想让 SQL Server 来发送邮件,首先要告诉它用户名称,密码,服务器地址,网络传送协议,邮件服务器的端口。。。等信息。
--  以下脚本实现了数据库邮件的配置:
----下面是具体的配置邮件步骤 
----在 sa 系统帐户下运行。 
--
--1. 启用 SQL Server  邮件功能。 
use master
go
exec sp_configure 'show advanced options',1 
go 
reconfigure with override
go
exec sp_configure 'Database Mail XPs',1
go
reconfigure  with override
go
--2. 在 SQL Server  中添加邮件帐户(account) 
exec msdb..sysmail_add_account_sp
        @account_name            = '163yx'      -- 邮件帐户名称(SQL Server 使用)
       ,@email_address           = 'kk_XXXX@163.com'  -- 发件人邮件地址
       ,@display_name            = null                      -- 发件人姓名
       ,@replyto_address         = null
       ,@description             = null
       ,@mailserver_name         = 'smtp.163.com'           -- 邮件服务器地址
       ,@mailserver_type         = 'SMTP'                    -- 邮件协议(SQL 2005 只支持 SMTP)
       ,@port                    = 25                        -- 邮件服务器端口
       ,@username                = 'kk_XXXX@163.com'      -- 用户名
       ,@password                = 'XXXXX'      -- 密码
       ,@use_default_credentials = 0
       ,@enable_ssl              = 0
       ,@account_id              = null

--3. 在 SQL Server  中添加 profile 
exec msdb..sysmail_add_profile_sp @profile_name = 'dba_profile3'      -- profile 名称 
                                 ,@description  = 'dba mail profile' -- profile 描述 
                                 ,@profile_id   = null

-- 在 SQL Server  中映射 account 和 profile 
exec msdb..sysmail_add_profileaccount_sp  @profile_name    = 'dba_profile3' -- profile 名称 
                                         ,@account_name    = '163yx'     -- account 名称 
                                         ,@sequence_number = 1             -- account 在 profile 中顺序 

--5. 利用 SQL Server  Database Mail 功能发送邮件。 
exec msdb..sp_send_dbmail @profile_name =  'dba_profile3'     -- profile 名称 
                         ,@recipients   =  'kk_XXXX@163.com;kk2_XXXX@163.com' -- 收件人邮箱 
                         ,@subject      =  'SQL Server Mail 测试' -- 邮件标题 
                         ,@body         =  'Hello Mail!测试'   -- 邮件内容 
                         ,@body_format  =  'TEXT'      -- 邮件格式 
            ,@file_attachments = 'c:a.txt' --邮件附件


--6. 查看邮件发送情况: 
use msdb
go
select * from sysmail_allitems
select * from sysmail_mailitems
select * from sysmail_event_log 


--如果不是以 sa 帐户发送邮件,则可能会出现错误: 
--
--Msg 229, Level 14, State 5, Procedure sp_send_dbmail, Line 1
--EXECUTE permission denied on object 'sp_send_dbmail', database 'msdb', schema 'dbo'.
--
--这是因为,当前 SQL Server 登陆帐户(login),在 msdb 数据库中没有发送数据库邮件的权限,需要加入 msdb 数据库用户,并通过加入 sp_addrolemember 角色赋予权限。假设该SQL Server 登陆帐户名字为 “dba” 
--
--use msdb
--go
--
--create user dba for login dba
--go
--
--exec dbo.sp_addrolemember @rolename   = 'DatabaseMailUserRole',
--                          @membername = 'dba'
--go
--
--此时,再次发送数据库邮件,仍可能有错误: 
--
--Msg 14607, Level 16, State 1, Procedure sp_send_dbmail, Line 119
--profile name is not valid
--
--虽然,数据库用户 “dba” 已经在 msdb 中拥有发送邮件的权限了,但这还不够,他还需要有使用 profile:“dba_profile” 的权限。 
--
--use msdb
--go
--
--exec sysmail_add_principalprofile_sp  @principal_name = 'dba'
--                                     ,@profile_name   = 'dba_profile'
--                                     ,@is_default     = 1
--
--从上面的参数 @is_default=1 可以看出,一个数据库用户可以在多个 mail profile 拥有发送权限。




--EXEC msdb.dbo.sysmail_configure_sp 'MaxFileSize', 100000000 (字节)设置邮件.note

 

 

补录数据

网上提供的解决方案是用一个工具生成差异的SQL数据然后给订阅库执行,但看了下觉得不是很方便,想起来SqlServer还提供一个 insert...from....语句,那么是否可以直接从发布数据库查询数据然后插入给订阅数据库呢?

可以使用同义词从发布库查询过来插入到本地订阅库,请看下面具体过程:
先在订阅库上建立一个同义词,比如下面为表 Biz_Customer 建立一个同义词 Biz_Customer_Master,建立的时候,要求指定同义词所在的服务器名称,数据库名称,架构,表名称等信息。

必威betway 1

但是此时同义词还不能直接使用,还需要建立“链接服务器”,具体过程如下:

EXEC sp_addlinkedserver
 @server='192.168.7.4',--被访问的服务器别名(习惯上直接使用目标服务器IP,或取个别名如:JOY)
 @srvproduct='',
 @provider='SQLOLEDB',
 @datasrc='192.168.7.4' --要访问的服务器
 go

 EXEC sp_addlinkedsrvlogin
 '192.168.7.4', --被访问的服务器别名(如果上面sp_addlinkedserver中使用别名JOY,则这里也是JOY)
 'false',
 NULL,
 'sa', --帐号
 '1234567890' --密码
go

select * from sys.servers;

然后使用下面的SQL语句插入数据:

insert into [Biz_Customer] 
select * from Biz_Customer_Master where id='7B210173-7382-43EB-BC5E-0000C3BA564A'

查询报错,某个列的数据类型错误,打开表一看,原来是 发布库上的表的字段顺序跟订阅库上不一样,因为当初做订阅的时候,为了解决Timestamp 问题,将订阅库的Timestamp字段修改成了binary(8)类型,故订阅库上表的字段顺序改变了。

此时,只需要在insert 和 select 语句上,指定相同顺序的列就可以了。那么如何获取表所有的列名称?
很简单,直接选择某个表,新建查询,生成的SQL语句就包含表所有的字段了。
最后正确的语句如下:

insert into [TB_Customer]([Id]
      ,[CustomerId]
      ,[Code]
      ,[Name]
      ,[BusinessId]
      ,[CreatedOn]
      ,[CreatedById]
      ,[ModifiedOn]
      ,[ModifiedById]
      ,[AppraiseTableType]
      ,[Timestamp]
      )
SELECT  [Id]
      ,[CustomerId]
      ,[Code]
      ,[Name]
      ,[BusinessId]
      ,[CreatedOn]
      ,[CreatedById]
      ,[ModifiedOn]
      ,[ModifiedById]
      ,[AppraiseTableType]
      ,[Timestamp]
  FROM dbo.TB_Customer_Master 
  where id='7B210173-7382-43EB-BC5E-0000C3BA564A';

经过这样的方式,很方便的把发布库的数据就补充到订阅库上了,之后,数据库的发布订阅错误就解决了。

配置操作员

  操作员主要是用于作业的通知对象:

  必威betway 2

  

  配置如下:

  必威betway 3

  

USE [msdb]
GO
EXEC msdb.dbo.sp_add_operator @name=N'mail_user2', 
        @enabled=1, 
        @pager_days=0, 
        @email_address=N'KK_XXXX.163.COM'
GO

 

 

  注 :操作员可根据是否在作业成功或失败时通知,后续脚本均未配置操作员,如需配置可在作业属性中自行添加 

  必威betway 4

 

修改订阅库存储过程

 但是,如果这样的错误很多,每次都去靠手工修补数据是不行的,所以我们还需要找到订阅库上的系统存储过程,做相应的修改。

  •   修改数据,对应的存储过程名字是 sp_MSupd_dboTableName ,所以我们可以拿到要操作的表名字:dbo.TableName
  •   删除数据,对应的存储过程名字是 sp_MSdel_dboTableName,所以我们可以拿到要操作的表名字:dbo.TableName

如果是删除数据,直接把存储过程中的下面内容注释:

if @@rowcount = 0
    if @@microsoftversion>0x07320000
        exec sp_MSreplraiserror 20598

如果是修改数据,首先也要把上面的内容注释,然后在存储过程的最后,添加下面这样的代码:

if @@rowcount = 0
begin
insert into [TB_Customer]([Id]
      ,[CustomerId]
      ,[Code]
      ,[Name]
      ,[BusinessId]
      ,[CreatedOn]
      ,[CreatedById]
      ,[ModifiedOn]
      ,[ModifiedById]
      ,[AppraiseTableType]
      ,[Timestamp]
      )
SELECT  [Id]
      ,[CustomerId]
      ,[Code]
      ,[Name]
      ,[BusinessId]
      ,[CreatedOn]
      ,[CreatedById]
      ,[ModifiedOn]
      ,[ModifiedById]
      ,[AppraiseTableType]
      ,[Timestamp]
  FROM [192.168.7.4].XXDB.dbo.Biz_Customer
  where id=@pkc1

end

这里没有使用同义词,而是直接使用远程服务器名字加数据库名字方式指定远程表名字,当你要修改的存储过程比较多,推荐采用这种方式而不是同义词。

参数 @pkc1 是存储过程使用的主键参数,每个存储过程都是这样的。

AlwaysOn相关

使用游标生成修改语句

但是,如果要修改从存储过程很多,这样一个个的去手工修改存储过程是非常麻烦的,所以我们可以把上面的过程,写一个T-SQL来输出,我们使用游标来便利表所有的列,生成语句:

declare @ObjTbName varchar(100)
declare @ColName varchar(100)
declare @ColType varchar(50)
declare @AllColName varchar(max)
declare @SqlText varchar(max)

set @ObjTbName='TB_Customer'
set @SqlText ='insert into '+@ObjTbName+'('

DECLARE column_cursor CURSOR FOR
SELECT COLUMN_NAME,DATA_TYPE FROM INFORMATION_SCHEMA.columns WHERE TABLE_NAME=@ObjTbName
OPEN column_cursor
FETCH NEXT FROM column_cursor into @ColName,@ColType
set @AllColName ='['+ @ColName+']'
WHILE @@FETCH_STATUS = 0
BEGIN
   -- This is executed as long as the previous fetch succeeds.
   --print 'Col Name:'+ @ColName +',Col Type:' + @ColType
   FETCH NEXT FROM column_cursor into @ColName,@ColType
   if @@FETCH_STATUS = 0
   --print ' ,'+@ColName
   set @AllColName = @AllColName +',['+ @ColName+']'
END

CLOSE column_cursor
DEALLOCATE column_cursor
--print @AllColName

set @SqlText =@SqlText + char(10)+ @AllColName +')' +CHAR(10)
set @SqlText =@SqlText +'select '+CHAR(10) + @AllColName + CHAR(10)
set @SqlText =@SqlText +' from [192.168.7.4].XXDB.dbo.'+@ObjTbName + ' where id=@pkc1 '

print '--if @@rowcount = 0'
print '--    if @@microsoftversion>0x07320000'
print '--        exec sp_MSreplraiserror 20598'
print 'end '
print 'end '

print 'if @@rowcount = 0'
print 'begin'
print @SqlText
print 'end '

将输消息复制粘贴在要修改的存储过程尾部即可。

修改并执行这个存储过程,等订阅代理重新执行这个存储过程后,数据就过去了。

为了方便这个这个过程被程序调用,可以将它封装成存储过程,具体内容如下:

/*
--创建数据库复制的时候订阅库修改使用的存储过程
--具体原理和使用,请参考博客文章:
--  http://www.cnblogs.com/bluedoctor/p/5680582.html 
--作者:请参考博客文章作者
--时间:2016.7.20

--调用示例:
  exec BuildReplUpdateTable 'MainSqlServer','HRDB','TB_AuditOrgBalance',1
*/
create procedure BuildReplUpdateTable 
   @LinkServer varchar(100),
   @ObjDBName varchar(50),
   @ObjTbName varchar(100),
   @IsSp_MSupd bit
as
begin
    declare @ColName varchar(100)
    declare @ColType varchar(50)
    declare @AllColName varchar(max)
    declare @SqlText varchar(max)
    declare @TempText varchar(max)

    set @SqlText ='insert into '+@ObjTbName+'('

    DECLARE column_cursor CURSOR FOR
    SELECT COLUMN_NAME,DATA_TYPE FROM INFORMATION_SCHEMA.columns WHERE TABLE_NAME=@ObjTbName
    OPEN column_cursor
    FETCH NEXT FROM column_cursor into @ColName,@ColType
    set @AllColName ='['+ @ColName+']'
    WHILE @@FETCH_STATUS = 0
    BEGIN
       --print 'Col Name:'+ @ColName +',Col Type:' + @ColType
       FETCH NEXT FROM column_cursor into @ColName,@ColType
       if @@FETCH_STATUS = 0
           set @AllColName = @AllColName +',['+ @ColName+']'
    END

    CLOSE column_cursor
    DEALLOCATE column_cursor

    set @SqlText =@SqlText + char(10)+ @AllColName +')' +CHAR(10)
    set @SqlText =@SqlText +'select '+CHAR(10) + @AllColName + CHAR(10)
    set @SqlText =@SqlText +' from ['+@LinkServer+'].['+@ObjDBName +'].[dbo].['+@ObjTbName + '] where id=@pkc1 '

    if @IsSp_MSupd = 1 
    begin
      set @TempText='--if @@rowcount = 0'+CHAR(10)+
                    '--    if @@microsoftversion>0x07320000' +CHAR(10)+
                    '--        exec sp_MSreplraiserror 20598'+CHAR(10)+
                    'end '+CHAR(10)+
                    'end '+CHAR(10)+
                    'if @@rowcount = 0'+CHAR(10)+
                    'begin'+CHAR(10)+
                    @SqlText +CHAR(10)+
                    'end '
       select @TempText        
    end
    else
    begin
       select @SqlText
    end

end

 虽然上面封装的存储过程可以很方便的生成修改订阅存储过程的部分修改语句,但是如果系统的表很多,目前还没有做到批量的全部修改这些订阅存储过程,如果有一种方法及时通知DBA 哪些订阅数据出现了问题,然后再按照前面的方法解决问题,就很方便了。这个功能,就是下面说的方法。

节点切换监控

  

    declare @role VARCHAR(8000);    
    declare @email_conetent varchar(8000);--存放邮件正文 
    declare @name varchar(100);
    declare @lastsend int;
declare @subject_str varchar(100);
    set @name =(select @@servername)
set @subject_str = @name + 'always on 预警'
    set @role=(SELECT role FROM sys.dm_hadr_availability_replica_states WHERE is_local=1)
    set @lastsend = (select isnull(datediff(MINUTE,max(send_request_date), getdate()),6000) from [msdb].[dbo].[sysmail_mailitems] where subject = @subject_str)

     if @role >1 and @lastsend > 30  ----30分钟发送一次
        begin 
            set  @email_conetent=(@name+'当前节点不是主节点,发生故障转移')
            print(@email_conetent)
print(@lastsend)
--if @lastsend > 1
            --发送邮件  
                      --邮件正文内容
            EXEC msdb.dbo.sp_send_dbmail 
                @profile_name = 'DB-mail',         --配置文件名称
                @recipients = 'KK_XXX@163.COM',  --收件email地址
                @subject = @subject_str,                 --邮件主题
                @body = @email_conetent    
        end 

 

 

 

SQL邮件监控订阅错误

SQL邮件提供了监视数据库各种性能,问题,警报,然后发邮件通知管理员的功能,我们也可以利用这个功能,当订阅库发生数据同步错误,发一封邮件及时通知管理员,而不用实时去盯着“复制监视器”,查看问题了。

  • 首先在“服务器”-管理-数据库邮件节点上,配置一个数据库邮件账号,具体过程略,请参考其它相关文章;
  • 然后,在Sql Server 代理-操作员功能上,添加一个操作员,填写上通知该操作员的电子邮件账号;
  • 最后,在Sql Server 代理-作业节点,选择用于订阅的作业名称,然后打开属性窗口,进行如下设置:

必威betway 5

如图填写上一个合适的重试次数,默认这是一个很大的数字,所以会重试很久都不会发出问题邮件。该问题我查找了很久才发现,大家不用走弯路了。

经过这样的配置之后,出现订阅同步问题,会收到大概如下的邮件内容:

作业运行:    “DNXSQL-HRDB-XX发布-DNXSQL1-HRDB-3D57B9A6-207B-486A-8B5D-41125B68A876”已在 2016/7/22 14:00:46 运行
持续时间:    0 小时,8 分钟,55 秒
状态: 失败
消息:    该作业失败。  用户 sa 调用了该作业。最后运行的是步骤 1 (运行代理。)。.

收到该邮件后,去服务器按照前面介绍的方法,解决此问题即可。
至此,DBA可以放心去干别的事情了。

(注:本文是一个业余DBA奋战N多天,不断尝试总结,数次修订本文而成,转载请注明作者,并欢迎使用SOD开发框架,它的数据库工具将会提供自动生成修改的订阅存储过程的功能。)

补充:

如果订阅库少了某些记录,可以通过下面类似的查询解决:

update [MainSqlServer].[XXDB].[dbo].TB_Appropriation set ModifiedOn=GETDATE () where ID in 
(
SELECT ID  FROM [MainSqlServer].[XXDB].[dbo].TB_Appropriation where id not in (
  SELECT ID FROM [XXDB].[dbo].TB_Appropriation
)
)

其中,MainSqlServer是发布服务器对应的链接服务器名称,假设要补充缺失数据的表有一个ModifiedOn 字段。

 

节点切换作业控制

  作业可以采用手动控制或如下脚本,也可以修改作业在作业执行前增加节点判断

--------------------------判断当前节点是否为主节点 如果不是则禁用作业 -------
------------节点 切换为主节点则启用JOB ------------
DECLARE @ROLE tinyint 
DECLARE @ENABLE tinyint 
----判断是否是主节点 --1 主节点
 SELECT @role=role FROM sys.dm_hadr_availability_replica_states WHERE is_local=1

--判断JOB状态  --0 禁用 1 启用
--以syspolicy_purge_history 为 参照 --如果 禁用或删除syspolicy_purge_history请修改 @ENABLE下段查询
SELECT @ENABLE  = [ENABLED] 
FROM MSDB.[dbo].[sysjobs] 
WHERE NAME = 'syspolicy_purge_history'


-----第一次切换 辅助节点没有创建CDC作业 job 则创建作业 [category_id] = 13 CDC LOG SCAN JOB
if not exists (select 1 from msdb.dbo.sysjobs where [category_id]= 13 or [category_id]= 16 ) and  @ROLE = 1
begin 
EXEC sys.sp_cdc_add_job @job_type = 'capture';
EXEC sys.sp_cdc_add_job @job_type = 'cleanup';
end

---primary and job disable set job enable
IF @ROLE = 1 and @ENABLE = 0
BEGIN

----如果存在原有作业为禁用,无法确定哪些JOB需要开启....所以此处最好手动维护作业的启用和禁用
EXEC msdb.dbo.sp_update_job
    @job_name = N'XXXXX',
    @enabled = 1 ;


-----执行 CDC 
EXEC msdb.dbo.sp_start_job @job_name = N'cdc.XX_capture'
EXEC msdb.dbo.sp_start_job @job_name = N'cdc.XX_cleanup'
end
---not primary and job enable set  disable
IF @ROLE <> 1 and @ENABLE  = 1
BEGIN
----如果存在原有作业为禁用,无法确定哪些JOB需要开启....所以此处最好手动维护作业的启用和禁用
EXEC msdb.dbo.sp_update_job
    @job_name = N'XXXXX',
    @enabled = 0 ;

END

 

数据备份

  备份方案:每天全备份、6小时一次差异备份、一小时一次日志备份。

备份存储过程

  存储过程创建后会保留在master库中,存储过程主要控制备份逻辑,备份路径等。

  存储过程中只有一个类型参数,用于控制全备/差异/日志备份,可根据需要修改。

USE [master]
GO

/****** Object:  StoredProcedure [dbo].[sp_BackupDatabase]    Script Date: 01/22/2015 13:52:46 ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

-- Author: KK

-- Create date: 2016-09-27

-- Description: 备份数据库,备份路径F:KK_BackUp 可自行修改

-- http://www.cnblogs.com/double-K/

-- Parameter1: 备份类型 F=全部, D=差异, L=日志

alter PROCEDURE [dbo].[sp_BackupDatabase]
@backupType CHAR(1)
AS
BEGIN
SET NOCOUNT ON;



declare @filepath_backup varchar(100)
declare @dateTime varchar(30),@del_time_stamp varchar(50)
DECLARE @sqlCommand NVARCHAR(1000)

---创建数据库对应文件夹
EXECUTE master.dbo.xp_create_subdir N'F:KK_BackUpFull'
EXECUTE master.dbo.xp_create_subdir N'F:KK_BackUpDifference'
EXECUTE master.dbo.xp_create_subdir N'F:KK_BackUpLog_Bak'

IF @backupType = 'F'
set @filepath_backup='F:KK_BackUpFull'
IF @backupType = 'D'
set @filepath_backup='F:KK_BackUpDifference'
IF @backupType = 'L'
set @filepath_backup='F:KK_BackUpLog_Bak'

SET ANSI_WARNINGS OFF
SET @dateTime = replace(convert(varchar,current_timestamp, 112)+'_'+convert(varchar,current_timestamp, 108),':','')

----删除超过3天的备份文件
DECLARE @delete_time datetime
set @delete_time = getdate() - 3

EXECUTE master.dbo.xp_delete_file 0,N'F:kk_backup',N'trn',@delete_time,1
EXECUTE master.dbo.xp_delete_file 0,N'F:kk_backup',N'bak',@delete_time,1

SELECT @dateTime = replace(convert(varchar,current_timestamp, 112)+'_'+convert(varchar,current_timestamp, 108),':','')





declare db_info cursor for    
SELECT NAME,recovery_model FROM MASTER.SYS.databases 
where state = 0 ---只处理online的数据库 
and name not in ('tempdb','ReportServerTempDB','ReportServer')  ----填写不需要备份的数据库


declare @databaseName nvarchar(128) 
declare @recovery_model  int
OPEN db_info    
fetch next from db_info into @databaseName,@recovery_model 
while @@fetch_status=0    
Begin    

---recovery_model 1 : FULL 2 : BULK_LOGGED 3:SIMPLE
---系统数据库只全备

IF @backupType = 'F' 

SET @sqlCommand = 'BACKUP DATABASE '+ @databaseName +' TO DISK = '''+ @filepath_backup + ''+ @databaseName +'_Full_'+@dateTime+'.BAK'' with STATS = 10, INIT, COMPRESSION, CHECKSUM '

IF @backupType = 'D' and @databaseName not in ('master','msdb','model')

SET @sqlCommand = 'BACKUP DATABASE '+ @databaseName +' TO DISK = '''+ @filepath_backup + ''+ @databaseName + '_Diff_' + @dateTime + '.BAK '' WITH DIFFERENTIAL, STATS = 10, INIT, COMPRESSION'

IF @backupType = 'L' and @recovery_model <> 3 and @databaseName not in ('master','msdb','model')
SET @sqlCommand = 'BACKUP LOG '+ @databaseName +' TO DISK = '''+ @filepath_backup + '' + @databaseName +'_Log_' + @dateTime + '.TRN'' with STATS = 10, INIT, COMPRESSION'
print @sqlCommand



EXECUTE sp_executesql @sqlCommand 


fetch next from db_info into @databaseName,@recovery_model 
End    

close db_info    
deallocate db_info    

PRINT '-- Backup completed successfully at '+convert(varchar, getdate(), 120)    

SET ANSI_WARNINGS ON
END
GO

 

备份作业

  备份作业很简单,就是调用存储过程用计划控制备份频率

  

-- Author: KK

-- Create date: 2016-09-27

-- Description: 备份数据库,全备份每天一次 0点执行,差异备份6小时一次,日志备份1小时一次

-- http://www.cnblogs.com/double-K/

--需要备份的数据库未使用参数传递,而是选择在存储过程中指定,当添加新库时不需要修改任何脚本

-- Parameter1: 备份类型 F=全部, D=差异, L=日志


-------------------完整备份作业-----------------
USE [msdb]
GO

/****** Object:  Job [FULL_BACKUP]    Script Date: 2016/9/30 12:13:12 ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object:  JobCategory [[Uncategorized (Local)]]]    Script Date: 2016/9/30 12:13:12 ******/
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'FULL_BACKUP', 
        @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'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object:  Step [FULL_STEP1]    Script Date: 2016/9/30 12:13:12 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'FULL_STEP1', 
        @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'[dbo].[sp_BackupDatabase] ''F''', 
        @database_name=N'master', 
        @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'EVERY_1d_zero', 
        @enabled=1, 
        @freq_type=4, 
        @freq_interval=1, 
        @freq_subday_type=1, 
        @freq_subday_interval=0, 
        @freq_relative_interval=0, 
        @freq_recurrence_factor=0, 
        @active_start_date=20160930, 
        @active_end_date=99991231, 
        @active_start_time=0, 
        @active_end_time=235959, 
        @schedule_uid=N'813653e1-4128-4f47-b378-5a26b49085d0'
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





-------------------日志备份作业------------------
USE [msdb]
GO

/****** Object:  Job [LOG_BACKUP]    Script Date: 2016/9/30 12:13:25 ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object:  JobCategory [[Uncategorized (Local)]]]    Script Date: 2016/9/30 12:13:25 ******/
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'LOG_BACKUP', 
        @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'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object:  Step [LOG_STEP1]    Script Date: 2016/9/30 12:13:25 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'LOG_STEP1', 
        @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'[dbo].[sp_BackupDatabase] ''L''', 
        @database_name=N'master', 
        @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'EVERY_1h', 
        @enabled=1, 
        @freq_type=4, 
        @freq_interval=1, 
        @freq_subday_type=8, 
        @freq_subday_interval=1, 
        @freq_relative_interval=0, 
        @freq_recurrence_factor=0, 
        @active_start_date=20160930, 
        @active_end_date=99991231, 
        @active_start_time=0, 
        @active_end_time=235959, 
        @schedule_uid=N'3d5ad87e-4f1d-46ef-9a24-e0f99c7d5c20'
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



----------------------差异备份作业
USE [msdb]
GO

/****** Object:  Job [DIFF_BACKUP]    Script Date: 2016/9/30 12:13:19 ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object:  JobCategory [[Uncategorized (Local)]]]    Script Date: 2016/9/30 12:13:19 ******/
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'DIFF_BACKUP', 
        @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'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object:  Step [DIFF_STEP1]    Script Date: 2016/9/30 12:13:19 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'DIFF_STEP1', 
        @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'[dbo].[sp_BackupDatabase] ''D''', 
        @database_name=N'master', 
        @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'EXERY_6h', 
        @enabled=1, 
        @freq_type=4, 
        @freq_interval=1, 
        @freq_subday_type=8, 
        @freq_subday_interval=6, 
        @freq_relative_interval=0, 
        @freq_recurrence_factor=0, 
        @active_start_date=20160930, 
        @active_end_date=99991231, 
        @active_start_time=0, 
        @active_end_time=235959, 
        @schedule_uid=N'f7514c1b-128f-4ae4-8361-9dbcbbff66c6'
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

 

数据一致性检查

 

-- Author: KK

-- Create date: 2016-09-27

-- Description: 数据库一致性检查,每周运行及时发现数据库损坏

-- 本脚本针对于中小型数据库,当数据库达到一定规模超过T级或有大表使用计算列等,可适当拆分或调整,以免checkdb时间超过维护时间窗口而影响业务

-- E:checkdb_report.txt ,    输出文件的路径,检查出的错误信息或被记录进去,或直接通过作业记录查看

-- http://www.cnblogs.com/double-K/

--需要备份的数据库未使用参数传递,而是选择在存储过程中指定,当添加新库时不需要修改任何脚本

--脚本针对中小数据库,如果数据库超过1T甚至更大,CHECKDB也是必要操作,但需要拆分文件组或更精细化检查以降低每次检查的时间,保证在指定的维护窗口完成任务。


USE [msdb]
GO

/****** Object:  Job [CHECKDB]    Script Date: 09/30/2016 15:16:01 ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object:  JobCategory [[Uncategorized (Local)]]]    Script Date: 09/30/2016 15:16:01 ******/
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'CHECKDB', 
        @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'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object:  Step [CHECKDB]    Script Date: 09/30/2016 15:16:01 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'CHECKDB', 
        @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'
declare db_info cursor for    
SELECT NAME FROM MASTER.SYS.databases 
where state = 0 ---只处理online的数据库 
and name not in (''tempdb'',''ReportServerTempDB'',''ReportServer'')  ----填写不需要检查的数据库

declare @databaseName nvarchar(128) 
declare @recovery_model  int
DECLARE @sqlCommand NVARCHAR(1000)
OPEN db_info    
fetch next from db_info into @databaseName 
while @@fetch_status=0    
Begin    
SET @sqlCommand = ''DBCC CHECKDB(N''''''+ @databaseName + '''''')  WITH NO_INFOMSGS''
print @sqlCommand

EXECUTE sp_executesql @sqlCommand 
fetch next from db_info into @databaseName 
End    
close db_info    
deallocate db_info    




', 
        @database_name=N'master', 
        @output_file_name=N'E:checkdb_report.txt',    --输出文件的路径,检查出的错误信息或被记录进去,或直接通过作业记录查看
        @flags=4
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'sunday_2am', 
        @enabled=1, 
        @freq_type=8, 
        @freq_interval=1, 
        @freq_subday_type=1, 
        @freq_subday_interval=0, 
        @freq_relative_interval=0, 
        @freq_recurrence_factor=1, 
        @active_start_date=20160930, 
        @active_end_date=99991231, 
        @active_start_time=20000, 
        @active_end_time=235959, 
        @schedule_uid=N'3ade533f-5ce1-434f-98ff-b4509b2ca582'
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

 

Agent作业备份

  备份作业可以通过备份MSDB完成,但是保留一份脚本还是不错的,脚本为存储过程,建议一个周或一个月备份一次,可使用JOB 调用存储过程。

  

USE [master]
GO

/****** Object:  StoredProcedure [dbo].[DumpJobsql]    Script Date: 02/07/2014 11:38:46 ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

alter PROCEDURE [dbo].[usp_DumpJobsql]
AS
BEGIN


-- Author: KK

-- Create date: 2016-09-27

-- Description: 备份JOB,目前不支持邮件

-- 生成数据一份保留在master的zzz_temp_JOB_bcp表中,另外会在目标位置生成一个 job_日期.sql

-- http://www.cnblogs.com/double-K/






    SET NOCOUNT ON
    DECLARE @SV nvarchar(4)
    DECLARE @i_enabled  TINYINT
    DECLARE @sql VARCHAR(max)
    DECLARE @i_job_name                    VARCHAR(1000)
    DECLARE @i_notify_level_eventlog    INT
    DECLARE @i_notify_level_email        INT
    DECLARE @i_notify_level_netsend        INT
    DECLARE @i_notify_level_page        INT
    DECLARE @i_delete_level                INT
    DECLARE @i_description                VARCHAR(1000)
    DECLARE @i_category_name            VARCHAR(1000)
    DECLARE @i_owner_login_name            VARCHAR(1000)
    DECLARE @i_category_class            INT

    DECLARE @i_start_step_id              INT                                
    DECLARE @i_step_name                 VARCHAR(1000)      
    DECLARE @i_step_id                     INT                
    DECLARE @i_cmdexec_success_code        INT             
    DECLARE @i_on_success_action         INT                
    DECLARE @i_on_success_step_id         INT                
    DECLARE @i_on_fail_action             INT                
    DECLARE @i_on_fail_step_id             INT                
    DECLARE @i_retry_attempts             BIGINT            
    DECLARE @i_retry_interval             INT                
    DECLARE @i_os_run_priority            INT                
    DECLARE @i_subsystem                 VARCHAR(1000)      
    DECLARE @i_command                    VARCHAR(8000)
    DECLARE @i_database_name            VARCHAR(100)              
    DECLARE @i_flags                    INT     

    DECLARE @i_class VARCHAR(10) ,@i_type VARCHAR(10)
    DECLARE @c_jobid UNIQUEIDENTIFIER ,@c_categoryid INT

    DECLARE @loop_stepid                INT
    DECLARE @m_stepid                    INT        
    DECLARE @loop_scheduleid            INT
    DECLARE @m_scheduleid                INT

    DECLARE @i_schedule_enabled            TINYINT
    DECLARE @i_freq_type                INT
    DECLARE @i_schedule_name            VARCHAR(1000)    
    DECLARE @i_freq_interval            INT    
    DECLARE @i_freq_subday_type            INT
    DECLARE @i_freq_subday_interval        INT
    DECLARE @i_freq_relative_interval    INT
    DECLARE @i_freq_recurrence_factor    INT
    DECLARE @i_active_start_date        BIGINT    
    DECLARE @i_active_end_date            BIGINT    
    DECLARE @i_active_start_time        BIGINT    
    DECLARE @i_active_end_time            BIGINT    
    DECLARE @i_schedule_uid                VARCHAR(1000)
    SET @i_class    =    'JOB'
    SET @i_type        =    'LOCAL'

       if exists (select 1 from sys.objects where name = 'zzz_temp_JOB_bcp')
       begin 
          delete from master..zzz_temp_JOB_bcp
       end
       else
       begin 
          create table zzz_temp_JOB_bcp(name nvarchar(100),text nvarchar(max),sv nvarchar(4),Bak_date nvarchar(10))
       end

    DECLARE job CURSOR FOR 
        SELECT a.job_id ,a.category_id,'服务器XX' as SV 
        FROM msdb.dbo.sysjobs a , msdb.dbo.syscategories c
        WHERE    a.category_id = c.category_id 
                    AND c.name NOT LIKE '%Database Maintenance%' 
                    AND c.name NOT LIKE '%REPL%'
                    AND c.name <> 'Log Shipping'
                    AND a.name <> 'syspolicy_purge_history'
        ----如果需要可多服务器备份
       --union all
        --select a.job_id ,a.category_id,'服务器XXX' 
        --from 
        --opendatasource('SQLOLEDB','Data Source=XX.XX.XX.XX;User ID=XX;Password=XX').msdb.dbo.sysjobs a,
        --opendatasource('SQLOLEDB','Data Source=XX.XX.XX.XX;User ID=XX;Password=XX').msdb.dbo.syscategories c
        --WHERE    a.category_id = c.category_id 
        --        AND c.name NOT LIKE '%Database Maintenance%' 
        --        AND c.name NOT LIKE '%REPL%'
        --        AND c.name <> 'Log Shipping'
        --        AND a.name <> 'syspolicy_purge_history'

    OPEN job
    FETCH job INTO @c_jobid ,@c_categoryid,@SV
    WHILE @@FETCH_STATUS = 0
    BEGIN
        SET @sql = ''
        SELECT    @i_job_name                 = a.name ,
                @i_enabled             = [enabled] ,
                @i_notify_level_eventlog = notify_level_eventlog ,
                @i_notify_level_email     = notify_level_email ,
                @i_notify_level_netsend     = notify_level_netsend ,
                @i_notify_level_page     = notify_level_page ,
                @i_delete_level             = delete_level ,
                @i_description             = [description] ,
                @i_category_name         = c.name ,
                @i_owner_login_name         =  ISNULL(SUSER_SNAME(a.owner_sid), N'''') ,
                @i_category_class         = category_class 
                FROM msdb.dbo.sysjobs a ,msdb.dbo.syscategories c
                WHERE a.category_id=c.category_id AND a.job_id=@c_jobid AND a.category_id = @c_categoryid

        SET @sql=@sql+CHAR(13)+CHAR(10) + 'USE [msdb]'
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'GO'
        SET @sql=@sql+CHAR(13)+CHAR(10) + '/****** Object:  Job ['+ @i_job_name +']    Script Date: '+CONVERT(VARCHAR,GETDATE(),22)+' ******/' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'BEGIN TRANSACTION' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'DECLARE @ReturnCode INT' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'SELECT @ReturnCode = 0'
        SET @sql=@sql+CHAR(13)+CHAR(10) + '/****** Object:  JobCategory ['+ @i_category_name +']    Script Date: 08/20/2016 12:35:16 ******/'
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'''+ @i_category_name +''' AND category_class='+ CAST(@i_category_class AS VARCHAR) +' )' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'BEGIN' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'''+ @i_class +''', @type=N'''+ @i_type +''', @name=N'''+ @i_category_name +'''' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback'
        SET @sql=@sql+CHAR(13)+CHAR(10) + '' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'END'
        SET @sql=@sql+CHAR(13)+CHAR(10) + ''
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'DECLARE @jobId BINARY(16)' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'EXEC @ReturnCode =  msdb.dbo.sp_add_job @job_name=N'''+ @i_job_name +''','  
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @enabled='+ CAST(@i_enabled AS VARCHAR) +',' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @notify_level_eventlog='+ CAST(@i_notify_level_eventlog AS VARCHAR) +','
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @notify_level_email='+ CAST(@i_notify_level_email AS VARCHAR) +',' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @notify_level_netsend='+ CAST(@i_notify_level_netsend AS VARCHAR) +',' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @notify_level_page='+ CAST(@i_notify_level_page AS VARCHAR) +',' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @delete_level='+ CAST(@i_delete_level AS VARCHAR) +',' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @description=N'''+ @i_description +''',' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @category_name=N'''+ @i_category_name +''',' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '        @owner_login_name=N'''+ @i_owner_login_name +''', @job_id = @jobId OUTPUT' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback' 
        IF EXISTS ( SELECT TOP 1 1 FROM msdb.dbo.sysjobsteps WHERE job_id = @c_jobid )
        BEGIN
            SELECT  @loop_stepid = MIN(step_id) ,@m_stepid = MAX(step_id) FROM msdb.dbo.sysjobsteps WHERE job_id = @c_jobid  
            WHILE (@loop_stepid < = @m_stepid) 
            BEGIN     
                SELECT    @i_start_step_id        = start_step_id,
                        @i_step_name            = step_name ,
                        @i_step_id                = step_id,
                        @i_cmdexec_success_code = cmdexec_success_code ,
                        @i_on_success_action    = on_success_action ,
                        @i_on_success_step_id    = on_success_step_id ,
                        @i_on_fail_action        = on_fail_action ,
                        @i_on_fail_step_id        = on_fail_step_id ,
                        @i_retry_attempts        = retry_attempts ,
                        @i_retry_interval        = retry_interval ,
                        @i_os_run_priority        = os_run_priority ,
                        @i_subsystem            = subsystem ,
                        @i_command                = command ,
                        @i_database_name        = database_name ,
                        @i_flags                = flags
                        FROM msdb.dbo.sysjobs a ,msdb.dbo.sysjobsteps b 
                        WHERE a.job_id = b.job_id AND step_id = @loop_stepid AND a.job_id = @c_jobid 

                SET @sql=@sql+CHAR(13)+CHAR(10) + '/****** Object:  Step ['+ @i_step_name +']    Script Date: '+CONVERT(VARCHAR,GETDATE(),22)+' ******/' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + 'EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'''+ @i_step_name +''','
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @step_id='+ CAST(@i_step_id AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @cmdexec_success_code='+ CAST(@i_cmdexec_success_code AS VARCHAR) +','  
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @on_success_action='+ CAST(@i_on_success_action AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @on_success_step_id='+ CAST(@i_on_success_step_id AS VARCHAR) +','  
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @on_fail_action='+ CAST(@i_on_fail_action AS VARCHAR) +','  
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @on_fail_step_id='+ CAST(@i_on_fail_step_id AS VARCHAR) +','  
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @retry_attempts='+ CAST(@i_retry_attempts AS VARCHAR) +','  
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @retry_interval='+ CAST(@i_retry_interval AS VARCHAR) +','  
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @os_run_priority='+ CAST(@i_os_run_priority AS VARCHAR) +', @subsystem=N'''+ @i_subsystem +''','  
                SET @sql=@sql+CHAR(13)+CHAR(10) + ISNULL('        @command=N''' + REPLACE(@i_command ,'''' ,'''''') + ''',' ,'')  
                SET @sql=@sql+CHAR(13)+CHAR(10) + ISNULL('        @database_name=N'''+ @i_database_name +''',' ,'') 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @flags='+ CAST(@i_flags AS VARCHAR) 
                SET @sql=@sql+CHAR(13)+CHAR(10) + 'IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback' 

                SET @loop_stepid = ( SELECT TOP 1 step_id FROM msdb.dbo.sysjobsteps WHERE job_id = @c_jobid AND step_id > @loop_stepid ORDER BY step_id )
            END
        END

        SET @sql=@sql+CHAR(13)+CHAR(10) + 'EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = '+ CAST(@i_start_step_id AS VARCHAR)  
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback'  
        IF EXISTS ( SELECT TOP 1 1 FROM msdb.dbo.sysschedules c ,msdb.dbo.sysjobschedules d WHERE c.schedule_id = d.schedule_id AND job_id = @c_jobid )
        BEGIN
            SELECT @loop_scheduleid= MIN(c.schedule_id) ,@m_scheduleid = MAX(c.schedule_id) 
                FROM  msdb.dbo.sysschedules c ,msdb.dbo.sysjobschedules d
                WHERE c.schedule_id = d.schedule_id AND job_id = @c_jobid 
            WHILE ( @loop_scheduleid <= @m_scheduleid ) 
            BEGIN
                SELECT    @i_schedule_enabled            = [enabled] ,
                        @i_freq_type                = freq_type ,
                        @i_schedule_name            = name,
                        @i_freq_interval            = freq_interval ,
                        @i_freq_subday_type            = freq_subday_type ,
                        @i_freq_subday_interval        = freq_subday_interval ,
                        @i_freq_relative_interval    = freq_relative_interval ,
                        @i_freq_recurrence_factor    = freq_recurrence_factor ,
                        @i_active_start_date        = active_start_date ,
                        @i_active_end_date            = active_end_date ,
                        @i_active_start_time        = active_start_time ,
                        @i_active_end_time            = active_end_time ,
                        @i_schedule_uid                = schedule_uid 
                        FROM msdb.dbo.sysschedules c LEFT JOIN msdb.dbo.sysjobschedules d
                             ON c.schedule_id = d.schedule_id 
                        WHERE d.job_id = @c_jobid AND c.schedule_id = @loop_scheduleid  

                SET @sql=@sql+CHAR(13)+CHAR(10) + 'EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'''+ @i_schedule_name +''',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @enabled='+ CAST(@i_schedule_enabled AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @freq_type='+ CAST(@i_freq_type AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @freq_interval='+ CAST(@i_freq_interval AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @freq_subday_type='+ CAST(@i_freq_subday_type AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @freq_subday_interval='+ CAST(@i_freq_subday_interval AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @freq_relative_interval='+ CAST(@i_freq_relative_interval AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @freq_recurrence_factor='+ CAST(@i_freq_recurrence_factor AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @active_start_date='+ CAST(@i_active_start_date AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @active_end_date='+ CAST(@i_active_end_date AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @active_start_time='+ CAST(@i_active_start_time AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @active_end_time='+ CAST(@i_active_end_time AS VARCHAR) +',' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + '        @schedule_uid=N'''+ @i_schedule_uid +'''' 
                SET @sql=@sql+CHAR(13)+CHAR(10) + 'IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback' 

                SET @loop_scheduleid = ( SELECT TOP 1 c.schedule_id FROM msdb.dbo.sysschedules c ,msdb.dbo.sysjobschedules d
                                                WHERE c.schedule_id = d.schedule_id AND job_id = @c_jobid AND c.schedule_id > @loop_scheduleid )  
            END
        END

        SET @sql=@sql+CHAR(13)+CHAR(10) + 'EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N''(local)''' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'COMMIT TRANSACTION' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'GOTO EndSave' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'QuitWithRollback:' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '    IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'EndSave:' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + '' 
        SET @sql=@sql+CHAR(13)+CHAR(10) + 'GO'

        PRINT @sql


        insert into master..zzz_temp_JOB_bcp
        SELECT @i_job_name,@sql,@SV,CONVERT(nvarchar(10),getdate(),112)

        FETCH NEXT FROM job INTO @c_jobid ,@c_categoryid ,@SV
    END
    CLOSE job
    DEALLOCATE job



    declare @a nvarchar(17),@c nvarchar(1000),@name nvarchar(100),@d nvarchar(100)
    set @a = CONVERT (nvarchar(17),GETDATE(),112)
    set @name = 'F:kk_backupjob_'+@a+'.sql'
    set @d = 'del ' + @name 
     set @c = 'bcp "select text from master..zzz_temp_JOB_bcp where bak_date = CONVERT(nvarchar(10),getdate(),112)" queryout  "'+ @name +'" -c -S"服务名称" -U"sa" -P"sa123456" '
     print @d
    print @c



    exec sp_configure 'show advanced options',1
    reconfigure with override
    exec sp_configure 'xp_cmdshell',1
    reconfigure with override

     EXEC master..xp_cmdshell @d
     EXEC master..xp_cmdshell @c



    exec sp_configure 'xp_cmdshell',0

    reconfigure with override

    exec sp_configure 'show advanced options',0

    reconfigure with override
    end
GO

 

--------------博客地址---------------------------------------------------------------------------------------

Expert 诊断优化系列 

 

 


 

  总结 : 文章中大部分脚本针对于中小数据库,由于工作性质涉及很多客户部署维护作业,所以力求总结出一套比较完善的脚本,一键部署。

必威betway,     本文脚本目前还不完善,后续会不断补充。另外也请各位看官们贡献下自己深藏的脚本,方便大众,我也取长补短!

     再次感谢!

 ----------------------------------------------------------------------------------------------------

注:此文章为原创,欢迎转载,请在文章页面明显位置给出此文链接!
若您觉得这篇文章还不错请点击下右下角的推荐,非常感谢!

本文由必威发布于数据库,转载请注明出处:解决发布订阅中订阅库丢失数据的问题,内附脚