sp_dropsubscription (Transact-SQL)

Applies to: SQL Server Azure SQL Managed Instance

Drops subscriptions to a particular article, publication, or set of subscriptions on the Publisher. This stored procedure is executed at the Publisher on the publication database.

Transact-SQL syntax conventions

Syntax

  
sp_dropsubscription [ [ @publication= ] 'publication' ]  
    [ , [ @article= ] 'article' ]  
        , [ @subscriber= ] 'subscriber'  
    [ , [ @destination_db= ] 'destination_db' ]  
    [ , [ @ignore_distributor = ] ignore_distributor ]  
    [ , [ @reserved= ] 'reserved' ]  

Arguments

[ @publication = ] 'publication' Is the name of the associated publication. publication is sysname, with a default of NULL. If all, all subscriptions for all publications for the specified Subscriber are canceled. publication is a required parameter.

[ @article = ] 'article' Is the name of the article. article is sysname, with a default value of NULL. If all, subscriptions to all articles for each specified publication and Subscriber are dropped. Use all for publications that allow immediate updating.

[ @subscriber = ] 'subscriber' Is the name of the Subscriber that will have its subscriptions dropped. subscriber is sysname, with no default. If all, all subscriptions for all Subscribers are dropped.

[ @destination_db = ] 'destination_db' Is the name of the destination database. destination_db is sysname, with a default of NULL. If NULL, all the subscriptions from that Subscriber are dropped.

[ @ignore_distributor = ] ignore_distributor

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

[ @reserved = ] 'reserved'

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

Return Code Values

0 (success) or 1 (failure)

Remarks

sp_dropsubscription is used in snapshot and transactional replication.

If you drop the subscription on an article in an immediate-sync publication, you cannot add it back unless you drop the subscriptions on all the articles in the publication and add them all back at once.

Example

-- This script uses sqlcmd scripting variables. They are in the form
-- $(MyVariable). 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".

-- This batch is executed at the Publisher to remove 
-- a pull or push subscription to a transactional publication.
DECLARE @publication AS sysname;
DECLARE @subscriber AS sysname;
SET @publication = N'AdvWorksProductTran';
SET @subscriber = $(SubServer);

USE [AdventureWorks2022]
EXEC sp_dropsubscription 
  @publication = @publication, 
  @article = N'all',
  @subscriber = @subscriber;
GO

Permissions

Only members of the sysadmin fixed server role, the db_owner fixed database role, or the user that created the subscription can execute sp_dropsubscription.

See Also

Delete a Push Subscription
sp_addsubscription (Transact-SQL)
sp_changesubstatus (Transact-SQL)
sp_helpsubscription (Transact-SQL)