Try OpenEdge Now
skip to main content
SQL Development
Change Data Capture : Use cases : Getting change data values driven by a source table row
 

Getting change data values driven by a source table row

When the table Policy defines change tracking as Level 0 or Level 1, the Change table contains change values as determined by the CDC table and Field policy selected by the user. In this use case, the application is looking for any possible changes for an identified source table row R. The application identifies the source table row R using application-specific criteria. Any changes that exist for that specific source table row R are found in the CDC tables, and then handled for row R. This is done in 3 steps.
In Step 1, the source table row R is identified using the RowID of row R. In this step, the details that are fetched are the RowID(RecID) and any partition ID of the source table row R. The partition ID information is needed if the source table is either Multi-tenant or if it is table Partitioned.
select rowid, pro_get_partid(pro_partn_rowid)
from my_source_table S
where my_key1 = <some value>
and my_key2 = <some value>
and my_column = <some value>;
-- Result Set values are saved for use in query below.
Step 2 on the CDC tables gets the source table number. It verifies whether Change tracking is active for source table by checking for an active CDC table Policy for the source table.
select f."_File-Number"
from pub.”_File” f
inner join
pub."_CDC-Table-Policy" tp
on f.rowid = tp.”_Source-File-Recid”
and tp."_Policy-Instance" = 0 -- Policy is current.
where f."_file-name" = ‘customer’
and f."_Owner" = ‘pub’ ;
Note: This step can be skipped if the source table number has been already obtained by the application numerous times.
Step 3 uses a query which gives a Result Set of the set of change values for each source table row R from the preliminary query, in change sequence order.
select c.* -- specify change table fields here.
from pub."_Cdc-Change-Tracking" ct
inner join
pub.CDC_Customer c -- well-known Change table name.
on ct."_Change-Sequence" = c."_Change-Sequence"
where ct.”_Source-Table-Number" = ? -- from 2nd query.
and ct."_Partition-Id" = ? -- partition id from preliminary query.
and ct."_Recid" = ? -- recid from preliminary query.
and c."_Operation" != 3 -- optional - exclude Before Update images.
order by ct.”_Source-Table-Number", ct."_Partition-Id", ct."_Recid",
ct."_Change-Sequence" ;
-- Order By keys map to index _Part-Rec-Id and should skip sorting.
These changes could be Insert, Delete, or Update operations and the application logic can decide how to transfer each change to the Data Warehouse. Step 1 and Step 2 of the query can be embedded inside an application in nested loops as shown in the following table:
Query #1
save rowid, partitioned for row R
query #2
build query #3
do
query #3
exitloop if no data
accumulate type of changes, aggregate changes, to Source row
send changed Source row values to Data Warehouse.
enddo