Home > Articles > Data > SQL Server

Maintaining Transactional Replication with SQL Server 2005

  • Print
  • + Share This
  • 💬 Discuss
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.

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’
  • + Share This
  • 🔖 Save To Your Account

Discussions

comments powered by Disqus