本主题介绍如何使用 SQL Server Management Studio、Transact-SQL 或复制管理对象(RMO)在 SQL Server 2014 中定义文章。
本主题内容
准备工作:
若要定义项目,请使用:
在您开始之前
局限性与限制
- 项目名称不能包含以下任何字符:%、* 、[ 、 [ 、 ] |, : , " , ? , ' , \ , / , < , > 如果数据库中的对象包含这些字符中的任何一个,并且要复制这些字符,则必须指定不同于对象名称的项目名称。
安全
如果可能,请提示用户在运行时输入安全凭据。 如果必须存储凭据,请使用 Microsoft Windows .NET Framework 提供的 加密服务 。
使用 SQL Server Management Studio
使用“新建发布向导”创建出版物并定义文章。 创建发布后,在 “发布属性 - <发布> ”对话框中查看和修改发布属性。 有关从 Oracle 数据库创建发布的信息,请参阅 从 Oracle 数据库创建发布。
创建出版物并定义文章
在 SQL Server Management Studio 中连接到发布服务器,然后展开该服务器节点。
展开 “复制 ”文件夹,然后右键单击 “本地发布 ”文件夹。
单击“ 新建出版物”。
请按照【新建发布向导】中的页面完成以下步骤:
如果未在服务器上配置分发服务器,请指定分发服务器。 有关配置分发的详细信息,请参阅 “配置发布和分发”。
如果在 分发服务器 页面指定发布服务器将充当其自己的分发服务器(本地分发服务器),并且服务器未配置为分发服务器,则新建发布向导将对服务器进行配置。 将在“快照文件夹”页上为分发服务器指定默认 快照文件夹 。 快照文件夹只是你已指定为共享的目录;从此文件夹读取和写入的代理必须具有足够的权限才能访问它。 有关适当保护文件夹的详细信息,请参阅 “保护快照文件夹”。
如果指定另一台服务器应充当分发服务器,则必须在 “管理密码 ”页上输入密码,以便从发布服务器连接到分发服务器的连接。 此密码必须与在远程分发服务器上启用发布服务器时指定的密码匹配。
有关详细信息,请参阅 “配置分发”。
选择出版物数据库。
选择发布类型。 有关详细信息,请参阅 复制类型。
指定要发布的数据和数据库对象;(可选)从表项目筛选列,并设置项目属性。
(可选)从表文章中筛选行。 有关详细信息,请参阅 “筛选已发布数据”。
设置快照代理时间表。
指定以下复制代理运行并建立连接的凭据:
- 所有发布的快照代理。
- 所有事务性发布的日志读取器代理。
- 用于允许更新订阅的事务性发布的队列读取器代理。
(可选)编写发布脚本。 有关详细信息,请参阅 脚本复制。
指定发布的名称。
使用 Transact-SQL
创建出版物后,可以使用与数据库复制相关的存储过程程序化地创建文章。 创建文章的存储过程将依赖于为其定义的出版类型。 有关详细信息,请参阅 “创建发布”。
为快照发布或事务发布定义条目
在发布服务器上,对发布数据库执行 sp_addarticle。 指定文章所属的出版物名称为 @publication,文章名称为 @article,发布的数据库对象为 @source_object,以及任何其他可选参数。 使用 @source_owner 指定对象的架构所有权(如果不是 dbo)。 如果项目不是基于日志的表项目,请为 @type 指定项目类型;有关详细信息,请参阅“指定项目类型”(复制 Transact-SQL 编程)。
若要水平筛选表或查看文章中的行,请使用 sp_articlefilter 来定义筛选器子句。 有关详细信息,请参阅 “定义和修改静态行筛选器”。
若要垂直筛选表或查看项目中的列,请使用 sp_articlecolumn。 有关详细信息,请参阅 “定义和修改列筛选器”。
如果筛选了文章,则执行 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 ,用于筛选表列。 有关详细信息,请参阅 “定义和修改列筛选器”。
示例 (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 = "AdventureWorks2012";
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 = "AdventureWorks2012"
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 = "AdventureWorks2012";
// 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 = "AdventureWorks2012"
' 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
另请参阅
创建出版物
复制系统存储过程概念
向现有出版物添加文章并删除文章
筛选已发布数据
发布数据和数据库对象
复制系统存储过程概念