SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Replication Statement Delivery Options - Part 2


Replication Statement Delivery Options - Part 2

Author
Message
Andy Warren
Andy Warren
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: Moderators
Points: 25667 Visits: 2746
Comments posted here are about the content posted at http://www.sqlservercentral.com/columnists/awarren/3202.asp

Andy
SQLAndy - My Blog!
Connect with me on LinkedIn
Follow me on Twitter
Jack Corbett
  Jack Corbett
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45231 Visits: 14925
Good article. Can someone explain to me how the bitmap is created when an update takes place? I can envision using this technique in triggers when archiving/logging.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
firthr
firthr
SSC-Addicted
SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)

Group: General Forum Members
Points: 458 Visits: 99
Not sure how this procedure, sp_scriptdynamicupdateproc , is used, it won't parse for me. Can you give an example of it beign called please?



"There is one other option for updates, but you won't find it in the UI. You can run sp_scriptdynamicupdateproc to generate a stored procedure that will build and execute dynamic SQL on the subscriber. Running the procedure just generates the script, it is up to you to apply it to all of your subscribers. The tradeoff when using this is that you only touch truly changed columns which may increase performance if many of the columns are indexed, in return you incur the overhead of building the statement and executing it each time. Here's what we what we would get from our original test table after running the proc on the publisher"



firthr
firthr
SSC-Addicted
SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)

Group: General Forum Members
Points: 458 Visits: 99
Not sure how this procedure, sp_scriptdynamicupdateproc , is used, it won't parse for me. Can you give an example of it beign called please?



"There is one other option for updates, but you won't find it in the UI. You can run sp_scriptdynamicupdateproc to generate a stored procedure that will build and execute dynamic SQL on the subscriber. Running the procedure just generates the script, it is up to you to apply it to all of your subscribers. The tradeoff when using this is that you only touch truly changed columns which may increase performance if many of the columns are indexed, in return you incur the overhead of building the statement and executing it each time. Here's what we what we would get from our original test table after running the proc on the publisher"



firthr
firthr
SSC-Addicted
SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)SSC-Addicted (458 reputation)

Group: General Forum Members
Points: 458 Visits: 99
Not sure how this procedure, sp_scriptdynamicupdateproc , is used, it won't parse for me. Can you give an example of it beign called please?



"There is one other option for updates, but you won't find it in the UI. You can run sp_scriptdynamicupdateproc to generate a stored procedure that will build and execute dynamic SQL on the subscriber. Running the procedure just generates the script, it is up to you to apply it to all of your subscribers. The tradeoff when using this is that you only touch truly changed columns which may increase performance if many of the columns are indexed, in return you incur the overhead of building the statement and executing it each time. Here's what we what we would get from our original test table after running the proc on the publisher"



msuarez
msuarez
SSC-Enthusiastic
SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)

Group: General Forum Members
Points: 106 Visits: 70
Hi Andy,

Great Article. Very thorough and informative.

When I create a publication, I use the default settings (CALL for INSERT and DELETE and SCALL for UPDATE), and as expected I get these 3 procedures, as described in your article:

[sp_MSdel_dboTableName]
[sp_MSins_dboTableName]
[sp_MSupd_dboTableName]

However, in addition, unexpectedly I get two more procedures:

[sp_MSdel_dboTableName_msrepl_ccs]
[sp_MSins_dboTableName_msrepl_ccs]

Basically, it's just an extra insert and an extra delete procedure with msrepl_ccs appended to the end of the names.

The difference in the delete procedure is that it does not post the error if the rowcount is 0. The difference in the insert procedure is that it checks to see if a record exists with the same pk, and if one does, it will update that record (instead of doing an insert that would ultimately fail).

I don't believe these procedures are being called by anything. It seems as though they are just there. The only reason I can think of is that if someone wants that type of behavior, they can simply change the properties of the article to call those procs instead of the other ones.

I haven't seen any documentation on it, and you didn't mention it in your article.

Do you have any explanation for why these procedures are being created? Do you know of any way to prevent them from being created? (if they are not being used, then they are just cluttering up the list of stored procedures).
Andy Warren
Andy Warren
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: Moderators
Points: 25667 Visits: 2746
Msaurez, no idea. What version of SQL? What type of replication? If transactional, vanilla, updatable subscribers??

Andy
SQLAndy - My Blog!
Connect with me on LinkedIn
Follow me on Twitter
msuarez
msuarez
SSC-Enthusiastic
SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)

Group: General Forum Members
Points: 106 Visits: 70
SQL Server 2005.
Transactional (standard).
Distribution Server set up on another machine.

As straight forward a publication as you could imagine. Single table, no row filters, no column filters.
I'm fairly new to replication, and in doing all of the set up through the wizards, I haven't deviated from the default settings at all.

Every time I subscribe to a publication, these 2 extra sps get created.

One of my collegues noticed that when you set distribution to run locally, these 2 sps are not created... I wonder what that has to do with it...

Andy, do you not get these when sp's when you set up trans rep in 2005?
msuarez
msuarez
SSC-Enthusiastic
SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)

Group: General Forum Members
Points: 106 Visits: 70
And here they are... the 5 sp's that I get for this table:

CREATE TABLE [dbo].[test_for_replication](
[id] [int] NOT NULL PRIMARY KEY,
[name] [varchar](30) NOT NULL,
[description] [varchar](255) NOT NULL)

The ones being used are:

sp_MSdel_dbotest_for_replication
sp_MSins_dbotest_for_replication
sp_MSupd_dbotest_for_replication

The seemingly superfluous ones are:

sp_MSdel_dbotest_for_replication_msrepl_ccs
sp_MSins_dbotest_for_replication_msrepl_ccs

Here are the create proc scripts for all of them:

CREATE procedure [dbo].[sp_MSdel_dbotest_for_replication]
@pkc1 int
as
begin
delete "dbo"."test_for_replication"
where "id" = @pkc1
if @@rowcount = 0
if @@microsoftversion>0x07320000
exec sp_MSreplraiserror 20598
end

create procedure [dbo].[sp_MSdel_dbotest_for_replication_msrepl_ccs]
@pkc1 int
as
begin
delete "dbo"."test_for_replication"
where "id" = @pkc1
end

create procedure [dbo].[sp_MSins_dbotest_for_replication]
@c1 int,@c2 varchar(30),@c3 varchar(255)
as
begin
insert into "dbo"."test_for_replication"(
"id"
,"name"
,"description"
)
values (
@c1
,@c2
,@c3
)
end

create procedure [dbo].[sp_MSins_dbotest_for_replication_msrepl_ccs]
@c1 int,@c2 varchar(30),@c3 varchar(255)
as
begin
if exists ( select * from "dbo"."test_for_replication"
where "id" = @c1
)
begin
update "dbo"."test_for_replication" set
"name" = @c2
,"description" = @c3
where "id" = @c1
end
else
begin
insert into "dbo"."test_for_replication"(
"id"
,"name"
,"description"
)
values (
@c1
,@c2
,@c3
)
end
end

create procedure [dbo].[sp_MSupd_dbotest_for_replication]
@c1 int = null,@c2 varchar(30) = null,@c3 varchar(255) = null,@pkc1 int
,@bitmap binary(1)
as
begin
if ( substring(@bitmap,1,1) & 1 = 1 )
begin
update "dbo"."test_for_replication" set
"id" = case substring(@bitmap,1,1) & 1 when 1 then @c1 else "id" end
,"name" = case substring(@bitmap,1,1) & 2 when 2 then @c2 else "name" end
,"description" = case substring(@bitmap,1,1) & 4 when 4 then @c3 else "description" end
where "id" = @pkc1
if @@rowcount = 0
if @@microsoftversion>0x07320000
exec sp_MSreplraiserror 20598
end
else
begin
update "dbo"."test_for_replication" set
"name" = case substring(@bitmap,1,1) & 2 when 2 then @c2 else "name" end
,"description" = case substring(@bitmap,1,1) & 4 when 4 then @c3 else "description" end
where "id" = @pkc1
if @@rowcount = 0
if @@microsoftversion>0x07320000
exec sp_MSreplraiserror 20598
end
end
Simon Bailey
Simon Bailey
SSC Veteran
SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)SSC Veteran (220 reputation)

Group: General Forum Members
Points: 220 Visits: 269
Hi msuarez

I am also seeing similarly named stored procedures being created when I apply a snapshot after configuring transactional replication. They also appear when adding articles to an existing publication.

The important point is, though, that they (should) disappear immediately after the snapshot has been applied. they seem to be temporary in nature, for whatever purpose.

Cheers

Simon
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search