You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
By default transactional replication makes all data changes at Subscribers through stored procedures that are generated by internal procedures for each table article in the publication. The three procedures (one each for inserts, updates, and deletes) are copied to the Subscriber and execute when an insert, update, or delete is replicated to the Subscriber. When a schema change is made to a table on a [!INCLUDE[ssNoVersion](../../../includes/ssnoversion-md.md)] Publisher, replication regenerates these procedures automatically by calling the same set of internal scripting procedures so that the new procedures match the new schema (replication of schema changes is not supported for Oracle Publishers).
21
-
22
-
It is also possible to specify custom procedures to replace one or more of the default procedures. The custom procedures should be changed if the schema change will affect the procedure. For example, if a procedure references a column that is dropped in a schema change, references to the column should be removed from the procedure. There are two ways for replication to propagate a new custom procedure to Subscribers:
23
-
24
-
- The first option is to use a custom scripting procedure to replace the defaults used by replication:
25
-
26
-
1. When executing [sp_addarticle (Transact-SQL)](../../../relational-databases/system-stored-procedures/sp-addarticle-transact-sql.md), ensure the `@schema_option` 0x02 bit is to **true**.
27
-
28
-
2. Execute [sp_register_custom_scripting (Transact-SQL)](../../../relational-databases/system-stored-procedures/sp-register-custom-scripting-transact-sql.md) and specify a value of 'insert', 'update', or 'delete' for the parameter `@type` and the name of the custom scripting procedure for the parameter `@value`.
29
-
30
-
The next time a schema change is made, replication calls this stored procedure to script out the definition for the new user defined custom stored procedure, and then propagates the procedure to each Subscriber.
31
-
32
-
- The second option is to use a script that contains a new custom procedure definition:
33
-
34
-
1. When executing [sp_addarticle (Transact-SQL)](../../../relational-databases/system-stored-procedures/sp-addarticle-transact-sql.md), set the `@schema_option` 0x02 bit to **false** so replication does not automatically generate custom procedures at the Subscriber.
35
-
36
-
2. Before each schema change, create a new script file and register the script with replication by executing [sp_register_custom_scripting (Transact-SQL)](../../../relational-databases/system-stored-procedures/sp-register-custom-scripting-transact-sql.md). Specify a value of 'custom_script' for the parameter `@type` and the path to the script on the Publisher for the parameter `@value`.
37
-
38
-
The next time a relevant schema change is made, this script executes on each Subscriber within the same transaction as the DDL command. After the schema change is made, the script is unregistered. You must re-register the script to have it executed after a subsequent schema change.
By default, transactional replication makes all data changes at Subscribers through stored procedures that are generated by internal procedures, for each table article in the publication. The three procedures (one each for inserts, updates, and deletes) are copied to the Subscriber and executed when an insert, update, or delete is replicated to the Subscriber.
24
+
25
+
When a schema change is made to a table on a [!INCLUDE [ssNoVersion](../../../includes/ssnoversion-md.md)] Publisher, replication regenerates these procedures automatically by calling the same set of internal scripting procedures so that the new procedures match the new schema (replication of schema changes isn't supported for Oracle Publishers).
26
+
27
+
You can also specify custom procedures to replace one or more of the default procedures. The custom procedures should be changed if the schema change affects the procedure. For example, if a procedure references a column that is dropped in a schema change, references to the column should be removed from the procedure.
28
+
29
+
There are two ways for replication to propagate a new custom procedure to Subscribers:
30
+
31
+
- Use a custom scripting procedure to replace the defaults used by replication
32
+
- Use a script that contains a new custom procedure definition
33
+
34
+
## Use a custom scripting procedure to replace the defaults used by replication
35
+
36
+
When you execute [sp_addarticle](../../system-stored-procedures/sp-addarticle-transact-sql.md), ensure the *@schema_option*`0x02` bit is to `true`.
37
+
38
+
> [!NOTE]
39
+
> The custom stored procedure definition must be scripted using dynamic Transact-SQL, inside a wrapper stored procedure. This wrapper stored procedure must also include an *@artid* parameter of type **int**, to ensure that it's created on the Subscriber.
40
+
41
+
Execute [sp_register_custom_scripting](../../system-stored-procedures/sp-register-custom-scripting-transact-sql.md) and specify a value of `insert`, `update`, or `delete` for the *@type* parameter, and the name of the custom scripting procedure for the *@value* parameter.
42
+
43
+
The next time a schema change is made, replication calls this stored procedure to script out the definition for the new user defined custom stored procedure, and then propagates the procedure to each Subscriber.
44
+
45
+
### Example
46
+
47
+
In this example, assume that the Publisher and Subscriber are already configured, and you want to create a custom `delete` stored procedure.
48
+
49
+
1. On the Subscriber, create a table to showcase the custom delete script.
50
+
51
+
```sql
52
+
USE [SubscriberDB];
53
+
GO
54
+
55
+
CREATETABLEDeleteLogging (id INTPRIMARY KEY);
56
+
GO
57
+
```
58
+
59
+
1. Add the article from the Publisher. Note the values of the `@schema_option`, `@ins_cmd`, `@upd_cmd`, and `@del_cmd` parameters:
1. Create a stored procedure that scripts out the `custom_delete` stored procedure you want to use on the Subscriber. This is the wrapper stored procedure, as indicated previously.
85
+
86
+
Returning non-zero values from this stored procedure results in `custom_delete` not being created on the Subscriber. The `SELECT` should return the full `CREATE` definition of the stored procedure that will be used on the Subscriber.
87
+
88
+
Note the use of the required `@artid` parameter.
89
+
90
+
```sql
91
+
USE [PublisherDB];
92
+
GO
93
+
94
+
CREATE OR ALTER PROCEDURE script_custom_delete (@artid INT)
95
+
AS
96
+
BEGIN
97
+
SELECT'CREATE OR ALTER PROCEDURE custom_delete
98
+
@pkc1 INT
99
+
AS
100
+
BEGIN
101
+
INSERT INTO DeleteLogging (id) VALUES (@pkc1)
102
+
END';
103
+
RETURN 0;
104
+
END
105
+
GO
106
+
```
107
+
108
+
1. Register the custom script on the Publisher.
109
+
110
+
```sql
111
+
USE [PublisherDB];
112
+
GO
113
+
114
+
EXECUTE sp_register_custom_scripting
115
+
@type ='delete',
116
+
@value ='script_custom_delete',
117
+
@publication ='PubName1',
118
+
@article ='Purchases';
119
+
GO
120
+
```
121
+
122
+
1. Add a subscription. In this example, the `@sync_type` parameter is set to `replication support only`, so no snapshot is used.
123
+
124
+
```sql
125
+
USE [PublisherDB];
126
+
GO
127
+
128
+
EXECUTE sp_addsubscription
129
+
@publication = N'PubName1',
130
+
@subscriber = @@SERVERNAME,
131
+
@destination_db = N'SubscriberDB',
132
+
@subscription_type = N'Push',
133
+
@sync_type = N'replication support only',
134
+
@article = N'all',
135
+
@update_mode = N'read only',
136
+
@subscriber_type =0;
137
+
GO
138
+
```
139
+
140
+
## Use a script that contains a new custom procedure definition
141
+
142
+
When you execute [sp_addarticle](../../system-stored-procedures/sp-addarticle-transact-sql.md), set the *@schema_option*`0x02` bit to `false` so replication doesn't automatically generate custom procedures at the Subscriber.
143
+
144
+
Before each schema change, create a new script file and register the script with replication by executing [sp_register_custom_scripting](../../system-stored-procedures/sp-register-custom-scripting-transact-sql.md). Specify a value of `custom_script` for the *@type* parameter, and the path to the script on the Publisher for the *@value* parameter.
145
+
146
+
The next time a relevant schema change is made, this script executes on each Subscriber within the same transaction as the DDL command. After the schema change is made, the script is unregistered. You must re-register the script to have it execute after a subsequent schema change.
147
+
40
148
## Related content
41
149
42
-
-[Specify How Changes Are Propagated for Transactional Articles](../../../relational-databases/replication/transactional/transactional-articles-specify-how-changes-are-propagated.md)
43
-
-[Make Schema Changes on Publication Databases](../../../relational-databases/replication/publish/make-schema-changes-on-publication-databases.md)
150
+
-[Transactional Articles - Specify How Changes Are Propagated](transactional-articles-specify-how-changes-are-propagated.md)
151
+
-[Make Schema Changes on Publication Databases](../publish/make-schema-changes-on-publication-databases.md)
Copy file name to clipboardExpand all lines: docs/relational-databases/system-stored-procedures/sp-register-custom-scripting-transact-sql.md
+2-2Lines changed: 2 additions & 2 deletions
Display the source diff
Display the rich diff
Original file line number
Diff line number
Diff line change
@@ -4,7 +4,7 @@ description: sp_register_custom_scripting registers a stored procedure or Transa
4
4
author: markingmyname
5
5
ms.author: maghan
6
6
ms.reviewer: randolphwest
7
-
ms.date: 08/22/2024
7
+
ms.date: 04/21/2025
8
8
ms.service: sql
9
9
ms.subservice: replication
10
10
ms.topic: "reference"
@@ -74,7 +74,7 @@ Name of the article for which the custom stored procedure or script is being reg
74
74
75
75
`sp_register_custom_scripting` is used in snapshot and transactional replication.
76
76
77
-
This stored procedure should be executed before making a schema change to a replicated table. For more information about using this stored procedure, see [Transactional Articles - Regenerate to Reflect Schema Changes](../replication/transactional/transactional-articles-regenerate-to-reflect-schema-changes.md).
77
+
This stored procedure should be executed before making a schema change to a replicated table. For more information about using this stored procedure, see [Transactional articles - Regenerate custom procedures to reflect schema changes](../replication/transactional/transactional-articles-regenerate-to-reflect-schema-changes.md).
0 commit comments