定义项目
适用于:SQL Server
本主题介绍如何通过使用 SQL Server Management Studio、Transact-SQL 或复制管理对象 (RMO) 在 SQL Server 中定义项目。
本主题内容
开始之前:
定义项目,使用:
开始之前
限制和局限
- 项目名称不能包含以下任何字符:%、*、[、]、|、:、"、? 如果数据库中的对象包括任意上述字符,并且您希望复制它们,那么必须指定一个不同于相应对象名称的项目名称。
安全性
如果可能,请在运行时提示用户输入安全凭据。 如果必须存储凭据,请使用 Microsoft Windows .NET Framework 提供的加密服务。
使用 SQL Server Management Studio
可以使用新建发布向导创建发布和定义项目。 创建发布之后,可在“发布属性 - <发布>”对话框中查看和修改发布属性。 有关从 Oracle 数据库创建发布的信息,请参阅从 Oracle 数据库创建发布。
创建发布和定义项目
在 Microsoft SQL Server Management Studio 中连接到发布服务器,然后展开服务器节点。
展开 “复制” 文件夹,再右键单击 “本地发布” 文件夹。
单击 “新建发布”。
按照新建发布向导中的页完成以下任务:
如果尚未在服务器上配置分发,请指定分发服务器。 有关如何配置分发的详细信息,请参阅配置发布和分发。
如果在 “分发服务器” 页上指定将发布服务器用作其自己的分发服务器(本地分发服务器),而未将服务器配置为分发服务器,则新建发布向导将配置该服务器。 在 “快照文件夹” 页中指定分发服务器的快照文件夹。 快照文件夹只是指定共享的目录。向此文件夹中执行读写操作的代理必须对其具有足够的访问权限。 有关正确保护文件夹的详细信息,请参阅保护快照文件夹。
如果指定另一台服务器作为分发服务器,则必须在 “管理密码” 页上输入密码来连接发布服务器和分发服务器。 此密码必须与在远程分发服务器上启用发布服务器时所指定的密码相匹配。
有关详细信息,请参阅 Configure Distribution。
选择发布数据库。
选择发布类型。 有关详细信息,请参阅复制类型。
指定要发布的数据和数据库对象;(可选)筛选来自表项目的列,并设置项目属性。
可选择筛选来自表项目的行。 有关详细信息,请参阅筛选已发布数据。
设置快照代理调度。
指定运行下列复制代理和进行连接的凭证:
- 所有发布的快照代理。
- 所有事务发布的日志读取器代理。
- 用于允许更新订阅的事务发布的队列读取器代理。
有关详细信息,请参阅 Replication Agent Security Model 和 Replication Security Best Practices。
(可选)编写发布脚本。 有关详细信息,请参阅 Scripting Replication。
指定发布的名称。
“使用 Transact-SQL”
在创建发布后,可以使用复制存储过程以编程方式创建项目。 用于创建项目的存储过程取决于要为其定义项目的发布的类型。 有关详细信息,请参阅 Create a Publication。
为快照发布或事务发布定义项目
在发布服务器上,对发布数据库执行 sp_addarticle。 为
@publication
指定项目所属的发布名称,为@article
指定项目的名称,并为@source_object
指定要发布的数据库对象,同时指定任何其他可选参数。 如果不是 dbo,则使用@source_owner
指定对象的架构所有权。 如果该项目不是基于日志的表项目,可将@type
指定为该项目类型;有关详细信息,请参阅指定项目类型(复制 Transact-SQL 编程)。若要水平筛选表中的行或查看项目,请使用 sp_articlefilter 来定义筛选子句。 有关详细信息,请参阅 Define and Modify a Static Row Filter。
若要垂直筛选表中的列或查看项目,请使用 sp_articlecolumn。 有关详细信息,请参阅 Define and Modify a Column Filter。
如果已经筛选出了项目,请执行 sp_articleview 。
如果发布已具有订阅,并且 sp_helppublication 在 immediate_sync 列中返回 0 值,必须调用 sp_addsubscription 将项目添加到每个现有订阅。
如果发布已具有请求订阅,可在发布服务器上执行 sp_refreshsubscriptions 为现有请求订阅创建只包含新项目的新快照。
注意
对于没有使用快照进行初始化的订阅,不需要执行 sp_refreshsubscriptions ,因为该过程由 sp_addarticle执行。
为合并发布定义项目
在发布服务器上,对发布数据库执行 sp_addmergearticle。 为
@publication
指定发布的名称,为@article
指定项目的名称,为@source_object
指定要发布的对象。 若要水平筛选表行,请为@subset_filterclause
指定一个值。 有关详细信息,请参阅 定义和修改合并项目的参数化行筛选器 和 定义和修改静态行筛选器。 如果相应项目不是表项目,请将@type
指定为该项目类型。 有关详细信息,请参阅指定项目类型(复制 Transact-SQL 编程)。(可选)在发布服务器上,对发布数据库执行 sp_addmergefilter 以在两个项目之间定义一个联接筛选器。 有关详细信息,请参阅 定义和修改合并项目间的联接筛选器。
(可选)在发布服务器上的发布数据库中,执行 sp_mergearticlecolumn 可筛选表列。 有关详细信息,请参阅 Define and Modify a Column Filter。
示例 (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
使用复制管理对象 (RMO)
可以使用复制管理对象 (RMO) 以编程方式定义项目。 用来定义项目的 RMO 类取决于要为其定义项目的发布的类型。
示例 (RMO)
下例向一个事务发布添加一个带有行和列筛选器的项目。
// Define the Publisher, publication, and article names.
string publisherName = publisherInstance;
string publicationName = "AdvWorksProductTran";
string publicationDbName = "AdventureWorks2022";
string articleName = "Product";
string schemaOwner = "Production";
TransArticle article;
// Create a connection to the Publisher.
ServerConnection conn = new ServerConnection(publisherName);
// Create a filtered transactional articles in the following steps:
// 1) Create the article with a horizontal filter clause.
// 2) Add columns to or remove columns from the article.
try
{
// Connect to the Publisher.
conn.Connect();
// Define a horizontally filtered, log-based table article.
article = new TransArticle();
article.ConnectionContext = conn;
article.Name = articleName;
article.DatabaseName = publicationDbName;
article.SourceObjectName = articleName;
article.SourceObjectOwner = schemaOwner;
article.PublicationName = publicationName;
article.Type = ArticleOptions.LogBased;
article.FilterClause = "DiscontinuedDate IS NULL";
// Ensure that we create the schema owner at the Subscriber.
article.SchemaOption |= CreationScriptOptions.Schema;
if (!article.IsExistingObject)
{
// Create the article.
article.Create();
}
else
{
throw new ApplicationException(String.Format(
"The article {0} already exists in publication {1}.",
articleName, publicationName));
}
// Create an array of column names to remove from the article.
String[] columns = new String[1];
columns[0] = "DaysToManufacture";
// Remove the column from the article.
article.RemoveReplicatedColumns(columns);
}
catch (Exception ex)
{
// Implement appropriate error handling here.
throw new ApplicationException("The article could not be created.", ex);
}
finally
{
conn.Disconnect();
}
' Define the Publisher, publication, and article names.
Dim publisherName As String = publisherInstance
Dim publicationName As String = "AdvWorksProductTran"
Dim publicationDbName As String = "AdventureWorks2022"
Dim articleName As String = "Product"
Dim schemaOwner As String = "Production"
Dim article As TransArticle
' Create a connection to the Publisher.
Dim conn As ServerConnection = New ServerConnection(publisherName)
' Create a filtered transactional articles in the following steps:
' 1) Create the article with a horizontal filter clause.
' 2) Add columns to or remove columns from the article.
Try
' Connect to the Publisher.
conn.Connect()
' Define a horizontally filtered, log-based table article.
article = New TransArticle()
article.ConnectionContext = conn
article.Name = articleName
article.DatabaseName = publicationDbName
article.SourceObjectName = articleName
article.SourceObjectOwner = schemaOwner
article.PublicationName = publicationName
article.Type = ArticleOptions.LogBased
article.FilterClause = "DiscontinuedDate IS NULL"
' Ensure that we create the schema owner at the Subscriber.
article.SchemaOption = article.SchemaOption Or _
CreationScriptOptions.Schema
If Not article.IsExistingObject Then
' Create the article.
article.Create()
Else
Throw New ApplicationException(String.Format( _
"The article {0} already exists in publication {1}.", _
articleName, publicationName))
End If
' Create an array of column names to remove from the article.
Dim columns() As String = New String(0) {}
columns(0) = "DaysToManufacture"
' Remove the column from the article.
article.RemoveReplicatedColumns(columns)
Catch ex As Exception
' Implement appropriate error handling here.
Throw New ApplicationException("The article could not be created.", ex)
Finally
conn.Disconnect()
End Try
下例将三个项目添加到一个合并发布。 这些项目具有列筛选器,而且使用两个联接筛选器来将一个参数化行筛选器传播给其他项目。
// Define the Publisher and publication names.
string publisherName = publisherInstance;
string publicationName = "AdvWorksSalesOrdersMerge";
string publicationDbName = "AdventureWorks2022";
// Specify article names.
string articleName1 = "Employee";
string articleName2 = "SalesOrderHeader";
string articleName3 = "SalesOrderDetail";
// Specify join filter information.
string filterName12 = "SalesOrderHeader_Employee";
string filterClause12 = "Employee.EmployeeID = " +
"SalesOrderHeader.SalesPersonID";
string filterName23 = "SalesOrderDetail_SalesOrderHeader";
string filterClause23 = "SalesOrderHeader.SalesOrderID = " +
"SalesOrderDetail.SalesOrderID";
string salesSchema = "Sales";
string hrSchema = "HumanResources";
MergeArticle article1 = new MergeArticle();
MergeArticle article2 = new MergeArticle();
MergeArticle article3 = new MergeArticle();
MergeJoinFilter filter12 = new MergeJoinFilter();
MergeJoinFilter filter23 = new MergeJoinFilter();
// Create a connection to the Publisher.
ServerConnection conn = new ServerConnection(publisherName);
// Create three merge articles that are horizontally partitioned
// using a parameterized row filter on Employee.EmployeeID, which is
// extended to the two other articles using join filters.
try
{
// Connect to the Publisher.
conn.Connect();
// Create each article.
// For clarity, each article is defined separately.
// In practice, iterative structures and arrays should
// be used to efficiently create multiple articles.
// Set the required properties for the Employee article.
article1.ConnectionContext = conn;
article1.Name = articleName1;
article1.DatabaseName = publicationDbName;
article1.SourceObjectName = articleName1;
article1.SourceObjectOwner = hrSchema;
article1.PublicationName = publicationName;
article1.Type = ArticleOptions.TableBased;
// Define the parameterized filter clause based on Hostname.
article1.FilterClause = "Employee.LoginID = HOST_NAME()";
// Set the required properties for the SalesOrderHeader article.
article2.ConnectionContext = conn;
article2.Name = articleName2;
article2.DatabaseName = publicationDbName;
article2.SourceObjectName = articleName2;
article2.SourceObjectOwner = salesSchema;
article2.PublicationName = publicationName;
article2.Type = ArticleOptions.TableBased;
// Set the required properties for the SalesOrderDetail article.
article3.ConnectionContext = conn;
article3.Name = articleName3;
article3.DatabaseName = publicationDbName;
article3.SourceObjectName = articleName3;
article3.SourceObjectOwner = salesSchema;
article3.PublicationName = publicationName;
article3.Type = ArticleOptions.TableBased;
if (!article1.IsExistingObject) article1.Create();
if (!article2.IsExistingObject) article2.Create();
if (!article3.IsExistingObject) article3.Create();
// Select published columns for SalesOrderHeader.
// Create an array of column names to vertically filter out.
// In this example, only one column is removed.
String[] columns = new String[1];
columns[0] = "CreditCardApprovalCode";
// Remove the column.
article2.RemoveReplicatedColumns(columns);
// Define a merge filter clauses that filter
// SalesOrderHeader based on Employee and
// SalesOrderDetail based on SalesOrderHeader.
// Parent article.
filter12.JoinArticleName = articleName1;
// Child article.
filter12.ArticleName = articleName2;
filter12.FilterName = filterName12;
filter12.JoinUniqueKey = true;
filter12.FilterTypes = FilterTypes.JoinFilter;
filter12.JoinFilterClause = filterClause12;
// Add the join filter to the child article.
article2.AddMergeJoinFilter(filter12);
// Parent article.
filter23.JoinArticleName = articleName2;
// Child article.
filter23.ArticleName = articleName3;
filter23.FilterName = filterName23;
filter23.JoinUniqueKey = true;
filter23.FilterTypes = FilterTypes.JoinFilter;
filter23.JoinFilterClause = filterClause23;
// Add the join filter to the child article.
article3.AddMergeJoinFilter(filter23);
}
catch (Exception ex)
{
// Do error handling here and rollback the transaction.
throw new ApplicationException(
"The filtered articles could not be created", ex);
}
finally
{
conn.Disconnect();
}
' Define the Publisher and publication names.
Dim publisherName As String = publisherInstance
Dim publicationName As String = "AdvWorksSalesOrdersMerge"
Dim publicationDbName As String = "AdventureWorks2022"
' Specify article names.
Dim articleName1 As String = "Employee"
Dim articleName2 As String = "SalesOrderHeader"
Dim articleName3 As String = "SalesOrderDetail"
' Specify join filter information.
Dim filterName12 As String = "SalesOrderHeader_Employee"
Dim filterClause12 As String = "Employee.EmployeeID = " + _
"SalesOrderHeader.SalesPersonID"
Dim filterName23 As String = "SalesOrderDetail_SalesOrderHeader"
Dim filterClause23 As String = "SalesOrderHeader.SalesOrderID = " + _
"SalesOrderDetail.SalesOrderID"
Dim salesSchema As String = "Sales"
Dim hrSchema As String = "HumanResources"
Dim article1 As MergeArticle = New MergeArticle()
Dim article2 As MergeArticle = New MergeArticle()
Dim article3 As MergeArticle = New MergeArticle()
Dim filter12 As MergeJoinFilter = New MergeJoinFilter()
Dim filter23 As MergeJoinFilter = New MergeJoinFilter()
' Create a connection to the Publisher.
Dim conn As ServerConnection = New ServerConnection(publisherName)
' Create three merge articles that are horizontally partitioned
' using a parameterized row filter on Employee.EmployeeID, which is
' extended to the two other articles using join filters.
Try
' Connect to the Publisher.
conn.Connect()
' Create each article.
' For clarity, each article is defined separately.
' In practice, iterative structures and arrays should
' be used to efficiently create multiple articles.
' Set the required properties for the Employee article.
article1.ConnectionContext = conn
article1.Name = articleName1
article1.DatabaseName = publicationDbName
article1.SourceObjectName = articleName1
article1.SourceObjectOwner = hrSchema
article1.PublicationName = publicationName
article1.Type = ArticleOptions.TableBased
' Define the parameterized filter clause based on Hostname.
article1.FilterClause = "Employee.LoginID = HOST_NAME()"
' Set the required properties for the SalesOrderHeader article.
article2.ConnectionContext = conn
article2.Name = articleName2
article2.DatabaseName = publicationDbName
article2.SourceObjectName = articleName2
article2.SourceObjectOwner = salesSchema
article2.PublicationName = publicationName
article2.Type = ArticleOptions.TableBased
' Set the required properties for the SalesOrderDetail article.
article3.ConnectionContext = conn
article3.Name = articleName3
article3.DatabaseName = publicationDbName
article3.SourceObjectName = articleName3
article3.SourceObjectOwner = salesSchema
article3.PublicationName = publicationName
article3.Type = ArticleOptions.TableBased
' Create the articles, if they do not already exist.
If article1.IsExistingObject = False Then
article1.Create()
End If
If article2.IsExistingObject = False Then
article2.Create()
End If
If article3.IsExistingObject = False Then
article3.Create()
End If
' Select published columns for SalesOrderHeader.
' Create an array of column names to vertically filter out.
' In this example, only one column is removed.
Dim columns() As String = New String(0) {}
columns(0) = "CreditCardApprovalCode"
' Remove the column.
article2.RemoveReplicatedColumns(columns)
' Define a merge filter clauses that filter
' SalesOrderHeader based on Employee and
' SalesOrderDetail based on SalesOrderHeader.
' Parent article.
filter12.JoinArticleName = articleName1
' Child article.
filter12.ArticleName = articleName2
filter12.FilterName = filterName12
filter12.JoinUniqueKey = True
filter12.FilterTypes = FilterTypes.JoinFilter
filter12.JoinFilterClause = filterClause12
' Add the join filter to the child article.
article2.AddMergeJoinFilter(filter12)
' Parent article.
filter23.JoinArticleName = articleName2
' Child article.
filter23.ArticleName = articleName3
filter23.FilterName = filterName23
filter23.JoinUniqueKey = True
filter23.FilterTypes = FilterTypes.JoinFilter
filter23.JoinFilterClause = filterClause23
' Add the join filter to the child article.
article3.AddMergeJoinFilter(filter23)
Catch ex As Exception
' Do error handling here and rollback the transaction.
Throw New ApplicationException( _
"The filtered articles could not be created", ex)
Finally
conn.Disconnect()
End Try