跳到主要內容 跳至補充內容

必要權限

若要使用 Microsoft SQL Server (記錄式) 作為登陸任務中的來源,Microsoft SQL Server (記錄式) 連線屬性中指定的使用者必須是下列身分之一:

  • 同時有 db_owner 資料庫角色和 sysAdmin 固定伺服器角色的成員。
  • db_owner 資料庫角色,但不是 sysAdmin 固定伺服器角色的成員。這也需要您執行以下在獨立環境中設定非系統管理員使用者中描述的程序。

在獨立環境中設定非 sysadmin 使用者

下列區段描述若在 連接器 連線設定中指定了非系統管理員使用者,如何設定 Microsoft SQL Server。

資訊備註

若您想要在 AlwaysOn 環境中設定非系統管理員使用者,請參閱 在處理 AlwaysOn 可用性群組時設定非系統管理員使用者

設定程序

資訊備註

只有在連接器設定如下所示時,才需要執行步驟 16-20:

  • 變更處理模式 (讀取變更來源) 設定為以備份記錄為優先僅備份記錄
  • 替代備份資料夾已設定

若要支援非系統管理員使用者:

  1. 設定 Microsoft SQL Server 以便複寫 中所述設定 Microsoft SQL Server 以便複寫。

  2. 在來源資料庫上啟用 MS-REPLICATION。進行方式可以是手動或使用系統管理員使用者執行任務一次。

    資訊備註

    MS-REPLICATION 發佈程式應設定為本機或以允許透過關聯的連結伺服器存取非系統管理員使用者的方式來設定。

  3. 在主要資料庫中建立結構描述 [attrep]
  4. 在主要資料庫建立資料表值式函數 [attrep].[split_partition_list]

     

    USE [master]
    GO
    
    set ansi_nulls on
    go
    
    set quoted_identifier on
    go
    
    if (object_id('[attrep].[split_partition_list]','TF')) is not null
    drop  function [attrep].[split_partition_list];
    go
    
    create function [attrep].[split_partition_list] 
    ( 
    @plist varchar(8000),	--A delimited list of partitions	
    @dlm nvarchar(1)	--Delimiting character
    ) 
    returns @partitionsTable table --Table holding the BIGINT values of the string fragments
    (
    pid bigint primary key
    ) 
    as 
    begin
    declare @partition_id bigint;
    declare @dlm_pos integer;
    declare @dlm_len integer;
    
    set @dlm_len = len(@dlm);
    
    while (charindex(@dlm,@plist)>0)
    begin 
    set @dlm_pos = charindex(@dlm,@plist);
    set @partition_id = cast( ltrim(rtrim(substring(@plist,1,@dlm_pos-1))) as bigint);
    insert into @partitionsTable (pid) values (@partition_id)
    set @plist = substring(@plist,@dlm_pos+@dlm_len,len(@plist));
    end 
    set @partition_id = cast (ltrim(rtrim(@plist)) as bigint);
    insert into @partitionsTable (pid) values (  @partition_id  );
    return
    end
    GO
  5. 在主要資料庫建立程序 [attrep].[rtm_dump_dblog]

    
    use [MASTER] 
    go 
    
    if (object_id('[attrep].[rtm_dump_dblog]','P')) is not null
    drop procedure [attrep].[rtm_dump_dblog]; 
    go
    
    set ansi_nulls on
    go 
    
    set quoted_identifier on 
    go
    
    create procedure [attrep].[rtm_dump_dblog]
    (
    @start_lsn        varchar(32),
    @seqno            integer,
    @filename         varchar(260),
    @partition_list        varchar(8000), -- A comma delimited list: P1,P2,... Pn
    @programmed_filtering integer,
    @minPartition     bigint,
    @maxPartition     bigint
    ) 
    as begin
    
            declare @start_lsn_cmp varchar(32); -- Stands against the GT comparator
    
            SET NOCOUNT ON  -- Disable "rows affected display"
    
            set @start_lsn_cmp = @start_lsn;
            if (@start_lsn_cmp) is null
                    set @start_lsn_cmp = '00000000:00000000:0000';
    
            if (@partition_list is null)
            begin
                    RAISERROR ('Null partition list waspassed',16,1);
                    return
                    --set @partition_list = '0,';    -- A dummy which is never matched
            end
    
            if (@start_lsn) is not null
                    set @start_lsn = '0x'+@start_lsn;
    
    if (@programmed_filtering=0)
            SELECT
                    [Current LSN],
                    [operation],
                    [Context],
                    [Transaction ID],
                    [Transaction Name],
                    [Begin Time],
                    [End Time],
                    [Flag Bits],
                    [PartitionID],
                    [Page ID],
                    [Slot ID],
                    [RowLog Contents 0],
                    [Log Record],
                    [RowLog Contents 1], -- After Image
    		 [Xact Id] -- Only needed if you are using the AR_H_XACT_ID custom header
            FROM
                    fn_dump_dblog (
                            @start_lsn, NULL, N'DISK', @seqno, @filename,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default)
            where [Current LSN] collate SQL_Latin1_General_CP1_CI_AS > @start_lsn_cmp collate SQL_Latin1_General_CP1_CI_AS -- This aims for implementing FN_DBLOG based on GT comparator.
            and
            (
              (  [operation] in ('LOP_BEGIN_XACT','LOP_COMMIT_XACT','LOP_ABORT_XACT') )
              or
              (  [operation] in ('LOP_INSERT_ROWS','LOP_DELETE_ROWS','LOP_MODIFY_ROW')
                    and
                    ( ( [context]   in ('LCX_HEAP','LCX_CLUSTERED','LCX_MARK_AS_GHOST') ) or ([context] = 'LCX_TEXT_MIX' and  (datalength([RowLog Contents 0]) in (0,14,28))) )   -- This one filters only TEXT_MIX of interest.\
                    and       [PartitionID] in ( select * from master.attrep.split_partition_list (@partition_list,','))
              )
              or
              ([operation] = 'LOP_HOBT_DDL')
            )
    else
            SELECT
                    [Current LSN],
                    [operation],
                    [Context],
                    [Transaction ID],
                    [Transaction Name],
                    [Begin Time],
                    [End Time],
                    [Flag Bits],
                    [PartitionID],
                    [Page ID],
                    [Slot ID],
                    [RowLog Contents 0],
                    [Log Record],
                    [RowLog Contents 1], -- After Image 
    		 [Xact Id] -- Only needed if you are using the AR_H_XACT_ID custom header
    	FROM
                    fn_dump_dblog (
                            @start_lsn, NULL, N'DISK', @seqno, @filename,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default,
                            default, default, default, default, default, default, default)
            where [Current LSN] collate SQL_Latin1_General_CP1_CI_AS > @start_lsn_cmp collate SQL_Latin1_General_CP1_CI_AS -- This aims for implementing FN_DBLOG based on GT comparator.
            and
            (
              (  [operation] in ('LOP_BEGIN_XACT','LOP_COMMIT_XACT','LOP_ABORT_XACT') )
              or
              (  [operation] in ('LOP_INSERT_ROWS','LOP_DELETE_ROWS','LOP_MODIFY_ROW')
                    and
                    ( ( [context]   in ('LCX_HEAP','LCX_CLUSTERED','LCX_MARK_AS_GHOST') ) or ([context] = 'LCX_TEXT_MIX' and  (datalength([RowLog Contents 0]) in (0,14,28))) )   -- This one filters only TEXT_MIX of interest.\
                    and           ([PartitionID] is not null) and ([PartitionID] >= @minPartition and [PartitionID]<=@maxPartition)
              )
              or
              ([operation] = 'LOP_HOBT_DDL')
            )
            SET NOCOUNT OFF -- Re-enable "rows affected display"
    
    end
    GO
  6. 在主要 DB 建立憑證:

     

    Use [master]
    Go
    CREATE CERTIFICATE [attrep_rtm_dump_dblog_cert]
    ENCRYPTION BY PASSWORD = N'choose_your_own_pwd'
    WITH SUBJECT = N'Certificate for FN_DUMP_DBLOG Permissions';
  7. 從憑證建立登入:

     

    Use [master]
    Go
    CREATE LOGIN attrep_rtm_dump_dblog_login FROM CERTIFICATE 
    [attrep_rtm_dump_dblog_cert];
  8. 將登入新增至系統管理員伺服器角色:

    ALTER SERVER ROLE [sysadmin] ADD MEMBER [attrep_rtm_dump_dblog_login];
  9. 將憑證簽章新增至 [master].[attrep].[rtm_dump_dblog]:

     

    Use [master]
    GO
    ADD SIGNATURE
    TO [master].[attrep].[rtm_dump_dblog]
    BY CERTIFICATE [attrep_rtm_dump_dblog_cert]
    WITH PASSWORD = 'choose_your_own_pwd';
    資訊備註

    若重新建立儲存的程序,您需要重新新增簽章。

  10. 在主要資料庫建立程序 [attrep].[rtm_position_1st_timestamp]

     

    use [master]
    if object_id('[attrep].[rtm_position_1st_timestamp]','P') is not null
    DROP PROCEDURE [attrep].[rtm_position_1st_timestamp];
    go
    create procedure [attrep].[rtm_position_1st_timestamp]
    (
    @dbname                sysname,      -- Database name
    @seqno                 integer,      -- Backup set sequence/position number within file
    @filename              varchar(260), -- The backup filename
    @1stTimeStamp          varchar(40)   -- The timestamp to position by
    ) 
    as begin
    
    SET NOCOUNT ON       -- Disable "rows affected display"
    
    declare @firstMatching table
    (
    cLsn varchar(32),
    bTim datetime
    )
    
    declare @sql nvarchar(4000)
    declare @nl                       char(2)
    declare @tb                       char(2)
    declare @fnameVar                 sysname = 'NULL'
    
    set @nl  = char(10); -- New line
    set @tb  = char(9)   -- Tab separator
    
    if (@filename is not null)
    set @fnameVar = ''''+@filename +''''
    
    set @sql='use ['+@dbname+'];'+@nl+
    'select top 1 [Current LSN],[Begin Time]'+@nl+
    'FROM fn_dump_dblog (NULL, NULL, NULL, '+ cast(@seqno as varchar(10))+','+ @fnameVar+','+@nl+
    @tb+'default, default, default, default, default, default, default,'+@nl+
    @tb+'default, default, default, default, default, default, default,'+@nl+
    @tb+'default, default, default, default, default, default, default,'+@nl+
    @tb+'default, default, default, default, default, default, default,'+@nl+
    @tb+'default, default, default, default, default, default, default,'+@nl+
    @tb+'default, default, default, default, default, default, default,'+@nl+
    @tb+'default, default, default, default, default, default, default,'+@nl+
    @tb+'default, default, default, default, default, default, default,'+@nl+
    @tb+'default, default, default, default, default, default, default)'+@nl+
    'where operation=''LOP_BEGIN_XACT''' +@nl+
    'and [Begin Time]>= cast('+''''+@1stTimeStamp+''''+' as datetime)'+@nl
    
    --print @sql
    delete from  @firstMatching 
    insert into @firstMatching  exec sp_executesql @sql    -- Get them all
    
    select top 1 cLsn as [matching LSN],convert(varchar,bTim,121) as [matching Timestamp] from @firstMatching;
    
    SET NOCOUNT OFF      -- Re-enable "rows affected display"
    
    end
    GO
    
  11. 在主要 DB 建立憑證:

     

    Use [master]
    Go
    CREATE CERTIFICATE [attrep_rtm_position_1st_timestamp_cert]
    ENCRYPTION BY PASSWORD = N'choose_your_own_pwd'
    WITH SUBJECT = N'Certificate for FN_POSITION_1st_TIMESTAMP Permissions';
  12. 從憑證建立登入:

     

    Use [master]
    Go
    CREATE LOGIN attrep_rtm_position_1st_timestamp_login FROM CERTIFICATE
    [attrep_rtm_position_1st_timestamp_cert];
  13. 將登入新增至系統管理員伺服器角色:

     

    ALTER SERVER ROLE [sysadmin] ADD MEMBER [attrep_rtm_position_1st_timestamp_login];
  14. 依憑證將簽章新增至 [master].[attrep].[rtm_position_1st_timestamp]

     

    Use [master]
    GO
    ADD SIGNATURE
    TO [master].[attrep].[rtm_position_1st_timestamp]
    BY CERTIFICATE [attrep_rtm_position_1st_timestamp_cert]
    WITH PASSWORD = 'choose_your_own_pwd';
    資訊備註

    若重新建立儲存的程序,您需要重新新增簽章。

  15. 在主要 DB 建立函數 [attrep].[rtm_check_file_exists]

     

    USE [master]

    GO

     

    IF object_id('[attrep].[rtm_check_file_exists]','FN') IS NOT NULL

    DROP FUNCTION [attrep].[rtm_check_file_exists];

    GO

     

    CREATE FUNCTION [attrep].[rtm_check_file_exists]

    (

    @filename varchar(260)

    ) returns int

    as

    begin

    declare @exists int = 0;

    exec master.dbo.xp_fileexist @filename, @exists OUT;

    return @exists;

    end

    GO

  16. 在主要 DB 建立 attrep_rtm_check_file_exists 憑證:

     

    CREATE CERTIFICATE [attrep_rtm_check_file_exists_cert]

    ENCRYPTION BY PASSWORD = N'choose_your_own_pwd'

    WITH SUBJECT = N'Certificate for rtm_check_file_exists Permissions';

     

  17. 從憑證建立 attrep_rtm_check_file_exists_login

     

    CREATE LOGIN attrep_rtm_check_file_exists_login

    FROM CERTIFICATE [attrep_rtm_check_file_exists_cert];

     

  18. 將登入新增至系統管理員伺服器角色:

     

    ALTER SERVER ROLE [sysadmin] ADD MEMBER attrep_rtm_check_file_exists_login;

     

  19. 依憑證將簽章新增至函數 [rtm_check_file_exists]

     

    ADD SIGNATURE TO [master].[attrep].[rtm_check_file_exists]

    BY CERTIFICATE [attrep_rtm_check_file_exists_cert]

    WITH PASSWORD = N'choose_your_own_pwd';

    資訊備註若重新建立儲存的程序,您需要重新新增簽章。
  20. 使用現有登入使用者或建立登入使用者:

     

    CREATE LOGIN [username] WITH PASSWORD='password';

     

  21. 在登入使用者的主要和 MSDB 資料庫建立使用者:

     

    USE master

    GO

    CREATE USER [username] FOR LOGIN [username];

    GO

    USE msdb

    GO

    CREATE USER [username] FOR LOGIN [username];

    GO

     

    對您要以非系統管理員使用者身分存取的每個資料庫重複此步驟。

  22. 向使用者授予下列權限和角色 (在以下每個資料庫):

    • 主要 DB:
      • 在 sys.fn_dblog 選取
      • 檢視任何定義
      • 檢視伺服器狀態 (應向登入授予)。
      • 在 sp_repldone 執行
      • 在 sp_replincrementlsn 執行
      • 在 sp_addpublication 執行
      • 在 sp_addarticle 執行
      • 在 sp_articlefilter 執行
      • 在 [attrep].[split_partition_list] 選取
      • 在 [attrep].[rtm_dump_dblog] 執行
      • 在 [attrep].[rtm_position_1st_timestamp] 執行
      • 在 [attrep].[rtm_check_file_exists] 執行

        資訊備註只有在您執行了以上步驟 16-20 時,才需要此權限。
    • MSDB DB:
      • 在 msdb.dbo.backupset 選取
      • 在 msdb.dbo.backupmediafamily 選取
      • 在 msdb.dbo.backupfile 選取
    • 對於來源資料庫:
      • db_owner 角色
  23. 向非系統管理員授予存取權限,讓端點能夠建立發佈:

    USE master

    EXEC sp_replicationdboption @dbname = '<databaseName>', @optname = 'publish', @value = 'true'

    EXEC <databaseName>.sys.sp_addlogreader_agent

此頁面是否對您有幫助?

若您發現此頁面或其內容有任何問題——錯字、遺漏步驟或技術錯誤——請告知我們可以如何改善!