Today I got a request from a client that I had to add a new article to an existing publication. But they didn't want me to generate a snapshot for the entire database. It takes more than 2 hours for the snapshot to be taken and then additional 4 hours to apply it. This would cause significant outage.
So after a lot of research I found the following method to achieve this.
1) Make sure that your publication has IMMEDIATE_SYNC and ALLOW_ANONYMOUS properties set to FALSE or 0.
Use yourDB
Use yourDB
select immediate_sync , allow_anonymous from syspublications
If either of them is TRUE then modify that to FALSE by using the following
command
EXEC sp_changepublication @publication = 'yourpublication', @property =
N'allow_anonymous', @value='False'
Go
EXEC sp_changepublication @publication = 'yourpublication', @property =
N'immediate_sync', @value='false'
Go
2) Now add the article to the publication
Use yourDB
EXEC sp_addarticle @publication = 'yourpublication', @article ='test',
@source_owner = 'schemanameofobject',
@source_owner = 'schemanameofobject',
@source_object = 'sourceobjectname',
@source_owner = 'schemanameatsubscriber', @force_invalidate_snapshot=1
@source_owner = 'schemanameatsubscriber', @force_invalidate_snapshot=1
If you do not use the @force_invalidate_snapshot option then you will receive the
following error
Msg 20607, Level 16, State 1, Procedure sp_MSreinit_article, Line 99
Cannot make the change because a snapshot is already generated. Set
@force_invalidate_snapshot to 1 to force the change and invalidate the existing snapshot.
3) Verify if you are using CONCURRENT or NATIVE method for synchronization by running the following command.
Use yourdb
select sync_method from syspublications
If the value is 3 or 4 then it is CONCURRENT and if it is 0 then it is NATIVE.
For more information check
4) Then add the subscription for this new article using the following command
EXEC sp_addsubscription @publication = 'yourpublicationname',
@subscription_type = N'pull',
@article = 'yourarticlename',
@subscriber ='subscriberservername', @destination_db = 'destinationDB',
@reserved='Internal'
@subscription_type = N'pull',
@article = 'yourarticlename',
@subscriber ='subscriberservername', @destination_db = 'destinationDB',
@reserved='Internal'
It is upto you if you want to use the PULL subscription or not.
If you are using the NATIVE method for synchronization then the parameter
@reserved=’Internal’ is optional but there is no harm in using it anyways. But if it is CONCURRENT then you have to use that parameter. Else the next time you run the snapshot agent it is going to generate a snapshot for all the articles.
Lastly start the SNAPSHOT AGENT job from the job activity monitor. To find
the job name follow these steps.
· select * from msdb..sysjobs where name like '%yourpublication%'
· Right click on each of those jobs and find which one contains the step
‘Snapshot Agent startup message’. This is the job that you want to
start from the first step.
Verify that the snapshot was generated for only one article.
Do not use the Replication monitor to Re-initialize the subscribers.
Thanks for taking the time to post this!
ReplyDeleteYou are most welcome. I know how important this is hence I documented it for my own benefit.
DeleteLet me know if you have any other questions regarding replication.
Really it is helpful, thanks a lot
ReplyDeleteYou are welcome
DeleteWHY DO WE NEED TO SET IMMEDIATE_SYNC AND ALLOW_ANONYMOUS OPTIONS TO ZERO?
DeleteAt least that's what I found in the documentation. I have not tested how it will work if I don't use those two options.
DeleteAccording to what I had read, without those options, you will be forced to take a snapshot for all the published articles.
Thanks a million to point this out.
ReplyDeleteThe large pub really annoys me. Great article and I am trying this on my dev env.
I wonder if MS has made this easy in SQL server 2014 or 2016
DeleteHi,Is this process gonna work for publication that has been initialized with backup option? Need to know urgent. Thanks in advance.
ReplyDelete