如何定义项目(复制 Transact-SQL 编程)

在创建发布后,可以使用复制存储过程以编程方式创建项目。用于创建项目的存储过程取决于要为其定义项目的发布的类型。有关详细信息,请参阅如何创建发布(复制 Transact-SQL 编程)

注意注意

项目名称不能包含以下任何字符:%、*、[、]、|、:、"、?、'、\、/、<、>。如果数据库中的对象包括任意上述字符,并且您希望复制它们,那么必须指定一个不同于相应对象名称的项目名称。

为快照发布或事务发布定义项目

  1. 在发布服务器上,对发布数据库执行 sp_addarticle。将 @publication@article@source_object 的值分别指定为项目所属发布的名称、项目的名称以及要发布的数据库对象,同时指定任何其他可选参数。使用 @source_owner 指定对象的架构所有权(如果不是 dbo)。如果该项目不是基于日志的表项目,可将 @type 指定为该项目类型;有关更多信息,请参阅如何指定项目类型(复制 Transact-SQL 编程)

  2. 若要水平筛选表中的行或查看项目,请使用 sp_articlefilter 来定义筛选子句。有关详细信息,请参阅如何定义和修改静态行筛选器(复制 Transact-SQL 编程)

  3. 若要垂直筛选表中的列或查看项目,请使用 sp_articlecolumn。有关详细信息,请参阅如何定义和修改列筛选器(复制 Transact-SQL 编程)

  4. 如果已经筛选出了项目,请执行 sp_articleview

  5. 如果发布已具有订阅,并且 sp_helppublicationimmediate_sync 列中返回 0 值,必须调用 sp_addsubscription 将项目添加到每个现有订阅。

  6. 如果发布已具有请求订阅,可在发布服务器上执行 sp_refreshsubscriptions 为现有请求订阅创建只包含新项目的新快照。

    注意注意

    对于没有使用快照进行初始化的订阅,不需要执行 sp_refreshsubscriptions,因为该过程由 sp_addarticle 执行。

为合并发布定义项目

  1. 在发布服务器上,对发布数据库执行 sp_addmergearticle。将 @publication@article@source_object 分别指定为发布的名称、项目的名称以及要发布的对象。若要水平筛选表行,请为 @subset_filterclause 指定一个值。有关详细信息,请参阅如何为合并项目定义和修改参数化行筛选器(复制 Transact-SQL 编程)如何定义和修改静态行筛选器(复制 Transact-SQL 编程)。如果相应项目不是表项目,请将 @type 指定为该项目类型。有关详细信息,请参阅如何指定项目类型(复制 Transact-SQL 编程)

  2. (可选)在发布服务器上,对发布数据库执行 sp_addmergefilter 以在两个项目之间定义一个联接筛选器。有关详细信息,请参阅如何定义和修改合并项目之间的联接筛选器(复制 Transact-SQL 编程)

  3. (可选)在发布服务器上的发布数据库中,执行 sp_mergearticlecolumn 可筛选表列。有关详细信息,请参阅如何定义和修改列筛选器(复制 Transact-SQL 编程)

示例

本例为某个事务发布定义了一个基于 Product 表的项目,其中项目在水平和垂直两个方向上进行了筛选。

DECLARE @publication    AS sysname;
DECLARE @table AS sysname;
DECLARE @filterclause AS nvarchar(500);
DECLARE @filtername AS nvarchar(386);
DECLARE @schemaowner AS sysname;
SET @publication = N'AdvWorksProductTran'; 
SET @table = N'Product';
SET @filterclause = N'[DiscontinuedDate] IS NULL'; 
SET @filtername = N'filter_out_discontinued';
SET @schemaowner = N'Production';

-- Add a horizontally and vertically filtered article for the Product table.
-- Manually set @schema_option to ensure that the Production schema 
-- is generated at the Subscriber (0x8000000).
EXEC sp_addarticle 
    @publication = @publication, 
    @article = @table, 
    @source_object = @table,
    @source_owner = @schemaowner, 
    @schema_option = 0x80030F3,
    @vertical_partition = N'true', 
    @type = N'logbased',
    @filter_clause = @filterclause;

-- (Optional) Manually call the stored procedure to create the 
-- horizontal filtering stored procedure. Since the type is 
-- 'logbased', this stored procedures is executed automatically.
EXEC sp_articlefilter 
    @publication = @publication, 
    @article = @table, 
    @filter_clause = @filterclause, 
    @filter_name = @filtername;

-- Add all columns to the article.
EXEC sp_articlecolumn 
    @publication = @publication, 
    @article = @table;

-- Remove the DaysToManufacture column from the article
EXEC sp_articlecolumn 
    @publication = @publication, 
    @article = @table, 
    @column = N'DaysToManufacture', 
    @operation = N'drop';

-- (Optional) Manually call the stored procedure to create the 
-- vertical filtering view. Since the type is 'logbased', 
-- this stored procedures is executed automatically.
EXEC sp_articleview 
    @publication = @publication, 
    @article = @table,
    @filter_clause = @filterclause;
GO

本例为某个合并发布定义项目,其中 SalesOrderHeader 项目基于 SalesPersonID 进行静态筛选,而 SalesOrderDetail 项目则基于 SalesOrderHeader 进行联接筛选。

DECLARE @publication AS sysname;
DECLARE @table1 AS sysname;
DECLARE @table2 AS sysname;
DECLARE @table3 AS sysname;
DECLARE @salesschema AS sysname;
DECLARE @hrschema AS sysname;
DECLARE @filterclause AS nvarchar(1000);
SET @publication = N'AdvWorksSalesOrdersMerge'; 
SET @table1 = N'Employee'; 
SET @table2 = N'SalesOrderHeader'; 
SET @table3 = N'SalesOrderDetail'; 
SET @salesschema = N'Sales';
SET @hrschema = N'HumanResources';
SET @filterclause = N'Employee.LoginID = HOST_NAME()';

-- Add a filtered article for the Employee table.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table1, 
  @source_object = @table1, 
  @type = N'table', 
  @source_owner = @hrschema,
  @schema_option = 0x0004CF1,
  @description = N'article for the Employee table',
  @subset_filterclause = @filterclause;

-- Add an article for the SalesOrderHeader table that is filtered
-- based on Employee and horizontally filtered.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table2, 
  @source_object = @table2, 
  @type = N'table', 
  @source_owner = @salesschema, 
  @vertical_partition = N'true',
  @schema_option = 0x0034EF1,
  @description = N'article for the SalesOrderDetail table';

-- Add an article for the SalesOrderDetail table that is filtered
-- based on SaledOrderHeader.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table3, 
  @source_object = @table3, 
  @source_owner = @salesschema,
  @description = 'article for the SalesOrderHeader table', 
  @identityrangemanagementoption = N'auto', 
  @pub_identity_range = 100000, 
  @identity_range = 100, 
  @threshold = 80,
  @schema_option = 0x0004EF1;

-- Add all columns to the SalesOrderHeader article.
EXEC sp_mergearticlecolumn 
  @publication = @publication, 
  @article = @table2, 
  @force_invalidate_snapshot = 1, 
  @force_reinit_subscription = 1;

-- Remove the credit card Approval Code column.
EXEC sp_mergearticlecolumn 
  @publication = @publication, 
  @article = @table2, 
  @column = N'CreditCardApprovalCode', 
  @operation = N'drop', 
  @force_invalidate_snapshot = 1, 
  @force_reinit_subscription = 1;

-- Add a merge join filter between Employee and SalesOrderHeader.
EXEC sp_addmergefilter 
  @publication = @publication, 
  @article = @table2, 
  @filtername = N'SalesOrderHeader_Employee', 
  @join_articlename = @table1, 
  @join_filterclause = N'Employee.BusinessEntityID = SalesOrderHeader.SalesPersonID', 
  @join_unique_key = 1, 
  @filter_type = 1, 
  @force_invalidate_snapshot = 1, 
  @force_reinit_subscription = 1;

-- Add a merge join filter between SalesOrderHeader and SalesOrderDetail.
EXEC sp_addmergefilter 
  @publication = @publication, 
  @article = @table3, 
  @filtername = N'SalesOrderDetail_SalesOrderHeader', 
  @join_articlename = @table2, 
  @join_filterclause = N'SalesOrderHeader.SalesOrderID = SalesOrderDetail.SalesOrderID', 
  @join_unique_key = 1, 
  @filter_type = 1, 
  @force_invalidate_snapshot = 1, 
  @force_reinit_subscription = 1;
GO