如何:定義和修改合併發行項之間的聯結篩選 (複寫 Transact-SQL 程式設計)
合併式複寫支援聯結篩選,聯結篩選通常會配合參數化篩選一起使用,以將資料表資料分割擴充到其他相關的資料表發行項。本主題將顯示父發行項上的參數化篩選,其中包含此發行項與相關子發行項之間的聯結篩選。您可以使用複寫預存程序來以程式設計的方式定義及修改聯結篩選。
定義聯結篩選,將發行項擴充到合併式發行集中的相關發行項
針對聯結的發行項定義篩選,此發行項也稱為父發行項。
如需使用參數化資料列篩選器篩選的發行項,請參閱<如何:定義和修改合併發行項的參數化資料列篩選器 (複寫 Transact-SQL 程式設計)>。
如需使用靜態資料列篩選進行篩選的發行項,請參閱<如何:定義及修改靜態資料列篩選 (複寫 Transact-SQL 程式設計)>。
在發行集資料庫的發行者上,執行 sp_addmergearticle (Transact-SQL) 來針對發行集定義一或多個相關發行項,這些發行項也稱為子發行項。如需詳細資訊,請參閱<如何:定義發行項 (複寫 Transact-SQL 程式設計)>。
在發行集資料庫的發行者上,執行 sp_addmergefilter (Transact-SQL)。指定 @publication、針對 @filtername 指定此篩選的唯一名稱、針對 @article 指定步驟 2 中建立的子發行項名稱、針對 @join_articlename 指定聯結的父發行項名稱,以及針對 @join_unique_key 指定下列其中一個值:
0 - 指示父發行項與子發行項之間的多對一或多對多的聯結。
1 - 指示父發行項與子發行項之間的一對一或一對多的聯結。
這樣會定義兩個發行項之間的聯結篩選。
注意 只有當保證唯一性的父發行項之基礎資料表中的聯結資料行上有條件約束時,才能將 @join_unique_key 設為 1。如果將 @join_unique_key 錯誤地設定為 1,可能會發生資料無法聚合。
範例
這個範例會針對合併式發行集定義發行項,其中會針對 SalesOrderHeader 資料表篩選 SalesOrderDetail 資料表發行項 (該資料表本身會使用靜態資料列篩選來進行篩選)。如需詳細資訊,請參閱<如何:定義及修改靜態資料列篩選 (複寫 Transact-SQL 程式設計)>。
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
此範例會在合併式發行集中定義一組發行項,其中的發行項會使用一系列的聯結篩選來針對 Employee 資料表進行篩選 (此資料表本身是使用 LoginID 資料行中 HOST_NAME 值上的參數化資料列篩選器來進行篩選)。如需詳細資訊,請參閱<如何:定義和修改合併發行項的參數化資料列篩選器 (複寫 Transact-SQL 程式設計)>。
-- To avoid storing the login and password in the script file, the value
-- is passed into SQLCMD as a scripting variable. For information about
-- how to use scripting variables on the command line and in SQL Server
-- Management Studio, see the "Executing Replication Scripts" section in
-- the topic "Programming Replication Using System Stored Procedures".
--Add a new merge publication.
DECLARE @publicationdb AS sysname;
DECLARE @publication AS sysname;
DECLARE @table1 AS sysname;
DECLARE @table2 AS sysname;
DECLARE @filter AS sysname;
DECLARE @schema_hr AS sysname;
DECLARE @schema_sales AS sysname;
SET @publicationdb = N'AdventureWorks2008R2';
SET @publication = N'AdvWorksSalesPersonMerge';
SET @table1 = N'Employee';
SET @table2 = N'SalesPerson';
SET @filter = N'SalesPerson_Employee';
SET @schema_hr = N'HumanResources';
SET @schema_sales = N'Sales';
USE [AdventureWorks2008R2];
-- Enable AdventureWorks2008R2 for merge replication.
EXEC sp_replicationdboption
@dbname = @publicationdb,
@optname = N'merge publish',
@value = N'true';
-- Create new merge publication with Subscriber requested snapshot
-- and using the default agent schedule.
EXEC sp_addmergepublication
@publication = @publication,
@description = N'Merge publication of AdventureWorks2008R2.',
@allow_subscriber_initiated_snapshot = N'true',
@publication_compatibility_level = N'90RTM';
-- Create a new snapshot job for the publication, using the default schedule.
-- Pass credentials at runtime using sqlcmd scripting variables.
EXEC sp_addpublication_snapshot
@publication = @publication,
@job_login = $(login),
@job_password = $(password);
-- Add an article for the Employee table,
-- which is horizontally partitioned using
-- a parameterized row filter.
EXEC sp_addmergearticle
@publication = @publication,
@article = @table1,
@source_owner = @schema_hr,
@source_object = @table1,
@type = N'table',
@description = 'contains employee information',
@subset_filterclause = N'[LoginID] = HOST_NAME()';
-- Add an article for the SalesPerson table,
-- which is partitioned based on a join filter.
EXEC sp_addmergearticle
@publication = @publication,
@article = @table2,
@source_owner = @schema_sales,
@source_object = @table2,
@type = N'table',
@description = 'contains salesperson information';
-- Add a join filter between the two articles.
EXEC sp_addmergefilter
@publication = @publication,
@article = @table1,
@filtername = @filter,
@join_articlename = @table2,
@join_filterclause = N'[Employee].[BusinessEntityID] = [SalesPerson].[SalesPersonID]',
@join_unique_key = 1,
@filter_type = 1;
GO
-- Start the agent job to generate the full snapshot for the publication.
-- The filtered data snapshot is generated automatically the first time
-- the subscription is synchronized.
DECLARE @publication AS sysname;
SET @publication = N'AdvWorksSalesPersonMerge';
EXEC sp_startpublication_snapshot
@publication = @publication;
GO