Delete an Article
This topic describes how to delete an article in SQL Server 2012 by using Transact-SQL or Replication Management Objects (RMO). For information about the conditions under which articles can be dropped and whether dropping an article requires a new snapshot or the reinitialization of subscriptions, see Add Articles to and Drop Articles from Existing Publications.
In This Topic
To delete an article, using:
Transact-SQL
Replication Management Objects (RMO)
Using Transact-SQL
Articles can be deleted programmatically using replication stored procedures. The stored procedures that you use depend on the type of publication to which the article belongs.
To delete an article from a snapshot or transactional publication
Execute sp_droparticle (Transact-SQL) to delete an article, specified by @article, from a publication, specified by @publication. Specify a value of 1 for @force_invalidate_snapshot.
(Optional) To remove the published object from the database entirely, execute the DROP <objectname> command at the Publisher on the publication database.
To delete an article from a merge publication
Execute sp_dropmergearticle (Transact-SQL) to delete an article, specified by @article, from a publication, specified by @publication. If necessary, specify a value of 1 for @force_invalidate_snapshot and a value of 1 for @force_reinit_subscription.
(Optional) To remove the published object from the database entirely, execute the DROP <objectname> command at the Publisher on the publication database.
Examples (Transact-SQL)
The following example deletes an article from a transactional publication. Because this change invalidates the existing snapshot, a value of 1 is specified for the @force_invalidate_snapshot parameter.
DECLARE @publication AS sysname;
DECLARE @article AS sysname;
SET @publication = N'AdvWorksProductTran';
SET @article = N'Product';
-- Drop the transactional article.
USE [AdventureWorks2012]
EXEC sp_droparticle
@publication = @publication,
@article = @article,
@force_invalidate_snapshot = 1;
GO
The following example deletes two articles from a merge publication. Because these changes invalidate the existing snapshot, a value of 1 is specified for the @force_invalidate_snapshot parameter.
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()';
-- Drop the merge join filter between SalesOrderHeader and SalesOrderDetail.
EXEC sp_dropmergefilter
@publication = @publication,
@article = @table3,
@filtername = N'SalesOrderDetail_SalesOrderHeader',
@force_invalidate_snapshot = 1,
@force_reinit_subscription = 1;
-- Drops the merge join filter between Employee and SalesOrderHeader.
EXEC sp_dropmergefilter
@publication = @publication,
@article = @table2,
@filtername = N'SalesOrderHeader_Employee',
@force_invalidate_snapshot = 1,
@force_reinit_subscription = 1;
-- Drops the article for the SalesOrderDetail table.
EXEC sp_dropmergearticle
@publication = @publication,
@article = @table3,
@force_invalidate_snapshot = 1,
@force_reinit_subscription = 1;
-- Drops the article for the SalesOrderHeader table.
EXEC sp_dropmergearticle
@publication = @publication,
@article = @table2,
@force_invalidate_snapshot = 1,
@force_reinit_subscription = 1;
-- Drops the article for the Employee table.
EXEC sp_dropmergearticle
@publication = @publication,
@article = @table1,
@force_invalidate_snapshot = 1,
@force_reinit_subscription = 1;
GO
DECLARE @publication AS sysname;
DECLARE @article1 AS sysname;
DECLARE @article2 AS sysname;
SET @publication = N'AdvWorksSalesOrdersMerge';
SET @article1 = N'SalesOrderDetail';
SET @article2 = N'SalesOrderHeader';
-- Remove articles from a merge publication.
USE [AdventureWorks]
EXEC sp_dropmergearticle
@publication = @publication,
@article = @article1,
@force_invalidate_snapshot = 1;
EXEC sp_dropmergearticle
@publication = @publication,
@article = @article2,
@force_invalidate_snapshot = 1;
GO
[Top]
Using Replication Management Objects (RMO)
You can delete articles programmatically by using Replication Management Objects (RMO). The RMO classes you use to delete an article depend on the type of publication to which the article belongs.
To delete an article that belongs to a snapshot or transactional publication
Create a connection to the Publisher by using the ServerConnection class.
Create an instance of the TransArticle class.
Set the Name, PublicationName, and DatabaseName properties.
Set the connection from step 1 for the ConnectionContext property.
Check the IsExistingObject property to verify that the article exists. If the value of this property is false, either the article properties in step 3 were defined incorrectly or the article does not exist.
Call the Remove method.
Close all connections.
To delete an article that belongs to a merge publication
Create a connection to the Publisher by using the ServerConnection class.
Create an instance of the MergeArticle class.
Set the Name, PublicationName, and DatabaseName properties.
Set the connection from step 1 for the ConnectionContext property.
Check the IsExistingObject property to verify that the article exists. If the value of this property is false, either the article properties in step 3 were defined incorrectly or the article does not exist.
Call the Remove method.
Close all connections.
[Top]
See Also
Concepts
Add Articles to and Drop Articles from Existing Publications