Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Merge & Transactional Publications on the same DB Expand / Collapse
Author
Message
Posted Friday, April 16, 2010 2:51 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, January 23, 2013 5:40 AM
Points: 26, Visits: 400
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
Post #904620
Posted Sunday, April 18, 2010 8:10 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 7:35 PM
Points: 11,168, Visits: 10,940
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)




Paul White
SQL Server MVP
SQLblog.com
@SQL_Kiwi
Post #905649
Posted Tuesday, April 20, 2010 3:07 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, January 23, 2013 5:40 AM
Points: 26, Visits: 400
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

Post #906646
Posted Thursday, April 22, 2010 2:03 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, January 23, 2013 5:40 AM
Points: 26, Visits: 400
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.
Post #908378
Posted Thursday, August 02, 2012 12:13 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, March 27, 2014 8:23 AM
Points: 1, Visits: 101
Have you tried creating publisher on Server B for Transactional Replication?
Post #1339422
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse