Merge & Transactional Publications on the same DB

  • Hello,

    I've setup a Merge Publication and Subscriber between Server A (Publisher) and Server B (Subscriber) that works perfectly. But now I am trying to set up transactional replication from Server A (Publisher) to Server C (Subscriber) and I get an error when I try and create the transactional publication.

    - Adding article 1 of 1 (Error)

    Messages

    SQL Server Management Studio could not create article 'Table1'. (New Publication Wizard)

    ------------------------------

    ADDITIONAL INFORMATION:

    An exception occurred while executing a Transact-SQL statement or batch. (Microsoft.SqlServer.ConnectionInfo)

    ------------------------------

    Automatic identity range support is useful only for publications that allow updating subscribers.

    Changed database context to 'DB1'. (Microsoft SQL Server, Error: 21231)

    For help, click: http://go.microsoft.com/fwlink?ProdName=Microsoft+SQL+Server&ProdVer=10.00.2531&EvtSrc=MSSQLServer&EvtID=21231&LinkId=20476

    From my understanding the Automatic identity range support is enabled as part of the Merge Replication setup. Anyone any ideas what I should look at first?

    Cheers,

    Peter

  • You can't use automatic identity range management for a table that is published using both merge and transactional replication. Either set the merge article to use manual management at the time you create it, or use replication stored procedures to change this setting.

    See: How to: Manage Identity Columns (Replication Transact-SQL Programming)

  • Cheers, I got round this by setting the Auto value to Manual and then setting the pub range, ident range and threshold.

    Heres the code, hopefully it will help someone else.

    USE [DB]

    CREATE TABLE #tempSysMergeArticles

    (

    [tableName] [varchar](255) NOT NULL,

    [Row] [int] IDENTITY(1,1) NOT NULL

    )

    DECLARE @intLoop int

    DECLARE @tableName varchar(255), @replication_publication varchar(255), @value_option varchar(255)

    DECLARE @value_pub_identity_range int, @value_identity_range int, @value_threshold int

    SET @replication_publication = 'DBMerge'

    SET @value_pub_identity_range = 1000000

    SET @value_identity_range = 2000

    SET @value_threshold = 80

    SET @value_option = 'manual'

    INSERT INTO #tempSysMergeArticles

    (

    [tableName]

    )

    (

    select [name]

    from dbo.sysmergearticles

    WHERE [identity_support] = 1

    )

    set @intLoop = 0

    while (@intLoop < (SELECT MAX([Row]) FROM #tempSysMergeArticles))

    begin

    set @intLoop = @intLoop + 1

    set @tableName = (SELECT [tableName] FROM #tempSysMergeArticles WHERE [Row] = @intLoop)

    exec sp_changemergearticle

    @publication = @replication_publication,

    @article = @tableName,

    @property = N'pub_identity_range',

    @value = @value_pub_identity_range,

    @force_invalidate_snapshot = 1,

    @force_reinit_subscription = 1

    exec sp_changemergearticle

    @publication = @replication_publication,

    @article = @tableName,

    @property = N'identity_range',

    @value = @value_identity_range,

    @force_invalidate_snapshot = 1,

    @force_reinit_subscription = 1

    exec sp_changemergearticle

    @publication = @replication_publication,

    @article = @tableName,

    @property = N'threshold',

    @value = @value_threshold,

    @force_invalidate_snapshot = 1,

    @force_reinit_subscription = 1

    exec sp_changemergearticle

    @publication = @replication_publication,

    @article = @tableName,

    @property = N'identityrangemanagementoption',

    @value = @value_option,

    @force_invalidate_snapshot = 1,

    @force_reinit_subscription = 1

    end -- while loop

    DROP TABLE #tempSysMergeArticles

  • Having been working on this for a while now I have found that when our developers need to modify a DB to add a table or SP to the Merge Replication it fails unless it is deselected from the Transactional Replication beforehand. However when I de-select and re-select the article on the Transactional Publication it then breaks the Transactional Subscription and I have to re-create it every time.

    Is there an easy way to get round the addition or change of articles? I'm even looking and using Merge Replication throughout but this is causing issues when I re-publish even though the above script has been run on the 1st publisher.

  • Have you tried creating publisher on Server B for Transactional Replication?

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply