Home > Articles > Data > SQL Server

Maintaining Transactional Replication with SQL Server 2005

Microsoft has introduced some great improvements to replication with SQL Server 2005, alleviating some of the problematic maintenance issues in previous releases. Baya Pavliashvili demonstrates the steps necessary to maintain a typical publication, and explains how new options for delivering data changes can help you tailor a replication solution to your application's needs.
Like this article? We recommend

The first article in this series introduced you to replication setup with SQL Server 2005. In a simple scenario, replication setup is straightforward; however, replication does require some maintenance. This article shows you how to maintain replication stored procedures, how to make changes to existing publications, and how to reinitialize subscriptions as applied to SQL Server 2005. As in the first article, some differences between the most current and previous versions of SQL Server are highlighted.

Replication Stored Procedures

By default, replication replaces INSERT, UPDATE, and DELETE commands executed on the publisher with respective stored procedures on the subscriber. Doing so is recommended because stored procedures break larger INSERT, UPDATE, and DELETE commands into smaller chunks—affecting one row at a time. So an UPDATE statement that affects 1,000 rows will be translated into 1,000 executions of the update stored procedure. Changing one row at a time isn’t very efficient, but it reduces the locking impact on the subscriber so that you won’t experience many contention issues.

Unlike previous releases, SQL Server 2005 has several new options for statement delivery, which enable you to customize how replication works—depending on your needs. The options are summarized in the following table.

Statement

Option

Meaning

New in SQL Server 2005

INSERT

Call stored procedure (default)

Translate INSERT statements executed on publisher into stored procedure calls, adding a single row at a time.

No

INSERT

Do not replicate INSERT statements

Do not forward INSERT statements executed on the publisher to the subscriber(s).

Yes

INSERT

INSERT statement

Execute the same INSERT statements on publisher and subscriber.

No

INSERT

INSERT statement without column list

Replicate the INSERT statement without specifying the column list:

insert into [dbo].[DimAccount] 
values (11,9,1164,1160,N’work in progress’,N’Assets’,N’+’,NULL,N’Currency’,NULL)

Yes

UPDATE

Do not replicate UPDATE statements

Do not forward UPDATE statements executed on the publisher to the subscriber(s).

Yes

UPDATE

UPDATE statement

Execute the same UPDATE statements on publisher and subscriber.

No

UPDATE

CALL stored procedure (default)

Translate UPDATE statements executed on publisher into stored procedure calls, changing a single row at a time.

No

UPDATE

MCALL stored procedure

Translate UPDATE statements executed on publisher into stored procedure calls, changing a single row at a time. This option passes the value of the affected column and NULL for unaffected columns, as in the following:

{CALL [sp_MSupd_dboDimAccount] 
(NULL,NULL,NULL,NULL,N’work in process’,NULL,NULL,NULL,NULL,NULL,11,0x1000)}

No

UPDATE

XCALL stored procedure

Translate UPDATE statements executed on publisher into stored procedure calls changing a single row at a time. This option passes the values of all columns, as in the following:

{CALL [sp_MSupd_dboDimAccount] (11, 9, 1164, 1160, 
N’work in process’, N’Assets’, N’+’, NULL,
N’Currency’, NULL, 11, 9, 1164, 1160, 
N’work in progress’, N’Assets’, N’+’, NULL, N’Currency’, NULL)}

No

UPDATE

SCALL stored procedure

Translate UPDATE statements executed on publisher into stored procedure calls, changing a single row at a time. This option passes nothing for nonaffected columns and values of the affected columns, as in the following:

{CALL [sp_MSupd_dboDimAccount] 
(,,,,N’work in process’,,,,,,11,0x1000)}

Yes

DELETE

CALL stored procedure (default)

Translate DELETE statements executed on publisher into stored procedure calls, deleting a single row at a time.

No

DELETE

Do not replicate DELETE statements

Do not forward DELETE statements executed on publisher to the subscriber(s).

Yes

DELETE

DELETE statement

Execute the same DELETE statements on publisher and subscriber.

No

DELETE

XCALL stored procedure

Translate DELETE statements executed on publisher into stored procedure calls, deleting a single row at a time. This option passes the values of all columns, as in the following:

{CALL [sp_MSdel_dboDimAccount] (11,9,1164,1160,N’work in progress’,N’Assets’,N’+’,NULL,N’Currency’,NULL)}

No

Note that although previous versions didn’t support ignoring INSERT, UPDATE, or DELETE commands, you could modify stored procedures created by replication on subscribers to achieve similar functionality. This isn’t a recommended practice, however, because customized replication procedures are not supported. More importantly, even if you modify the replication procedures, the commands would still have to be delivered to the distribution database—they just wouldn’t make data changes on the subscriber. With SQL Server 2005, if you configure INSERT, UPDATE, or DELETE commands to not be replicated, such commands are simply ignored and never even forwarded to the distributor. Furthermore, the respective stored procedures are NOT created on the subscribers.

The text of the replication stored procedures executed on the subscriber(s) hasn’t changed much; the skeleton of the INSERT, UPDATE, and DELETE statements is shown below:

/* 
** DELETE procedure
** passes the primary key as the only parameter 
*/
create procedure [dbo].[sp_MSdel_dboDimAccount] 
@pkc1 int 
as 
begin 
delete [dbo].[DimAccount] where [AccountKey] = @pkc1 

if @@rowcount = 0  
if @@microsoftversion>0x07320000   
exec sp_MSreplraiserror 20598 
end 
/*
** INSERT procedure
*/
create procedure [dbo].[sp_MSins_dboDimAccount] 
 @c1 int,@c2 int,@c3 int,@c4 int,@c5 nvarchar(50),@c6 nvarchar(50),@c7 nvarchar(50),@c8 nvarchar(300),@c9 nvarchar(50),@c10 nvarchar(200)
as 
begin 
insert into "dbo"."DimAccount"( 
 "AccountKey"
,"ParentAccountKey"
,"AccountCodeAlternateKey"
,"ParentAccountCodeAlternateKey"
,"AccountDescription"
,"AccountType"
,"Operator"
,"CustomMembers"
,"ValueType"
,"CustomMemberOptions"
 )
values ( 
 @c1
,@c2
,@c3
,@c4
,@c5
,@c6
,@c7
,@c8
,@c9
,@c10
 ) 
end

/*
** UPDATE procedure
*/

create procedure [dbo].[sp_MSupd_dboDimAccount] 
 @c1 int = null,@c2 int = null,@c3 int = null,@c4 int = null,@c5 nvarchar(50) = null,@c6 nvarchar(50) = null,@c7 nvarchar(50) = null,@c8 nvarchar(300) = null,@c9 nvarchar(50) = null,@c10 nvarchar(200) = null,@pkc1 int
,@bitmap binary(2)
as
begin
update "dbo"."DimAccount" set 
 "ParentAccountKey" = case substring(@bitmap,1,1) & 2 when 2 then @c2 else "ParentAccountKey" end
,"AccountCodeAlternateKey" = case substring(@bitmap,1,1) & 4 when 4 then @c3 else "AccountCodeAlternateKey" end
,"ParentAccountCodeAlternateKey" = case substring(@bitmap,1,1) & 8 when 8 then @c4 else "ParentAccountCodeAlternateKey" end
,"AccountDescription" = case substring(@bitmap,1,1) & 16 when 16 then @c5 else "AccountDescription" end
,"AccountType" = case substring(@bitmap,1,1) & 32 when 32 then @c6 else "AccountType" end
,"Operator" = case substring(@bitmap,1,1) & 64 when 64 then @c7 else "Operator" end
,"CustomMembers" = case substring(@bitmap,1,1) & 128 when 128 then @c8 else "CustomMembers" end
,"ValueType" = case substring(@bitmap,2,1) & 1 when 1 then @c9 else "ValueType" end
,"CustomMemberOptions" = case substring(@bitmap,2,1) & 2 when 2 then @c10 else "CustomMemberOptions" end
where "AccountKey" = @pkc1

if @@rowcount = 0
 if @@microsoftversion>0x07320000
  exec sp_MSreplraiserror 20598
end

If you change the publication—for example by adding columns, changing column data types, or filtering replicated columns, you also need to modify the replication stored procedures. If you run the Snapshot Agent, it will automatically create the updated stored procedures for you; however, you might not always have this luxury. Generating snapshots for publications that support large databases can take a long time, and applying such snapshots at the subscriber can take the same time. If you can’t afford lengthy downtime, and the data on the subscriber doesn’t have to be reapplied, there is a better option for refreshing stored procedures. You can execute the system procedure sp_scriptpublicationcustomprocs on the publisher. This procedure accepts the publication name as the only parameter, so it can be called as follows:

EXECUTE sp_scriptpublicationcustomprocs ’publicationName’

The result will be all INSERT, UPDATE, and DELETE stored procedures that you need to apply on the subscribers.

If you’re using immediate updating subscribers, you can use another system procedure to script the triggers that will be created on the subscription tables. The sp_script_synctran_commands procedure accepts two parameters: publication name and article name. For example, to script triggers for all articles, you can execute the following:

EXEC sp_script_synctran_commands 
@publication = ’publicationName’, @article = ’all’

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020