Bewerken

Delen via


Configure Publishing and Distribution

Applies to: SQL Server Azure SQL Managed Instance

This topic describes how to configure publishing and distribution in SQL Server by using SQL Server Management Studio, Transact-SQL, or Replication Management Objects (RMO).

Before You Begin

Security

For more information, see View and modify replication security settings.

Using SQL Server Management Studio

Configure distribution using the New Publication Wizard or the Configure Distribution Wizard. After the Distributor is configured, view and modify properties in the Distributor Properties - <Distributor> dialog box. Use the Configure Distribution Wizard if you want to configure a Distributor so that members of the db_owner fixed database roles can create publications, or because you want to configure a remote Distributor that is not a Publisher.

To configure distribution

  1. In Microsoft SQL Server Management Studio, connect to the server that will be the Distributor (in many cases, the Publisher and Distributor are the same server), and then expand the server node.

  2. Right-click the Replication folder, and then click Configure Distribution.

  3. Follow the Configure Distribution Wizard to:

  • Select a Distributor. To use a local Distributor, select ServerName will act as its own Distributor; SQL Server will create a distribution database and log. To use a remote Distributor, select Use the following server as the Distributor, and then select a server. The server must already be configured as a Distributor, and the Publisher must be enabled to use the Distributor. For more information, see Enable a Remote Publisher at a Distributor (SQL Server Management Studio).

    If you select a remote Distributor, you must enter a password on the Administrative Password page for connections made from the Publisher to the Distributor. This password must match the password specified when the Publisher was enabled at the remote Distributor.

  • Specify a root snapshot folder (for a local Distributor). The snapshot folder is simply a directory that you have designated as a share; agents that read from and write to this folder must have sufficient permissions to access it. Each Publisher that uses this Distributor creates a folder under the root folder, and each publication creates folders under the Publisher folder in which to store snapshot files. For more information on securing the folder appropriately, see Secure the Snapshot Folder.

  • Specify the distribution database (for a local Distributor). The distribution database stores metadata and history data for all types of replication and transactions for transactional replication.

  • Optionally enable other Publishers to use the Distributor. If other Publishers are enabled to use the Distributor, you must enter a password on the Distributor Password page for connections made from these Publishers to the Distributor.

  • Optionally script configuration settings. For more information, see Scripting Replication.

Using Transact-SQL

Replication publishing and distribution can be configured programmatically using replication stored procedures.

To configure publishing using a local distributor

  1. Execute sp_get_distributor (Transact-SQL) to determine if the server is already configured as a Distributor.
  • If the value of installed in the result set is 0, execute sp_adddistributor (Transact-SQL) at the Distributor on the master database.

  • If the value of distribution db installed in the result set is 0, execute sp_adddistributiondb (Transact-SQL) at the Distributor on the master database. Specify the name of the distribution database for @database. Optionally, you can specify the maximum transactional retention period for @max_distretention and the history retention period for @history_retention. If a new database is being created, specify the desired database property parameters.

  1. At the Distributor, which is also the Publisher, execute sp_adddistpublisher (Transact-SQL), specifying the UNC share that will be used as default snapshot folder for @working_directory.

    For a distributor on SQL Managed Instance, use an Azure storage account for @working_directory and the storage access key for @storage_connection_string.

  2. At the Publisher, execute sp_replicationdboption (Transact-SQL). Specify the database being published for @dbname, the type of replication for @optname, and a value of true for @value.

To configure publishing using a remote distributor

  1. Execute sp_get_distributor (Transact-SQL) to determine if the server is already configured as a Distributor.

    • If the value of installed in the result set is 0, execute sp_adddistributor (Transact-SQL) at the Distributor on the master database. Specify a strong password for @password. This password for the distributor_admin account will be used by the Publisher when connecting to the Distributor.

    • If the value of distribution db installed in the result set is 0, execute sp_adddistributiondb (Transact-SQL) at the Distributor on the master database. Specify the name of the distribution database for @database. Optionally, you can specify the maximum transactional retention period for @max_distretention and the history retention period for @history_retention. If a new database is being created, specify the desired database property parameters.

  2. At the Distributor, execute sp_adddistpublisher (Transact-SQL), specifying the UNC share that will be used as default snapshot folder for @working_directory. If the Distributor will use SQL Server Authentication when connecting to the Publisher, you must also specify a value of 0 for @security_mode and the Microsoft SQL Server login information for @login and @password.

    For a distributor on SQL Managed Instance, use an Azure storage account for @working_directory and the storage access key for @storage_connection_string.

  3. At the Publisher on the master database, execute sp_adddistributor (Transact-SQL). Specify the strong password used in step 1 for @password. This password will be used by the Publisher when connecting to the Distributor.

  4. At the Publisher, execute sp_replicationdboption (Transact-SQL). Specify the database being published for @dbname, the type of replication for @optname, and a value of true for @value.

Example (Transact-SQL)

The following example demonstrates how to configure publishing and distribution programmatically. In this example, the name of the server that is being configured as a publisher and a local distributor is supplied using scripting variables. Replication publishing and distribution can be configured programmatically using replication stored procedures.

-- 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".

-- Install the Distributor and the distribution database.
DECLARE @distributor AS sysname;
DECLARE @distributionDB AS sysname;
DECLARE @publisher AS sysname;
DECLARE @directory AS nvarchar(500);
DECLARE @publicationDB AS sysname;
-- Specify the Distributor name.
SET @distributor = $(DistPubServer);
-- Specify the distribution database.
SET @distributionDB = N'distribution';
-- Specify the Publisher name.
SET @publisher = $(DistPubServer);
-- Specify the replication working directory.
SET @directory = N'\\' + $(DistPubServer) + '\repldata';
-- Specify the publication database.
SET @publicationDB = N'AdventureWorks2022'; 

-- Install the server MYDISTPUB as a Distributor using the defaults,
-- including autogenerating the distributor password.
USE master
EXEC sp_adddistributor @distributor = @distributor;

-- Create a new distribution database using the defaults, including
-- using Windows Authentication.
USE master
EXEC sp_adddistributiondb @database = @distributionDB, 
    @security_mode = 1;
GO

-- Create a Publisher and enable AdventureWorks2022 for replication.
-- Add MYDISTPUB as a publisher with MYDISTPUB as a local distributor
-- and use Windows Authentication.
DECLARE @distributionDB AS sysname;
DECLARE @publisher AS sysname;
-- Specify the distribution database.
SET @distributionDB = N'distribution';
-- Specify the Publisher name.
SET @publisher = $(DistPubServer);

USE [distribution]
EXEC sp_adddistpublisher @publisher=@publisher, 
    @distribution_db=@distributionDB, 
    @security_mode = 1;
GO

Using Replication Management Objects (RMO)

To configure publishing and distribution on a single server

  1. Create a connection to the server by using the ServerConnection class.

  2. Create an instance of the ReplicationServer class. Pass the ServerConnection from step 1.

  3. Create an instance of the DistributionDatabase class.

  4. Set the Name property to the database name and set the ConnectionContext property to the ServerConnection from step 1.

  5. Install the Distributor by calling the InstallDistributor method. Pass the DistributionDatabase object from step 3.

  6. Create an instance of the DistributionPublisher class.

  7. Set the following properties of DistributionPublisher:

  1. Call the Create method.

To configure publishing and distribution using a remote Distributor

  1. Create a connection to the remote Distributor server by using the ServerConnection class.

  2. Create an instance of the ReplicationServer class. Pass the ServerConnection from step 1.

  3. Create an instance of the DistributionDatabase class.

  4. Set the Name property to the database name, and set the ConnectionContext property to the ServerConnection from step 1.

  5. Install the Distributor by calling the InstallDistributor method. Specify a secure password (used by the Publisher when connecting to the remote Distributor) and the DistributionDatabase object from step 3. For more information, see Secure the Distributor.

    Important

    When possible, prompt users to enter security credentials at runtime. If you must store credentials, use the cryptographic services provided by the Microsoft Windows .NET Framework.

  6. Create an instance of the DistributionPublisher class.

  7. Set the following properties of DistributionPublisher:

  1. Call the Create method.

  2. Create a connection to the local Publisher server by using the ServerConnection class.

  3. Create an instance of the ReplicationServer class. Pass the ServerConnection from step 9.

  4. Call the InstallDistributor method. Pass the name of the remote Distributor and the password for the remote Distributor specified in step 5.

Important

When possible, prompt users to enter security credentials at runtime. If you must store credentials, use the cryptographic services provided by the Windows .NET Framework.

Example (RMO)

You can programmatically configure replication publishing and distribution by using Replication Management Objects (RMO).

// Set the server and database names
string distributionDbName = "distribution";
string publisherName = publisherInstance;
string publicationDbName = "AdventureWorks2022";

DistributionDatabase distributionDb;
ReplicationServer distributor;
DistributionPublisher publisher;
ReplicationDatabase publicationDb;

// Create a connection to the server using Windows Authentication.
ServerConnection conn = new ServerConnection(publisherName);

try
{
    // Connect to the server acting as the Distributor 
    // and local Publisher.
    conn.Connect();

    // Define the distribution database at the Distributor,
    // but do not create it now.
    distributionDb = new DistributionDatabase(distributionDbName, conn);
    distributionDb.MaxDistributionRetention = 96;
    distributionDb.HistoryRetention = 120;

    // Set the Distributor properties and install the Distributor.
    // This also creates the specified distribution database.
    distributor = new ReplicationServer(conn);
    distributor.InstallDistributor((string)null, distributionDb);

    // Set the Publisher properties and install the Publisher.
    publisher = new DistributionPublisher(publisherName, conn);
    publisher.DistributionDatabase = distributionDb.Name;
    publisher.WorkingDirectory = @"\\" + publisherName + @"\repldata";
    publisher.PublisherSecurity.WindowsAuthentication = true;
    publisher.Create();

    // Enable AdventureWorks2022 as a publication database.
    publicationDb = new ReplicationDatabase(publicationDbName, conn);

    publicationDb.EnabledTransPublishing = true;
    publicationDb.EnabledMergePublishing = true;
}
catch (Exception ex)
{
    // Implement appropriate error handling here.
    throw new ApplicationException("An error occurred when installing distribution and publishing.", ex);
}
finally
{
    conn.Disconnect();
}
' Set the server and database names
Dim distributionDbName As String = "distribution"
Dim publisherName As String = publisherInstance
Dim publicationDbName As String = "AdventureWorks2022"

Dim distributionDb As DistributionDatabase
Dim distributor As ReplicationServer
Dim publisher As DistributionPublisher
Dim publicationDb As ReplicationDatabase

' Create a connection to the server using Windows Authentication.
Dim conn As ServerConnection = New ServerConnection(publisherName)

Try
    ' Connect to the server acting as the Distributor 
    ' and local Publisher.
    conn.Connect()

    ' Define the distribution database at the Distributor,
    ' but do not create it now.
    distributionDb = New DistributionDatabase(distributionDbName, conn)
    distributionDb.MaxDistributionRetention = 96
    distributionDb.HistoryRetention = 120

    ' Set the Distributor properties and install the Distributor.
    ' This also creates the specified distribution database.
    distributor = New ReplicationServer(conn)
    distributor.InstallDistributor((CType(Nothing, String)), distributionDb)

    ' Set the Publisher properties and install the Publisher.
    publisher = New DistributionPublisher(publisherName, conn)
    publisher.DistributionDatabase = distributionDb.Name
    publisher.WorkingDirectory = "\\" + publisherName + "\repldata"
    publisher.PublisherSecurity.WindowsAuthentication = True
    publisher.Create()

    ' Enable AdventureWorks2022 as a publication database.
    publicationDb = New ReplicationDatabase(publicationDbName, conn)

    publicationDb.EnabledTransPublishing = True
    publicationDb.EnabledMergePublishing = True

Catch ex As Exception
    ' Implement appropriate error handling here.
    Throw New ApplicationException("An error occurred when installing distribution and publishing.", ex)

Finally
    conn.Disconnect()

End Try