sp_dropdistributiondb (Transact-SQL)
Applies to: SQL Server Azure SQL Managed Instance
Drops a distribution database. Drops the physical files used by the database if they aren't used by another database. This stored procedure is executed at the Distributor on any database.
Transact-SQL syntax conventions
Syntax
sp_dropdistributiondb
[ @database = ] N'database'
[ , [ @former_ag_secondary = ] former_ag_secondary ]
[ ; ]
Arguments
[ @database = ] N'database'
The database to drop. @database is sysname, with no default.
[ @former_ag_secondary = ] former_ag_secondary
Specifies whether this node was previously part of an availability group for the distribution database. @former_ag_secondary is int, with a default of 0
.
Return code values
0
(success) or 1
(failure).
Remarks
sp_dropdistributiondb
is used in all types of replication.
This stored procedure must be executed before dropping the Distributor by executing sp_dropdistributor
.
sp_dropdistributiondb
also removes a Queue Reader Agent job for the distribution database, if one exists.
To disable distribution, the distribution database must be online. If a database snapshot exists for the distribution database, it must be dropped before disabling distribution. A database snapshot is a read-only offline copy of a database, and isn't related to a replication snapshot. For more information, see Database snapshots (SQL Server).
Examples
-- 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".
-- Disable publishing and distribution.
DECLARE @distributionDB AS sysname;
DECLARE @publisher AS sysname;
DECLARE @publicationDB as sysname;
SET @distributionDB = N'distribution';
SET @publisher = $(DistPubServer);
SET @publicationDB = N'AdventureWorks2022';
-- Disable the publication database.
USE [AdventureWorks2022]
EXEC sp_removedbreplication @publicationDB;
-- Remove the registration of the local Publisher at the Distributor.
USE master
EXEC sp_dropdistpublisher @publisher;
-- Delete the distribution database.
EXEC sp_dropdistributiondb @distributionDB;
-- Remove the local server as a Distributor.
EXEC sp_dropdistributor;
GO
Permissions
Only members of the sysadmin fixed server role can execute sp_dropdistributiondb
.