16.5 Assigning Resolution Methods with DBMS_REPCATOnce you have configured your column, priority, and/or site priority groups, you can assign conflict resolution techniques to your replicated tables. 16.5.1 About Resolution MethodsIn addition to column groups, priority groups, and site priority groups, the advanced replication option includes eleven other built-in resolution methods to handle update and uniqueness conflicts (see Table 16.14 ). You can also write your own resolution handlers. In particular, if you require a delete conflict handler, you must write your own because Oracle does not supply one.
You'll use the following procedures to manipulate the conflict resolution methods associated with a given table:
<conflicttype> can be UPDATE, UNIQUE, or DELETE. Therefore, the complete set of procedures in this category follows:
16.5.1.1 The DBMS_REPCAT.ADD_<conflicttype>_RESOLUTIONThe ADD_<conflicttype>_RESOLUTION procedure adds a conflict resolution type to a table. The value of <conflicttype> can be UPDATE, UNIQUE, or DELETE. Here are the specifications: PROCEDURE DBMS_REPCAT.ADD_UPDATE_RESOLUTION (sname IN VARCHAR2, oname IN VARCHAR2, column_group IN VARCHAR2, sequence_no IN NUMBER, method IN VARCHAR2, {parameter_column_name IN dbms_repcat.varchar2s,| parameter_column_name IN VARCHAR2,} priority_group IN VARCHAR2 := NULL, function_name IN VARCHAR2 := NULL, comment IN VARCHAR2 := NULL); PROCEDURE DBMS_REPCAT.ADD_UNIQUE_RESOLUTION (sname IN VARCHAR2, oname IN VARCHAR2, constraint_name IN VARCHAR2, sequence_no IN NUMBER, method IN VARCHAR2, {parameter_column_name IN dbms_repcat.varchar2s, | parameter_column_name IN VARCHAR2,} comment IN VARCHAR2 := NULL); PROCEDURE DBMS_REPCAT.ADD_DELETE_RESOLUTION (sname IN VARCHAR2, oname IN VARCHAR2, sequence_no IN NUMBER, {parameter_column_name IN dbms_repcat.varchar2s, | parameter_column_name IN VARCHAR2,} function_name IN VARCHAR2 := NULL, comment IN VARCHAR2 := NULL); Parameters are summarized in the following table.
16.5.1.1.1 ExceptionThe ADD_<conflicttype>RESOLUTION procedure may raise the following exceptions:
16.5.1.1.2 RestrictionsNote the following restrictions on calling ADD_<conflicttype>_RESOLUTION:
16.5.1.1.3 ExamplesThe following examples illustrate how to assign various conflict resolution methods to replicated tables. These examples use the products table used in earlier examples; for convenience, we've included its description here again. Sql>desc products Name Null? Type --------------------- --------- --- PRODUCT_ID NOT NULL NUMBER(9) PRODUCT_TYPE NOT NULL NUMBER(6) CATALOG_ID NOT NULL VARCHAR2(15) DESCRIPTION NOT NULL VARCHAR2(30) REV_LEVEL NOT NULL VARCHAR2(15) PRODUCTION_DATE NOT NULL DATE PRODUCTION_STATUS NOT NULL VARCHAR2(12) AUDIT_DATE NOT NULL DATE AUDIT_USER NOT NULL VARCHAR2(30) GLOBAL_NAME NOT NULL VARCHAR2(20) 16.5.1.1.4 Examples of ADD_UPDATE_RESOLUTIONAssume that we have created a priority group PG_PRODUCTION_STATUS and have designated priorities to the full range of values for the column PRODUCTION_STATUS. The following call implements this priority group as the conflict handler that Oracle invokes first (because sequence_no = 1) when an update conflict occurs. BEGIN DBMS_REPCAT.ADD_UPDATE_RESOLUTION( sname => 'SPROCKET', oname => 'PRODUCTS', sequence_no => 1, method => 'PRIORITY GROUP', priority_group => 'PG_PRODUCTION_STATUS', comment => 'Update Res. 1 added on '||sysdate); END; This next call assigns the column group CG_PRODUCT_MFG_COLS as the second update conflict resolution handler for table products. Oracle invokes this resolution method if and only if the first method failed to resolve the conflict. BEGIN DBMS_REPCAT.ADD_UPDATE_RESOLUTION( sname => 'SPROCKET', oname => 'PRODUCTS', colunn_group => 'CG_PRODUCT_PRICE_COLS', method => 'LATEST TIMESTAMP', parameter_column_name => 'PRODUCTION_DATE', comment => 'Update Res. 2 added on '||sysdate); END; The following example assigns a third update conflict resolution handler to the products table. This handler would simply ignore an update if the first two conflict handlers failed to resolve it. BEGIN DBMS_REPCAT.ADD_UPDATE_RESOLUTION( sname => 'SPROCKET', oname => 'PRODUCTS', sequence_no => 3, method => 'DISCARD', comment => 'Update Res. 3 added on '||sysdate); END; 16.5.1.1.5 Examples of ADD_UNIQUE_RESOLUTIONUniqueness conflicts may occur during inserts; for example, two different sites may insert a record with the same primary key. While you can guard against this sort of conflict by partitioning primary key values among your sites, this design is not always possible. Note that if you wish to use the APPEND SITE NAME or APPEND SEQUENCE NUMBER methods, the column with the unique constraint must specify a character datatype (CHAR or VARCHAR2). This choice of datatype may not be appropriate for a primary key column. The following example configures the products table to discard records that result in uniqueness conflicts: BEGIN DBMS_REPCAT.ADD_UNIQUE_RESOLUTION( sname => 'SPROCKET', oname => 'PRODUCTS', constraint_name => 'PK_PRODUCTS', sequence_no => 1, method => 'DISCARD', parameter_column => 'PRODUCT_ID', comment => 'Unique Res. 1 added on '||sysdate); END; 16.5.1.1.6 Examples of ADD_DELETE_RESOLUTIONAs we have mentioned, Oracle does not provide any built-in conflict resolution techniques for delete conflicts. In fact, Oracle recommends that applications that use the advanced replication option avoid delete entirely, and simply use a status column to flag records as deleted. However, if you must delete rows, you can write your own conflict resolution method and assign it to your table. See the Section 16.5.1.1.7, "User-defined methods" " section later in this chapter. The following function serves as a delete conflict handler for the products table. It forces a delete against the table. CREATE OR REPLACE FUNCTION products_delete_handler ( old_product_id IN OUT NUMBER, Old_product_type IN OUT NUMBER, old_catalog_id IN OUT VARCHAR2, old_description IN OUT VARCHAR2, old_rev_level IN OUT VARCHAR2, old_production_date IN OUT DATE, old_production_status IN OUT VARCHAR2, old_audit_date IN OUT DATE, old_audit_user IN OUT VARCHAR2, old_global_name IN OUT VARCHAR2, ignore_discard_flag OUT BOOLEAN ) RETURN BOOLEAN IS BEGIN DELETE FROM products WHERE product_id = old_product_id; ignore_discard_flag := TRUE; RETURN TRUE; END products_delete_handler; This final example designates the function products_delete_handler from the previous example and a user-defined delete conflict handler for the PRODUCTS_TABLE: DECLARE param_col_list DBMS_REPCAT.VARCHAR2S; BEGIN param_col_list( 1) := 'PRODUCT_ID'; param_col_list( 2) := 'PRODUCT_TYPE'; param_col_list( 3) := 'CATALOG_ID'; param_col_list( 4) := 'DESCRIPTION'; param_col_list( 5) := 'REV_LEVEL'; param_col_list( 6) := 'PRODUCTION_DATE'; param_col_list( 7) := 'PRODUCTION_STATUS', param_col_list( 8) := 'AUDIT_DATE', param_col_list( 9) := 'AUDIT_USER', param_col_list(10) := 'GLOBAL_NAME', DBMS_REPCAT.ADD_DELETE_RESOLUTION( sname => 'SPROCKET', oname => 'PRODUCTS', sequence_no => 1, paramekter_column_name => param_col_list, function_name => 'PRODUCTS_DELETE_HANDLER', comment => 'Del handler 1 added on ' || sysdate); END;
16.5.1.1.7 User-defined methodsUser-defined methods must meet the following criteria:
16.5.1.2 The DBMS_REPCAT.DROP_<conflicttype>_RESOLUTION procedureThe DROP_<conflicttype>_RESOLUTION procedure removes a conflict resolution type from a table. The value of <conflicttype> can be UPDATE, UNIQUE, DELETE. Here are the specifications: PROCEDURE DBMS_REPCAT.DROP_UPDATE_RESOLUTION (sname IN VARCHAR2, oname IN VARCHAR2, column_group IN VARCHAR2, sequence_no IN NUMBER) ; PROCEDURE DBMS_REPCAT.DROP_UNIQUE_RESOLUTION (sname IN VARCHAR2, oname IN VARCHAR2, constraint_name IN VARCHAR2, sequence_no IN NUMBER) ; PROCEDURE DBMS_REPCAT.DROP_DELETE_RESOLUTION (sname IN VARCHAR2, oname IN VARCHAR2, sequence_no IN NUMBER) ; Parameters are summarized in the following table.
16.5.1.2.1 ExceptionsThe DROP_<conflicttype>_RESOLUTION procedure may raise the following exceptions:
16.5.1.2.2 RestrictionsNote these restrictions on calling DROP_<conflicttype>_RESOLUTION:
16.5.1.2.3 ExampleIn this example we drop the delete handler (created in a previous example) from the products table: BEGIN DBMS_REPCAT.DROP_DELETE_RESOLUTION( sname => 'SPROCKETS', oname => 'PRODUCTS', sequence_no => 1); END; 16.5.1.3 The DBMS_REPCAT.COMMENT_ON_<conflicttype>_RESOLUTION procedureYou can use the COMMENT_ON_<conflicttype>_RESOLUTION procedure to create or replace a comment for a given resolution type. You can see this comment in the DBA_REPRESOLUTION data dictionary view. Following are the specifications for the three values of <conflicttype> (UPDATE, UNIQUE, DELETE): PROCEDURE DBMS_REPCAT.COMMENT_ON_UPDATE_RESOLUTION (sname IN VARCHAR2, oname IN VARCHAR2, column_group IN VARCHAR2, sequence_no IN NUMBER, comment IN VARCHAR2); PROCEDURE DBMS_REPCAT.COMMENT_ON_UNIQUE_RESOLUTION (sname IN VARCHAR2, oname in VARCHAR2, constraint_name IN VARCHAR2, sequence_no IN NUMBER, comment IN VARCHAR2) ; PROCEDURE DBMS_REPCAT.COMMENT_ON_DELETE_RESOLUTION (sname IN VARCHAR2, oname IN VARCHAR2, sequence_no IN NUMBER, comment IN VARCHAR2) ; Parameters are summarized in the following table.
16.5.1.3.1 ExceptionsThe COMMENT_ON_<conflicttype>_RESOLUTION procedure may raise the following exceptions:
16.5.1.3.2 RestrictionsNote the following restrictions on calling COMMENT_ON_ < conflicttype>_RESOLUTION:
16.5.1.3.3 ExampleThis example replaces the comment on the unique resolution method created in a previous example: BEGIN DBMS_REPCAT.COMMENT_ON_UNIQUE_RESOLUTION( sname => 'SPROCKET', oname => 'PRODUCTS', constraint_name => 'PK_PRODUCTS', sequence_no => 1, comment => 'New comment added on '||sysdate); END; Copyright (c) 2000 O'Reilly & Associates. All rights reserved. | ||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||
|