|
| 1 | +--- |
| 2 | +title: Troubleshoot Issues Configuring Transactional Replication on Multiple SQL Server Linux Containers |
| 3 | +description: Learn how to fix duplicate subscription errors when setting up transactional replication on SQL Server Linux containers. |
| 4 | +ms.reviewer: pijocoder, mlandzic, randolphwest, v-shaywood |
| 5 | +ms.custom: sap:Replication, Change Tracking, Change Data Capture\Errors or unexpected results during operation |
| 6 | +ms.date: 11/03/2025 |
| 7 | +--- |
| 8 | + |
| 9 | +# Configuring transactional replication fails on multiple SQL Server Linux containers |
| 10 | + |
| 11 | +This article provides troubleshooting guidance for an issue that occurs when you configure two Microsoft SQL Server-based servers that run in Linux containers on the same computer as replication subscribers. |
| 12 | + |
| 13 | +## Symptoms |
| 14 | + |
| 15 | +When you configure **Transactional Replication** on SQL Server 2022 running in Linux containers, you receive the following error message: |
| 16 | + |
| 17 | +> The subscription already exists. |
| 18 | +
|
| 19 | +This issue usually occurs when: |
| 20 | + |
| 21 | +- Two SQL Server instances are hosted in separate containers on the same Linux-based computer. |
| 22 | +- Both instances are added as subscribers to the same publisher. |
| 23 | +- The connection strings use the same hostname but different port numbers (for example, `LINUXHOST,5455` and `LINUXHOST,5465`). |
| 24 | + |
| 25 | +## Cause |
| 26 | + |
| 27 | +This issue occurs because subscriber metadata doesn't honor port numbers during persistence. Only the hostname is stored. This behavior causes the second subscriber to be seen as a duplicate of the first. |
| 28 | + |
| 29 | +This behavior is specific to Linux container environments in which named instances don't exist and connections rely on hostname and port mapping. |
| 30 | + |
| 31 | +## Workaround |
| 32 | + |
| 33 | +To successfully add multiple subscribers on the same computer but in different containers, follow these steps: |
| 34 | + |
| 35 | +1. Install [Cumulative Update 20 (CU20) for SQL Server 2022](https://www.catalog.update.microsoft.com/Search.aspx?q=KB5059390). |
| 36 | + |
| 37 | +1. Enable trace flag [15005](/sql/t-sql/database-console-commands/dbcc-traceon-trace-flags-transact-sql#tf15005). This trace flag enables you to use a subscriber that has a nondefault port for transactional replication. |
| 38 | + |
| 39 | +1. Perform the following manual cleanup and configuration steps in Transact-SQL. In this script, replace the `@hostname`, `@port_sub1`, `@port_sub2`, `@PublicationName`, `@SubscriberDb_Sub1`, and `@SubscriberDb_Sub2` variables with values that are specific to your environment: |
| 40 | + |
| 41 | + ```sql |
| 42 | + DECLARE @hostname AS SYSNAME = 'LinuxSubscriberHostName', |
| 43 | + @port_sub1 AS NVARCHAR (10) = '5455', |
| 44 | + @port_sub2 AS NVARCHAR (10) = '5465', |
| 45 | + @host_and_port_sub1 AS NVARCHAR (100), |
| 46 | + @host_and_port_sub2 AS NVARCHAR (100), |
| 47 | + @PublicationName AS SYSNAME = 'PublicationName', |
| 48 | + @SubscriberDb_Sub1 AS SYSNAME = 'SubscriberDB1', |
| 49 | + @SubscriberDb_Sub2 AS SYSNAME = 'SubscriberDB2'; |
| 50 | + |
| 51 | + -- Concatenate the hostname and port for each subscriber (for example 'LinuxSubscriberHostName,5455') |
| 52 | + SET @host_and_port_sub1 = CONCAT(@hostname, ',', @port_sub1); |
| 53 | + SET @host_and_port_sub2 = CONCAT(@hostname, ',', @port_sub2); |
| 54 | + |
| 55 | + -- Step 1: Remove subscription metadata |
| 56 | + USE [PublicationDb]; |
| 57 | + |
| 58 | + EXECUTE sp_dropsubscription |
| 59 | + @publication = @PublicationName, |
| 60 | + @article = 'all', |
| 61 | + @subscriber = @hostname, |
| 62 | + @destination_db = @SubscriberDb_Sub1; |
| 63 | + |
| 64 | + -- Step 2: Remove subscriber from publication |
| 65 | + EXECUTE sp_dropsubscriber @subscriber = @hostname; |
| 66 | + |
| 67 | + -- Step 3: Remove server entry for the first subscriber with no port information captured (on Publisher side) |
| 68 | + DELETE FROM distribution..MSreplservers |
| 69 | + WHERE UPPER(srvname COLLATE database_default) = UPPER(@hostname COLLATE database_default); |
| 70 | + |
| 71 | + IF EXISTS (SELECT 1 FROM sys.servers WHERE name = @hostname) |
| 72 | + EXECUTE sp_dropserver @hostname, 'droplogins'; |
| 73 | + |
| 74 | + -- Step 4: Re-add linked server on Publisher side |
| 75 | + EXECUTE sp_addlinkedserver @server = @host_and_port_sub1; |
| 76 | + EXECUTE sp_serveroption @server = @host_and_port_sub1, @optname = 'sub', @optvalue = true; |
| 77 | + |
| 78 | + EXECUTE sp_addlinkedserver @server = @host_and_port_sub2; |
| 79 | + EXECUTE sp_serveroption @server = @host_and_port_sub2, @optname = 'sub', @optvalue = true; |
| 80 | + |
| 81 | + --Ensure entries are successful |
| 82 | + SELECT * FROM master..sysservers; |
| 83 | + |
| 84 | + --Step 5. Insert information about the subscribers to the Msreplservers table. |
| 85 | + INSERT INTO [distribution]..MSreplservers (srvid, srvname) |
| 86 | + SELECT srvid, srvname |
| 87 | + FROM master.dbo.sysservers |
| 88 | + WHERE UPPER(srvname COLLATE database_default) = UPPER(@host_and_port_sub1 COLLATE database_default); |
| 89 | + |
| 90 | + INSERT INTO [distribution]..MSreplservers (srvid, srvname) |
| 91 | + SELECT srvid, srvname |
| 92 | + FROM master.dbo.sysservers |
| 93 | + WHERE UPPER(srvname COLLATE database_default) = UPPER(@host_and_port_sub2 COLLATE database_default); |
| 94 | + |
| 95 | + --Verify entries |
| 96 | + SELECT * FROM [distribution]..MSreplservers; |
| 97 | + |
| 98 | + --Step 6. Create subscribers (push subscription) |
| 99 | + -----------------BEGIN: Script to be run at Publisher @hostname-----------------;; |
| 100 | + |
| 101 | + --Create subscriber to the first Linux container |
| 102 | + USE [PublicationDb]; |
| 103 | + |
| 104 | + EXECUTE sp_addsubscription |
| 105 | + @publication = @PublicationName, |
| 106 | + @subscriber = @host_and_port_sub1, |
| 107 | + @destination_db = @SubscriberDb_Sub1, |
| 108 | + @subscription_type = N'Push', |
| 109 | + @sync_type = N'automatic', |
| 110 | + @article = N'all', |
| 111 | + @update_mode = N'read only', |
| 112 | + @subscriber_type = 0; |
| 113 | + |
| 114 | + EXECUTE sp_addpushsubscription_agent |
| 115 | + @publication = @PublicationName, |
| 116 | + @subscriber = @host_and_port_sub1, |
| 117 | + @subscriber_db = @SubscriberDb_Sub1, |
| 118 | + @job_login = NULL, |
| 119 | + @job_password = NULL, |
| 120 | + @subscriber_security_mode = 1, |
| 121 | + @frequency_type = 64, |
| 122 | + @frequency_interval = 0, |
| 123 | + @frequency_relative_interval = 0, |
| 124 | + @frequency_recurrence_factor = 0, |
| 125 | + @frequency_subday = 0, |
| 126 | + @frequency_subday_interval = 0, |
| 127 | + @active_start_time_of_day = 0, |
| 128 | + @active_end_time_of_day = 235959, |
| 129 | + @active_start_date = 20250711, |
| 130 | + @active_end_date = 99991231, |
| 131 | + @enabled_for_syncmgr = N'False', |
| 132 | + @dts_package_location = N'Distributor'; |
| 133 | + |
| 134 | + --Create subscriber to the second Linux container |
| 135 | + USE [PublicationDb]; |
| 136 | + |
| 137 | + EXECUTE sp_addsubscription |
| 138 | + @publication = @PublicationName, |
| 139 | + @subscriber = @host_and_port_sub2, |
| 140 | + @destination_db = @SubscriberDb_Sub2, |
| 141 | + @subscription_type = N'Push', |
| 142 | + @sync_type = N'automatic', |
| 143 | + @article = N'all', |
| 144 | + @update_mode = N'read only', |
| 145 | + @subscriber_type = 0; |
| 146 | + |
| 147 | + EXECUTE sp_addpushsubscription_agent |
| 148 | + @publication = @PublicationName, |
| 149 | + @subscriber = @host_and_port_sub2, |
| 150 | + @subscriber_db = @SubscriberDb_Sub2, |
| 151 | + @job_login = NULL, |
| 152 | + @job_password = NULL, |
| 153 | + @subscriber_security_mode = 1, |
| 154 | + @frequency_type = 64, |
| 155 | + @frequency_interval = 0, |
| 156 | + @frequency_relative_interval = 0, |
| 157 | + @frequency_recurrence_factor = 0, |
| 158 | + @frequency_subday = 0, |
| 159 | + @frequency_subday_interval = 0, |
| 160 | + @active_start_time_of_day = 0, |
| 161 | + @active_end_time_of_day = 235959, |
| 162 | + @active_start_date = 20250711, |
| 163 | + @active_end_date = 99991231, |
| 164 | + @enabled_for_syncmgr = N'False', |
| 165 | + @dts_package_location = N'Distributor'; |
| 166 | + ``` |
| 167 | + |
| 168 | +## Resolution |
| 169 | + |
| 170 | +Currently, no permanent fix is available. Instead, see the ["Workaround"](#workaround) section. |
| 171 | + |
| 172 | +The product team is evaluating potential fixes for future releases. This article will be updated when a solution becomes available. |
| 173 | + |
| 174 | +## Related content |
| 175 | + |
| 176 | +- [Transactional Replication](/sql/relational-databases/replication/transactional/transactional-replication) |
| 177 | +- [Quickstart: Run SQL Server Linux container images with Docker](/sql/linux/quickstart-install-connect-docker) |
0 commit comments