An example using a local pending table

The pending table is a design enhancement of applied and request functions that allows clients at a remote site to update central data and see the updates at the remote site before they are returned from the central site. Use this model to implement local update applications.

In this strategy, a client application at a remote site executes a user stored procedure that updates data at the central site using a request function. Changes to the central data are replicated to the remote site via an applied function. A local pending table lets clients at the remote site see updates that are pending at the remote site before the replication system returns the updates.

When a client application executes the user stored procedure at the remote data server, it:

When the update succeeds at the central database, it is distributed to the remote sites, including the site where the transaction originated. At the remote site, a stored procedure updates the replicated table and deletes the corresponding updates from the pending table.

To use applied functions, request functions, and a local pending table, you must complete these tasks.

At the remote site:

At the primary site:

In this example, a client application at the remote (Sydney) site executes a stored procedure upd_publishers_pubs2_req, which inserts values in the publishers_pend table and causes an associated stored procedure, upd_publishers_pubs2, to execute at the central (Tokyo) site. Execution of upd_publishers_pubs2 at the central site causes the stored procedure upd_publishers_pubs to execute at the remote site, which updates the publishers table and deletes the corresponding information from the publishers_pend table.

Figure 3-12 illustrates the data flow when you use applied functions, request functions, and a local pending table. The gray arrows show the flow of the request function delivery. The black arrows show the flow of the applied function delivery.

Figure 3-12: Request functions and a local pending table

Figure 3-13 illustrates the data flow when you use applied functions, request functions, and a local pending table. A client application at a remote site executes a user stored procedure that updates data at the primary site using a request function. Changes to the primary data are replicated to the remote site via an applied function. A local pending table lets clients at the remote site see updates that are pending at the replicate site before the replication system returns the updates.

Pending table

This script creates a pending table in the remote database.

-- Execute this script at Sydney data server
-- Creates local pending table 
create table publishers_pend
(pub_id char(4) not null,
 pub_name varchar(40) null,
 city varchar(20) null,
 statechar(2) null)
go
/* end of script */

Stored procedures

The script creates the stored procedure upd_publisher_pubs2 at the central (Tokyo) site:

-- Execute this script at Tokoyo data server
-- Creates stored procedure
create procedure upd_publishers_pubs2
(@pub_id char(4),
 @pub_name varchar(40),
 @city varchar(20),
 @state char(2))
as
   insert into publishers
   values (@pub_id, @pub_name, @city, @state)
go
/* end of script */

The following script creates the upd_publishers_pub2_req stored procedure at the remote (Sydney) site. The insert into clause inserts values into the publishers_pend table.

-- Execute this script at Sydney data server
-- Creates stored procedure 
create procedure upd_publishers_pubs2_req
(@pub_id char(4),
 @pub_name varchar(40),
 @city varchar(20),
 @state char(2))
as
    insert into publishers_pend
    values (@pub_id, @pub_name, @city, @state)
go
/* end of script */

This script creates the upd_publishers_pubs2 procedure for the remote (Sydney) site. It updates the publishers table and deletes the corresponding information from the publishers_pend table.

-- Execute this script at Sydney data server
-- Creates stored procedure upd_publishers_pubs2
 create procedure upd_publishers_pubs2
 (@pub_id char(4),
 @pub_name varchar(40),
 @city varchar(20),
 @state char(2))
 as
 update publishers
 set
    pub_name = @pub_name,
    city = @city,
    state = @state
 where
    pub_id = @pub_id
 delete from publishers_pend
 where 
    pub_id = @pub_id
 go
 /* end of script */

Function replication definitions

This script creates the applied function replication definition at the central (Tokyo) Replication Server:

-- Execute this script at Tokyo Replication Server
-- Creates replication definition
create applied function replication definition
   upd_publishers_pubs2
with primary at TOKYO_DS.pubs2
(@pub_id char(4),
 @pub_name varchar(40),
 @city varchar(20),
 @state char(2))
go
/* end of script */

This script creates the request function replication definition at the remote (Sydney) Replication Server:

-- Execute this script at Sydney Replication Server
-- Creates replication definition
create request function replication definition
   upd_publishers_pubs2_req
with primary at SYDNEY_DS.pubs2
with primary function named upd_publishers_pubs2_req
with replicate function named upd_publishers_pubs2
(@pub_id char(4),
 @pub_name varchar(40),
 @city varchar(20),
 @state char(2))
go
/* end of script */

Subscription

This script creates a subscription at the remote Replication Server using the no-materialization method for the applied function replication definition defined at the central Replication Server:

-- Execute this script at Sydney Replication Server
-- Creates subscription using no-materialization
for upd_publishers_pubs2
create subscription upd_publishers_pubs2_sub
for upd_publishers_pubs2
with replicate at SYDNEY_DS.pubs2
without materialization
go
/* end of script */

This script creates a subscription at the central Replication Server using the no-materialization method for the request function replication definition defined at the remote Replication Server.

-- Execute this script at Tokoyo Replication Server
-- Creates subscription using no-materialization
for upd_publishers_pubs2_req
create subscription upd_publishers_pubs2_req_sub
for upd_publishers_pubs2_req
with replicate at TOKOYO_DS.pubs2
without materialization
go
/* end of script */