| Oracle® Streams Replication Administrator's Guide 10g Release 1 (10.1) Part Number B10728-01 |
|
|
View PDF |
This chapter illustrates an example of a single source heterogeneous replication environment that can be constructed using Streams, as well as the tasks required to add new objects and databases to such an environment.
This chapter contains these topics:
This example illustrates using Streams to replicate data between four databases. The environment is heterogeneous because three of the databases are Oracle databases and one is a Sybase database. DML and DDL changes made to tables in the hr schema at the dbs1.net Oracle database are captured and propagated to the other two Oracle databases. Only DML changes are captured and propagated to the dbs4.net database, because an apply process cannot apply DDL changes to a non-Oracle database. Changes to the hr schema occur only at dbs1.net. The hr schema is read-only at the other databases in the environment.
Figure 13-1 provides an overview of the environment.
Text description of the illustration strep002.gif
As illustrated in Figure 13-1, dbs1.net contains the following tables in the hr schema:
This example uses directed networks, which means that captured changes at a source database are propagated to another database through one or more intermediate databases. Here, the dbs1.net database propagates changes to the dbs3.net database through the intermediate database dbs2.net. This configuration is an example of queue forwarding in a directed network. Also, the dbs1.net database propagates changes to the dbs2.net database, which applies the changes directly to the dbs4.net database through a gateway.
Some of the databases in the environment do not have certain tables. If the database is not an intermediate database for a table and the database does not contain the table, then changes to the table do not need to be propagated to that database. For example, the departments, employees, job_history, and jobs tables do not exist at dbs3.net. Therefore, dbs2.net does not propagate changes to these tables to dbs3.net.
In this example, Streams is used to perform the following series of actions:
hr schema and enqueues them into a queue at the dbs1.net database. In this example, changes to only four of the seven tables are propagated to destination databases, but in the example that illustrates "Add Objects to an Existing Streams Replication Environment", the remaining tables in the hr schema are added to a destination database.dbs1.net database propagates these changes in the form of messages to a queue at dbs2.net.dbs2.net, DML changes to the jobs table are transformed into DML changes for the assignments table (which is a direct mapping of jobs) and then applied. Changes to other tables in the hr schema are not applied at dbs2.net.dbs3.net receives changes from the queue at dbs2.net that originated in countries, locations, and regions tables at dbs1.net, these changes are propagated from dbs2.net to dbs3.net. This configuration is an example of directed networks.dbs3.net applies changes to the countries, locations, and regions tables.dbs4.net, a Sybase database, receives changes from the queue at dbs2.net to the jobs table that originated at dbs1.net, these changes are applied remotely from dbs2.net using the dbs4.net database link through a gateway. This configuration is an example of heterogeneous support.The following prerequisites must be completed before you begin the example in this chapter.
GLOBAL_NAMES: This parameter must be set to true at each database that is participating in your Streams environment.JOB_QUEUE_PROCESSES: This parameter must be set to at least 2 at each database that is propagating events in your Streams environment. It should be set to the same value as the maximum number of jobs that can run simultaneously plus one. In this example, dbs1.net and dbs2.net propagate events. So, JOB_QUEUE_PROCESSES must be set to at least 2 at these databases.COMPATIBLE: This parameter must be set to 10.1.0 or higher.STREAMS_POOL_SIZE: Optionally set this parameter to an appropriate value for each database in the environment. This parameter specifies the size of the Streams pool. The Streams pool contains captured events. In addition, the Streams pool is used for internal communications during parallel capture and apply. If STREAMS_POOL_SIZE is set to zero (the default), then Streams uses the shared pool. In this case, you may need to increase the size of the shared pool at each database.
| See Also:
Oracle Streams Concepts and Administration for information about other initialization parameters that are important in a Streams environment |
ARCHIVELOG mode. In this example, changes are produced at dbs1.net, and so dbs1.net must be running in ARCHIVELOG mode.
| See Also:
Oracle Database Administrator's Guide for information about running a database in |
dbs2.net to communicate with the Sybase database dbs4.net.
dbs4.net, set up the hr user.
hr.jobs table from the dbs1.net Oracle database at the dbs4.net Sybase database.
strmadmin) at each database and prompts you for the tablespace you want to use for this user's data. Before you start this example, either create a new tablespace or identify an existing tablespace for the Streams administrator to use at each database. The Streams administrator should not use the SYSTEM tablespace.Complete the following steps to set up users and create queues and database links for a Streams replication environment that includes three Oracle databases and one Sybase database.
/************************* BEGINNING OF SCRIPT ******************************
Run SET ECHO ON and specify the spool file for the script. Check the spool file for errors after you run this script.
*/ SET ECHO ON SPOOL streams_setup_single.out /*
Connect to dbs1.net as SYS user.
*/ CONNECT SYS/CHANGE_ON_INSTALL@dbs1.net AS SYSDBA /*
Create the Streams administrator named strmadmin and grant this user the necessary privileges. These privileges enable the user to manage queues, execute subprograms in packages related to Streams, create rule sets, create rules, and monitor the Streams environment by querying data dictionary views and queue tables. You may choose a different name for this user.
| See Also:
Oracle Streams Concepts and Administration for more information about configuring a Streams administrator |
*/ GRANT CONNECT, RESOURCE, DBA, SELECT_CATALOG_ROLE TO strmadmin IDENTIFIED BY strmadminpw; ACCEPT streams_tbs PROMPT 'Enter Streams administrator tablespace on dbs1.net: ' ALTER USER strmadmin DEFAULT TABLESPACE &streams_tbs QUOTA UNLIMITED ON &streams_tbs; /*
Connect as the Streams administrator at the database where you want to capture changes. In this example, that database is dbs1.net.
*/ CONNECT strmadmin/strmadminpw@dbs1.net /*
Run the SET_UP_QUEUE procedure to create a queue named streams_queue at dbs1.net. This queue will function as the SYS.AnyData queue by holding the captured changes that will be propagated to other databases.
Running the SET_UP_QUEUE procedure performs the following actions:
streams_queue_table. This queue table is owned by the Streams administrator (strmadmin) and uses the default storage of this user.streams_queue owned by the Streams administrator (strmadmin).*/ EXEC DBMS_STREAMS_ADM.SET_UP_QUEUE(); /*
Create the database link from the database where changes are captured to the database where changes are propagated. In this example, the database where changes are captured is dbs1.net, and these changes are propagated to dbs2.net.
*/ CREATE DATABASE LINK dbs2.net CONNECT TO strmadmin IDENTIFIED BY strmadminpw USING 'dbs2.net'; /*
Connect to dbs2.net as SYS user.
*/ CONNECT SYS/CHANGE_ON_INSTALL@dbs2.net AS SYSDBA /*
Create the Streams administrator named strmadmin and grant this user the necessary privileges. These privileges enable the user to manage queues, execute subprograms in packages related to Streams, create rule sets, create rules, and monitor the Streams environment by querying data dictionary views and queue tables. You may choose a different name for this user.
| See Also:
Oracle Streams Concepts and Administration for more information about configuring a Streams administrator |
*/ GRANT CONNECT, RESOURCE, DBA, SELECT_CATALOG_ROLE TO strmadmin IDENTIFIED BY strmadminpw; ACCEPT streams_tbs PROMPT 'Enter Streams administrator tablespace on dbs2.net: ' ALTER USER strmadmin DEFAULT TABLESPACE &streams_tbs QUOTA UNLIMITED ON &streams_tbs; /*
Connect as the Streams administrator at dbs2.net.
*/ CONNECT strmadmin/strmadminpw@dbs2.net /*
Run the SET_UP_QUEUE procedure to create a queue named streams_queue at dbs2.net. This queue will function as the SYS.AnyData queue by holding the changes that will be applied at this database and the changes that will be propagated to other databases.
Running the SET_UP_QUEUE procedure performs the following actions:
streams_queue_table. This queue table is owned by the Streams administrator (strmadmin) and uses the default storage of this user.streams_queue owned by the Streams administrator (strmadmin).*/ EXEC DBMS_STREAMS_ADM.SET_UP_QUEUE(); /*
Create the database links to the databases where changes are propagated. In this example, database dbs2.net propagates changes to dbs3.net, which is another Oracle database, and to dbs4.net, which is a Sybase database. Notice that the database link to the Sybase database connects to the owner of the tables, not to the Streams administrator. This database link can connect to any user at dbs4.net that has privileges to change the hr.jobs table at that database.
*/ CREATE DATABASE LINK dbs3.net CONNECT TO strmadmin IDENTIFIED BY strmadminpw USING 'dbs3.net'; CREATE DATABASE LINK dbs4.net CONNECT TO "hr" IDENTIFIED BY "hrpass" USING 'dbs4.net'; /*
This example illustrates a rule-based transformation in which changes to the hr.jobs table at dbs1.net are transformed into changes to the hr.assignments table at dbs2.net. You must create the hr.assignments table on dbs2.net for the transformation portion of this example to work properly.
Connect as hr at dbs2.net.
*/ CONNECT hr/hr@dbs2.net /*
Create the hr.assignments table in the dbs2.net database.
*/ CREATE TABLE hr.assignments AS SELECT * FROM hr.jobs; ALTER TABLE hr.assignments ADD PRIMARY KEY (job_id); /*
Connect to dbs3.net as SYS user.
*/ CONNECT SYS/CHANGE_ON_INSTALL@dbs3.net AS SYSDBA /*
Create the Streams administrator named strmadmin and grant this user the necessary privileges. These privileges enable the user to manage queues, execute subprograms in packages related to Streams, create rule sets, create rules, and monitor the Streams environment by querying data dictionary views and queue tables. You may choose a different name for this user.
| See Also:
Oracle Streams Concepts and Administration for more information about configuring a Streams administrator |
*/ GRANT CONNECT, RESOURCE, DBA, SELECT_CATALOG_ROLE TO strmadmin IDENTIFIED BY strmadminpw; ACCEPT streams_tbs PROMPT 'Enter Streams administrator tablespace on dbs3.net: ' ALTER USER strmadmin DEFAULT TABLESPACE &streams_tbs QUOTA UNLIMITED ON &streams_tbs; /*
Connect as the Streams administrator at dbs3.net.
*/ CONNECT strmadmin/strmadminpw@dbs3.net /*
Run the SET_UP_QUEUE procedure to create a queue named streams_queue at dbs3.net. This queue will function as the SYS.AnyData queue by holding the changes that will be applied at this database.
Running the SET_UP_QUEUE procedure performs the following actions:
streams_queue_table. This queue table is owned by the Streams administrator (strmadmin) and uses the default storage of this user.streams_queue owned by the Streams administrator (strmadmin).*/ EXEC DBMS_STREAMS_ADM.SET_UP_QUEUE(); /*
Create a database link from dbs3.net to dbs1.net. Later in this example, this database link is used for the instantiation of some of the database objects that were dropped in Step 12. This example uses the DBMS_DATAPUMP package to perform a network import of these database objects directly from the dbs1.net database. Because this example performs a network import, no dump file is required.
Alternatively, you can perform an export at the source database dbs1.net, transfer the export dump file to the destination database dbs3.net, and then import the export dump file at the destination database. In this case, the database link created in this step is not required.
*/ CREATE DATABASE LINK dbs1.net CONNECT TO strmadmin IDENTIFIED BY strmadminpw USING 'dbs1.net'; /*
This example illustrates instantiating tables in the hr schema by importing them from dbs1.net into dbs3.net with Data Pump. You must delete these tables at dbs3.net for the instantiation portion of this example to work properly.
Connect as hr at dbs3.net.
*/ CONNECT hr/hr@dbs3.net /*
Drop all tables in the hr schema in the dbs3.net database.
*/ DROP TABLE hr.countries CASCADE CONSTRAINTS; DROP TABLE hr.departments CASCADE CONSTRAINTS; DROP TABLE hr.employees CASCADE CONSTRAINTS; DROP TABLE hr.job_history CASCADE CONSTRAINTS; DROP TABLE hr.jobs CASCADE CONSTRAINTS; DROP TABLE hr.locations CASCADE CONSTRAINTS; DROP TABLE hr.regions CASCADE CONSTRAINTS; /*
Check the streams_setup_single.out spool file to ensure that all actions finished successfully after this script is completed.
*/ SET ECHO OFF SPOOL OFF /*************************** END OF SCRIPT ******************************/
This example illustrates two ways to accomplish the replication of the tables in the hr schema using Streams.
DBMS_STREAMS_ADM package to create a capture process, propagations, and apply processes, as well as the rule sets associated with them. Using the DBMS_STREAMS_ADM package is the simplest way to configure a Streams environment.DBMS_CAPTURE_ADM package to create a capture process, the DBMS_PROPAGATION_ADM package to create propagations, and the DBMS_APPLY_ADM package to create apply processes. Also, this example uses the DBMS_RULES_ADM package to create and populate the rule sets associated with these capture processes, propagations, and apply processes. Using these packages, instead of the DBMS_STREAMS_ADM package, provides more configuration options and flexibility.
Complete the following steps to specify the capture, propagation, and apply definitions using primarily the DBMS_STEAMS_ADM package.
/************************* BEGINNING OF SCRIPT ******************************
Run SET ECHO ON and specify the spool file for the script. Check the spool file for errors after you run this script.
*/ SET ECHO ON SPOOL streams_share_schema1.out /*
Connect to dbs1.net as SYS user.
*/ CONNECT SYS/CHANGE_ON_INSTALL@dbs1.net AS SYSDBA /*
Supplemental logging places additional information in the redo log for changes made to tables. The apply process needs this extra information to perform certain operations, such as unique row identification and conflict resolution. Because dbs1.net is the only database where changes are captured in this environment, it is the only database where you must specify supplemental logging for the tables in the hr schema.
Specify an unconditional supplemental log group for all primary key columns in the hr schema.
*/ ALTER TABLE hr.countries ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.departments ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.employees ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.jobs ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.job_history ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.locations ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.regions ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; /*
Connect to dbs1.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs1.net /*
Configure and schedule propagation of DML and DDL changes in the hr schema from the queue at dbs1.net to the queue at dbs2.net.
*/ BEGIN DBMS_STREAMS_ADM.ADD_SCHEMA_PROPAGATION_RULES( schema_name => 'hr', streams_name => 'dbs1_to_dbs2', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs2.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / /*
Configure the capture process to capture changes to the entire hr schema at dbs1.net. This step specifies that changes to the tables in the specified schema are captured by the capture process and enqueued into the specified queue.
*/ BEGIN DBMS_STREAMS_ADM.ADD_SCHEMA_RULES( schema_name => 'hr', streams_type => 'capture', streams_name => 'capture', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, inclusion_rule => true); END; / /*
In this example, the hr.jobs table already exists at dbs2.net and dbs4.net. At dbs2.net, this table is named assignments, but it has the same shape and data as the jobs table at dbs1.net. Also, in this example, dbs4.net is a Sybase database. All of the other tables in the Streams environment are instantiated at the other destination databases using Data Pump import.
Because the hr.jobs table already exists at dbs2.net and dbs4.net, this example uses the GET_SYSTEM_CHANGE_NUMBER function in the DBMS_FLASHBACK package at dbs1.net to obtain the current SCN for the database. This SCN is used at dbs2.net to run the SET_TABLE_INSTANTIATION_SCN procedure in the DBMS_APPLY_ADM package. Running this procedure twice sets the instantiation SCN for the hr.jobs table at dbs2.net and dbs4.net.
The SET_TABLE_INSTANTIATION_SCN procedure controls which LCRs for a table are ignored by an apply process and which LCRs for a table are applied by an apply process. If the commit SCN of an LCR for a table from a source database is less than or equal to the instantiation SCN for that table at a destination database, then the apply process at the destination database discards the LCR. Otherwise, the apply process applies the LCR.
In this example, both of the apply processes at dbs2.net will apply transactions to the hr.jobs table with SCNs that were committed after SCN obtained in this step.
*/ DECLARE iscn NUMBER; -- Variable to hold instantiation SCN value BEGIN iscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER(); DBMS_APPLY_ADM.SET_TABLE_INSTANTIATION_SCN@DBS2.NET( source_object_name => 'hr.jobs', source_database_name => 'dbs1.net', instantiation_scn => iscn); DBMS_APPLY_ADM.SET_TABLE_INSTANTIATION_SCN@DBS2.NET( source_object_name => 'hr.jobs', source_database_name => 'dbs1.net', instantiation_scn => iscn, apply_database_link => 'dbs4.net'); END; / /*
This example performs a network Data Pump import of the following tables:
A network import means that Data Pump imports these tables from dbs1.net without using an export dump file.
| See Also:
Oracle Database Utilities for information about performing an import |
Connect to dbs3.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs3.net /*
This example will do a table import using the DBMS_DATAPUMP package. For simplicity, exceptions from any of the API calls will not be trapped. However, Oracle recommends that you define exception handlers and call GET_STATUS to retrieve more detailed error information if a failure occurs. If you want to monitor the import, then query the DBA_DATAPUMP_JOBS data dictionary view at the import database.
*/ SET SERVEROUTPUT ON SIZE 1000000 DECLARE h1 NUMBER; -- Data Pump job handle sscn NUMBER; -- Variable to hold current source SCN job_state VARCHAR2(30); -- To keep track of job state js ku$_JobStatus; -- The job status from GET_STATUS sts ku$_Status; -- The status object returned by GET_STATUS job_not_exist exception; pragma exception_init(job_not_exist, -31626); BEGIN -- Create a (user-named) Data Pump job to do a table-level import. h1 := DBMS_DATAPUMP.OPEN( operation => 'IMPORT', job_mode => 'TABLE', remote_link => 'DBS1.NET', job_name => 'dp_sing1'); -- A metadata filter is used to specify the schema that owns the tables -- that will be imported. DBMS_DATAPUMP.METADATA_FILTER( handle => h1, name => 'SCHEMA_EXPR', value => '=''HR'''); -- A metadata filter is used to specify the tables that will be imported. DBMS_DATAPUMP.METADATA_FILTER( handle => h1, name => 'NAME_EXPR', value => 'IN(''COUNTRIES'', ''REGIONS'', ''LOCATIONS'')'); -- Get the current SCN of the source database, and set the FLASHBACK_SCN -- parameter to this value to ensure consistency between all of the -- objects included in the import. sscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER@dbs1.net(); DBMS_DATAPUMP.SET_PARAMETER( handle => h1, name => 'FLASHBACK_SCN', value => sscn); -- Start the job. DBMS_DATAPUMP.START_JOB(h1); -- The import job should be running. In the following loop, the job -- is monitored until it completes. job_state := 'UNDEFINED'; BEGIN WHILE (job_state != 'COMPLETED') AND (job_state != 'STOPPED') LOOP sts:=DBMS_DATAPUMP.GET_STATUS( handle => h1, mask => DBMS_DATAPUMP.KU$_STATUS_JOB_ERROR + DBMS_DATAPUMP.KU$_STATUS_JOB_STATUS + DBMS_DATAPUMP.KU$_STATUS_WIP, timeout => -1); js := sts.job_status; DBMS_LOCK.SLEEP(10); job_state := js.state; END LOOP; -- Gets an exception when job no longer exists EXCEPTION WHEN job_not_exist THEN DBMS_OUTPUT.PUT_LINE('Data Pump job has completed'); DBMS_OUTPUT.PUT_LINE('Instantiation SCN: ' ||sscn); END; END; / /*
Connect to dbs3.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs3.net /*
Configure dbs3.net to apply changes to the countries table, locations table, and regions table.
*/ BEGIN DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.countries', streams_type => 'apply', streams_name => 'apply', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.locations', streams_type => 'apply', streams_name => 'apply', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.regions', streams_type => 'apply', streams_name => 'apply', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / /*
In this example, the hr user owns all of the database objects for which changes are applied by the apply process at this database. Therefore, hr already has the necessary privileges to change these database objects, and it is convenient to make hr the apply user.
When the apply process was created in the previous step, the Streams administrator strmadmin was specified as the apply user by default, because strmadmin ran the procedure that created the apply process. Instead of specifying hr as the apply user, you could retain strmadmin as the apply user, but then you must grant strmadmin privileges on all of the database objects for which changes are applied and privileges to execute all user procedures used by the apply process. In an environment where an apply process applies changes to database objects in multiple schemas, it may be more convenient to use the Streams administrator as the apply user.
| See Also:
Oracle Streams Concepts and Administration for more information about configuring a Streams administrator |
*/ BEGIN DBMS_APPLY_ADM.ALTER_APPLY( apply_name => 'apply', apply_user => 'hr'); END; / /*
Because the hr user was specified as the apply user in the previous step, the hr user requires execute privilege on the positive rule set used by the apply process
*/ DECLARE rs_name VARCHAR2(64); -- Variable to hold rule set name BEGIN SELECT RULE_SET_OWNER||'.'||RULE_SET_NAME INTO rs_name FROM DBA_APPLY WHERE APPLY_NAME='APPLY'; DBMS_RULE_ADM.GRANT_OBJECT_PRIVILEGE( privilege => SYS.DBMS_RULE_ADM.EXECUTE_ON_RULE_SET, object_name => rs_name, grantee => 'hr'); END; / /*
Set the disable_on_error parameter to n so that the apply process will not be disabled if it encounters an error, and start the apply process at dbs3.net.
*/ BEGIN DBMS_APPLY_ADM.SET_PARAMETER( apply_name => 'apply', parameter => 'disable_on_error', value => 'n'); END; / BEGIN DBMS_APPLY_ADM.START_APPLY( apply_name => 'apply'); END; / /*
Connect to dbs2.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs2.net /*
Configure and schedule propagation from the queue at dbs2.net to the queue at dbs3.net. You must specify this propagation for each table that will apply changes at dbs3.net. This configuration is an example of directed networks because the changes at dbs2.net originated at dbs1.net.
*/ BEGIN DBMS_STREAMS_ADM.ADD_TABLE_PROPAGATION_RULES( table_name => 'hr.countries', streams_name => 'dbs2_to_dbs3', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs3.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_PROPAGATION_RULES( table_name => 'hr.locations', streams_name => 'dbs2_to_dbs3', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs3.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_PROPAGATION_RULES( table_name => 'hr.regions', streams_name => 'dbs2_to_dbs3', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs3.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / /*
Connect to dbs2.net as the hr user.
*/ CONNECT hr/hr@dbs2.net /*
Create the rule-based transformation function that transforms row changes resulting from DML statements to the jobs table from dbs1.net into row changes to the assignments table on dbs2.net.
The following function transforms every row LCR for the jobs table into a row LCR for the assignments table.
*/ CREATE OR REPLACE FUNCTION hr.to_assignments_trans_dml( p_in_data in SYS.AnyData) RETURN SYS.AnyData IS out_data SYS.LCR$_ROW_RECORD; tc pls_integer; BEGIN -- Typecast AnyData to LCR$_ROW_RECORD tc := p_in_data.GetObject(out_data); IF out_data.GET_OBJECT_NAME() = 'JOBS' THEN -- Transform the in_data into the out_data out_data.SET_OBJECT_NAME('ASSIGNMENTS'); END IF; -- Convert to AnyData RETURN SYS.AnyData.ConvertObject(out_data); END; / /*
Connect to dbs2.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs2.net /*
Configure dbs2.net to apply changes to the assignments table. Remember that the assignments table receives changes from the jobs table at dbs1.net.
*/ DECLARE to_assignments_rulename_dml VARCHAR2(30); dummy_rule VARCHAR2(30); BEGIN -- DML changes to the jobs table from dbs1.net are applied to the assignments -- table. The to_assignments_rulename_dml variable is an out parameter -- in this call. DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.jobs', -- jobs, not assignments, specified streams_type => 'apply', streams_name => 'apply_dbs2', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => false, source_database => 'dbs1.net', dml_rule_name => to_assignments_rulename_dml, ddl_rule_name => dummy_rule, inclusion_rule => true); -- Modify the rule for the hr.jobs table to use the transformation function. DBMS_STREAMS_ADM.SET_RULE_TRANSFORM_FUNCTION( rule_name => to_assignments_rulename_dml, transform_function => 'hr.to_assignments_trans_dml'); END; / /*
In this example, the hr user owns all of the database objects for which changes are applied by the apply process at this database. Therefore, hr already has the necessary privileges to change these database objects, and it is convenient to make hr the apply user.
When the apply process was created in the previous step, the Streams administrator strmadmin was specified as the apply user by default, because strmadmin ran the procedure that created the apply process. Instead of specifying hr as the apply user, you could retain strmadmin as the apply user, but then you must grant strmadmin privileges on all of the database objects for which changes are applied and privileges to execute all user procedures used by the apply process. In an environment where an apply process applies changes to database objects in multiple schemas, it may be more convenient to use the Streams administrator as the apply user.
| See Also:
Oracle Streams Concepts and Administration for more information about configuring a Streams administrator |
*/ BEGIN DBMS_APPLY_ADM.ALTER_APPLY( apply_name => 'apply_dbs2', apply_user => 'hr'); END; / /*
Because the hr user was specified as the apply user in the previous step, the hr user requires execute privilege on the positive rule set used by the apply process
*/ DECLARE rs_name VARCHAR2(64); -- Variable to hold rule set name BEGIN SELECT RULE_SET_OWNER||'.'||RULE_SET_NAME INTO rs_name FROM DBA_APPLY WHERE APPLY_NAME='APPLY_DBS2'; DBMS_RULE_ADM.GRANT_OBJECT_PRIVILEGE( privilege => SYS.DBMS_RULE_ADM.EXECUTE_ON_RULE_SET, object_name => rs_name, grantee => 'hr'); END; / /*
Set the disable_on_error parameter to n so that the apply process will not be disabled if it encounters an error, and start the apply process for local apply at dbs2.net.
*/ BEGIN DBMS_APPLY_ADM.SET_PARAMETER( apply_name => 'apply_dbs2', parameter => 'disable_on_error', value => 'n'); END; / BEGIN DBMS_APPLY_ADM.START_APPLY( apply_name => 'apply_dbs2'); END; / /*
Configure the apply process for dbs4.net, which is a Sybase database. The dbs2.net database is acting as a gateway to dbs4.net. Therefore, the apply process for dbs4.net must be configured at dbs2.net. The apply process cannot apply DDL changes to non-Oracle databases. Therefore, the include_ddl parameter is set to false when the ADD_TABLE_RULES procedure is run.
*/ BEGIN DBMS_APPLY_ADM.CREATE_APPLY( queue_name => 'strmadmin.streams_queue', apply_name => 'apply_dbs4', apply_database_link => 'dbs4.net', apply_captured => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.jobs', streams_type => 'apply', streams_name => 'apply_dbs4', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => false, source_database => 'dbs1.net', inclusion_rule => true); END; / /*
Set the disable_on_error parameter to n so that the apply process will not be disabled if it encounters an error, and start the remote apply for Sybase using database link dbs4.net.
*/ BEGIN DBMS_APPLY_ADM.SET_PARAMETER( apply_name => 'apply_dbs4', parameter => 'disable_on_error', value => 'n'); END; / BEGIN DBMS_APPLY_ADM.START_APPLY( apply_name => 'apply_dbs4'); END; / /*
Connect to dbs1.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs1.net /*
Start the capture process at dbs1.net.
*/ BEGIN DBMS_CAPTURE_ADM.START_CAPTURE( capture_name => 'capture'); END; / /*
Check the streams_share_schema1.out spool file to ensure that all actions finished successfully after this script is completed.
*/ SET ECHO OFF SPOOL OFF /*
You can now make DML and DDL changes to specific tables at dbs1.net and see these changes replicated to the other databases in the environment based on the rules you configured for the Streams processes and propagations in this environment.
| See Also:
"Make DML and DDL Changes to Tables in the hr Schema" for examples of changes that are replicated in this environment |
/*************************** END OF SCRIPT ******************************/
Complete the following steps to use a more flexible approach for specifying the capture, propagation, and apply definitions. This approach does not use the DBMS_STREAMS_ADM package. Instead, it uses the following packages:
DBMS_CAPTURE_ADM package to configure capture processesDBMS_PROPAGATION_ADM package to configure propagationsDBMS_APPLY_ADM package to configure apply processesDBMS_RULES_ADM package to specify capture process, propagation, and apply process rules and rule sets
This example includes the following steps:
/************************* BEGINNING OF SCRIPT ******************************
Run SET ECHO ON and specify the spool file for the script. Check the spool file for errors after you run this script.
*/ SET ECHO ON SPOOL streams_share_schema2.out /*
Connect to dbs1.net as SYS user.
*/ CONNECT SYS/CHANGE_ON_INSTALL@dbs1.net AS SYSDBA /*
Supplemental logging places additional information in the redo log for changes made to tables. The apply process needs this extra information to perform certain operations, such as unique row identification and conflict resolution. Because dbs1.net is the only database where changes are captured in this environment, it is the only database where you must specify supplemental logging for the tables in the hr schema.
Specify an unconditional supplemental log group for all primary key columns in the hr schema.
*/ ALTER TABLE hr.countries ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.departments ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.employees ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.jobs ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.job_history ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.locations ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; ALTER TABLE hr.regions ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; /*
Connect to dbs1.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs1.net /*
Configure and schedule propagation from the queue at dbs1.net to the queue at dbs2.net. This configuration specifies that the propagation propagates all changes to the hr schema. You have the option of omitting the rule set specification, but then everything in the queue will be propagated, which may not be desired if, in the future, multiple capture processes will use the streams_queue.
*/ BEGIN -- Create the rule set DBMS_RULE_ADM.CREATE_RULE_SET( rule_set_name => 'strmadmin.propagation_dbs1_rules', evaluation_context => 'SYS.STREAMS$_EVALUATION_CONTEXT'); -- Create rules for all modifications to the hr schema DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_hr_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_hr_ddl', condition => ' (:ddl.get_object_owner() = ''HR'' OR ' || ' :ddl.get_base_table_owner() = ''HR'') AND ' || ' :ddl.is_null_tag() = ''Y'' AND ' || ' :ddl.get_source_database_name() = ''DBS1.NET'' '); -- Add rules to rule set DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_hr_dml', rule_set_name => 'strmadmin.propagation_dbs1_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_hr_ddl', rule_set_name => 'strmadmin.propagation_dbs1_rules'); -- Create a propagation that uses the rule set as its positive rule set DBMS_PROPAGATION_ADM.CREATE_PROPAGATION( propagation_name => 'dbs1_to_dbs2', source_queue => 'strmadmin.streams_queue', destination_queue => 'strmadmin.streams_queue', destination_dblink => 'dbs2.net', rule_set_name => 'strmadmin.propagation_dbs1_rules'); END; / /*
Create a capture process and rules to capture the entire hr schema at dbs1.net.
*/ BEGIN -- Create the rule set DBMS_RULE_ADM.CREATE_RULE_SET( rule_set_name => 'strmadmin.demo_rules', evaluation_context => 'SYS.STREAMS$_EVALUATION_CONTEXT'); -- Create rules that specify the entire hr schema DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.schema_hr_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.schema_hr_ddl', condition => ' (:ddl.get_object_owner() = ''HR'' OR ' || ' :ddl.get_base_table_owner() = ''HR'') AND ' || ' :ddl.is_null_tag() = ''Y'' AND ' || ' :ddl.get_source_database_name() = ''DBS1.NET'' '); -- Add the rules to the rule set DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.schema_hr_dml', rule_set_name => 'strmadmin.demo_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.schema_hr_ddl', rule_set_name => 'strmadmin.demo_rules'); -- Create a capture process that uses the rule set as its positive rule set DBMS_CAPTURE_ADM.CREATE_CAPTURE( queue_name => 'strmadmin.streams_queue', capture_name => 'capture', rule_set_name => 'strmadmin.demo_rules'); END; / /*
While still connected as the Streams administrator at dbs1.net, prepare the hr schema at dbs1.net for instantiation at dbs3.net. This step marks the lowest SCN of the tables in the schema for instantiation. SCNs subsequent to the lowest SCN can be used for instantiation.
|
Note: This step is not required in the "Simple Configuration for Sharing Data from a Single Database". In that example, when the |
*/ BEGIN DBMS_CAPTURE_ADM.PREPARE_SCHEMA_INSTANTIATION( schema_name => 'hr'); END; / /*
In this example, the hr.jobs table already exists at dbs2.net and dbs4.net. At dbs2.net, this table is named assignments, but it has the same shape and data as the jobs table at dbs1.net. Also, in this example, dbs4.net is a Sybase database. All of the other tables in the Streams environment are instantiated at the other destination databases using Data Pump import.
Because the hr.jobs table already exists at dbs2.net and dbs4.net, this example uses the GET_SYSTEM_CHANGE_NUMBER function in the DBMS_FLASHBACK package at dbs1.net to obtain the current SCN for the database. This SCN is used at dbs2.net to run the SET_TABLE_INSTANTIATION_SCN procedure in the DBMS_APPLY_ADM package. Running this procedure twice sets the instantiation SCN for the hr.jobs table at dbs2.net and dbs4.net.
The SET_TABLE_INSTANTIATION_SCN procedure controls which LCRs for a table are ignored by an apply process and which LCRs for a table are applied by an apply process. If the commit SCN of an LCR for a table from a source database is less than or equal to the instantiation SCN for that table at a destination database, then the apply process at the destination database discards the LCR. Otherwise, the apply process applies the LCR.
In this example, both of the apply processes at dbs2.net will apply transactions to the hr.jobs table with SCNs that were committed after SCN obtained in this step.
*/ DECLARE iscn NUMBER; -- Variable to hold instantiation SCN value BEGIN iscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER(); DBMS_APPLY_ADM.SET_TABLE_INSTANTIATION_SCN@DBS2.NET( source_object_name => 'hr.jobs', source_database_name => 'dbs1.net', instantiation_scn => iscn); DBMS_APPLY_ADM.SET_TABLE_INSTANTIATION_SCN@DBS2.NET( source_object_name => 'hr.jobs', source_database_name => 'dbs1.net', instantiation_scn => iscn, apply_database_link => 'dbs4.net'); END; /
/*
This example performs a network Data Pump import of the following tables:
A network import means that Data Pump imports these tables from dbs1.net without using an export dump file.
| See Also:
Oracle Database Utilities for information about performing an import |
Connect to dbs3.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs3.net /*
This example will do a table import using the DBMS_DATAPUMP package. For simplicity, exceptions from any of the API calls will not be trapped. However, Oracle recommends that you define exception handlers and call GET_STATUS to retrieve more detailed error information if a failure occurs. If you want to monitor the import, then query the DBA_DATAPUMP_JOBS data dictionary view at the import database.
*/ SET SERVEROUTPUT ON SIZE 1000000 DECLARE h1 NUMBER; -- Data Pump job handle sscn NUMBER; -- Variable to hold current source SCN job_state VARCHAR2(30); -- To keep track of job state js ku$_JobStatus; -- The job status from GET_STATUS sts ku$_Status; -- The status object returned by GET_STATUS job_not_exist exception; pragma exception_init(job_not_exist, -31626); BEGIN -- Create a (user-named) Data Pump job to do a table-level import. h1 := DBMS_DATAPUMP.OPEN( operation => 'IMPORT', job_mode => 'TABLE', remote_link => 'DBS1.NET', job_name => 'dp_sing2'); -- A metadata filter is used to specify the schema that owns the tables -- that will be imported. DBMS_DATAPUMP.METADATA_FILTER( handle => h1, name => 'SCHEMA_EXPR', value => '=''HR'''); -- A metadata filter is used to specify the tables that will be imported. DBMS_DATAPUMP.METADATA_FILTER( handle => h1, name => 'NAME_EXPR', value => 'IN(''COUNTRIES'', ''REGIONS'', ''LOCATIONS'')'); -- Get the current SCN of the source database, and set the FLASHBACK_SCN -- parameter to this value to ensure consistency between all of the -- objects included in the import. sscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER@dbs1.net(); DBMS_DATAPUMP.SET_PARAMETER( handle => h1, name => 'FLASHBACK_SCN', value => sscn); -- Start the job. DBMS_DATAPUMP.START_JOB(h1); -- The import job should be running. In the following loop, the job -- is monitored until it completes. job_state := 'UNDEFINED'; BEGIN WHILE (job_state != 'COMPLETED') AND (job_state != 'STOPPED') LOOP sts:=DBMS_DATAPUMP.GET_STATUS( handle => h1, mask => DBMS_DATAPUMP.KU$_STATUS_JOB_ERROR + DBMS_DATAPUMP.KU$_STATUS_JOB_STATUS + DBMS_DATAPUMP.KU$_STATUS_WIP, timeout => -1); js := sts.job_status; DBMS_LOCK.SLEEP(10); job_state := js.state; END LOOP; -- Gets an exception when job no longer exists EXCEPTION WHEN job_not_exist THEN DBMS_OUTPUT.PUT_LINE('Data Pump job has completed'); DBMS_OUTPUT.PUT_LINE('Instantiation SCN: ' ||sscn); END; END; / /*
Connect to dbs3.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs3.net /*
Configure dbs3.net to apply DML and DDL changes to the countries table, locations table, and regions table.
*/ BEGIN -- Create the rule set DBMS_RULE_ADM.CREATE_RULE_SET( rule_set_name => 'strmadmin.apply_rules', evaluation_context => 'SYS.STREAMS$_EVALUATION_CONTEXT'); -- Rules for hr.countries DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_countries_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.get_object_name() = ''COUNTRIES'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_countries_ddl', condition => ' (:ddl.get_object_owner() = ''HR'' OR ' || ' :ddl.get_base_table_owner() = ''HR'') AND ' || ' :ddl.get_object_name() = ''COUNTRIES'' AND ' || ' :ddl.is_null_tag() = ''Y'' AND ' || ' :ddl.get_source_database_name() = ''DBS1.NET'' '); -- Rules for hr.locations DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_locations_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.get_object_name() = ''LOCATIONS'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_locations_ddl', condition => ' (:ddl.get_object_owner() = ''HR'' OR ' || ' :ddl.get_base_table_owner() = ''HR'') AND ' || ' :ddl.get_object_name() = ''LOCATIONS'' AND ' || ' :ddl.is_null_tag() = ''Y'' AND ' || ' :ddl.get_source_database_name() = ''DBS1.NET'' '); -- Rules for hr.regions DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_regions_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.get_object_name() = ''REGIONS'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_regions_ddl', condition => ' (:ddl.get_object_owner() = ''HR'' OR ' || ' :ddl.get_base_table_owner() = ''HR'') AND ' || ' :ddl.get_object_name() = ''REGIONS'' AND ' || ' :ddl.is_null_tag() = ''Y'' AND ' || ' :ddl.get_source_database_name() = ''DBS1.NET'' '); -- Add rules to rule set DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_countries_dml', rule_set_name => 'strmadmin.apply_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_countries_ddl', rule_set_name => 'strmadmin.apply_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_locations_dml', rule_set_name => 'strmadmin.apply_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_locations_ddl', rule_set_name => 'strmadmin.apply_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_regions_dml', rule_set_name => 'strmadmin.apply_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_regions_ddl', rule_set_name => 'strmadmin.apply_rules'); -- Create an apply process that uses the rule set as its positive rule set DBMS_APPLY_ADM.CREATE_APPLY( queue_name => 'strmadmin.streams_queue', apply_name => 'apply', rule_set_name => 'strmadmin.apply_rules', apply_user => 'hr', apply_captured => true, source_database => 'dbs1.net'); END; / /*
Because the hr user was specified as the apply user in the previous step, the hr user requires execute privilege on the positive rule set used by the apply process
*/ BEGIN DBMS_RULE_ADM.GRANT_OBJECT_PRIVILEGE( privilege => SYS.DBMS_RULE_ADM.EXECUTE_ON_RULE_SET, object_name => 'strmadmin.apply_rules', grantee => 'hr'); END; / /*
Set the disable_on_error parameter to n so that the apply process will not be disabled if it encounters an error, and start the apply process at dbs3.net.
*/ BEGIN DBMS_APPLY_ADM.SET_PARAMETER( apply_name => 'apply', parameter => 'disable_on_error', value => 'n'); END; / BEGIN DBMS_APPLY_ADM.START_APPLY( apply_name => 'apply'); END; / /*
Connect to dbs2.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs2.net /*
Configure and schedule propagation from the queue at dbs2.net to the queue at dbs3.net. This configuration is an example of directed networks because the changes at dbs2.net originated at dbs1.net.
*/ BEGIN -- Create the rule set DBMS_RULE_ADM.CREATE_RULE_SET( rule_set_name => 'strmadmin.propagation_dbs3_rules', evaluation_context => 'SYS.STREAMS$_EVALUATION_CONTEXT'); -- Create rules for all modifications to the countries table DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_countries_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.get_object_name() = ''COUNTRIES'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_countries_ddl', condition => ' (:ddl.get_object_owner() = ''HR'' OR ' || ' :ddl.get_base_table_owner() = ''HR'') AND ' || ' :ddl.get_object_name() = ''COUNTRIES'' AND ' || ' :ddl.is_null_tag() = ''Y'' AND ' || ' :ddl.get_source_database_name() = ''DBS1.NET'' '); -- Create rules for all modifications to the locations table DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_locations_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.get_object_name() = ''LOCATIONS'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_locations_ddl', condition => ' (:ddl.get_object_owner() = ''HR'' OR ' || ' :ddl.get_base_table_owner() = ''HR'') AND ' || ' :ddl.get_object_name() = ''LOCATIONS'' AND ' || ' :ddl.is_null_tag() = ''Y'' AND ' || ' :ddl.get_source_database_name() = ''DBS1.NET'' '); -- Create rules for all modifications to the regions table DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_regions_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.get_object_name() = ''REGIONS'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_regions_ddl', condition => ' (:ddl.get_object_owner() = ''HR'' OR ' || ' :ddl.get_base_table_owner() = ''HR'') AND ' || ' :ddl.get_object_name() = ''REGIONS'' AND ' || ' :ddl.is_null_tag() = ''Y'' AND ' || ' :ddl.get_source_database_name() = ''DBS1.NET'' '); -- Add rules to rule set DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_countries_dml', rule_set_name => 'strmadmin.propagation_dbs3_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_countries_ddl', rule_set_name => 'strmadmin.propagation_dbs3_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_locations_dml', rule_set_name => 'strmadmin.propagation_dbs3_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_locations_ddl', rule_set_name => 'strmadmin.propagation_dbs3_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_regions_dml', rule_set_name => 'strmadmin.propagation_dbs3_rules'); DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_regions_ddl', rule_set_name => 'strmadmin.propagation_dbs3_rules'); -- Create a propagation that uses the rule set as its positive rule set DBMS_PROPAGATION_ADM.CREATE_PROPAGATION( propagation_name => 'dbs2_to_dbs3', source_queue => 'strmadmin.streams_queue', destination_queue => 'strmadmin.streams_queue', destination_dblink => 'dbs3.net', rule_set_name => 'strmadmin.propagation_dbs3_rules'); END; / /*
Connect to dbs2.net as the hr user.
*/ CONNECT hr/hr@dbs2.net /*
Create the rule-based transformation function that transforms row changes resulting from DML statements to the jobs table from dbs1.net into row changes to the assignments table on dbs2.net.
The following function transforms every row LCR for the jobs table into a row LCR for the assignments table.
*/ CREATE OR REPLACE FUNCTION hr.to_assignments_trans_dml( p_in_data in SYS.AnyData) RETURN SYS.AnyData IS out_data SYS.LCR$_ROW_RECORD; tc pls_integer; BEGIN -- Typecast AnyData to LCR$_ROW_RECORD tc := p_in_data.GetObject(out_data); IF out_data.GET_OBJECT_NAME() = 'JOBS' THEN -- Transform the in_data into the out_data out_data.SET_OBJECT_NAME('ASSIGNMENTS'); END IF; -- Convert to AnyData RETURN SYS.AnyData.ConvertObject(out_data); END; / /*
Connect to dbs2.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs2.net /*
Configure dbs2.net to apply changes to the local assignments table. Remember that the assignments table receives changes from the jobs table at dbs1.net. This step specifies a rule-based transformation without using the SET_RULE_TRANSFORM_FUNCTION procedure in the DBMS_STREAMS_ADM package. Instead, a name-value pair is added manually to the action context of the rule. The name-value pair specifies STREAMS$_TRANSFORM_FUNCTION for the name and hr.to_assignments_trans_dml for the value.
*/ DECLARE action_ctx_dml SYS.RE$NV_LIST; action_ctx_ddl SYS.RE$NV_LIST; ac_name VARCHAR2(30) := 'STREAMS$_TRANSFORM_FUNCTION'; BEGIN -- Specify the name-value pair in the action context action_ctx_dml := SYS.RE$NV_LIST(SYS.RE$NV_ARRAY()); action_ctx_dml.ADD_PAIR( ac_name, SYS.ANYDATA.CONVERTVARCHAR2('hr.to_assignments_trans_dml')); -- Create the rule set strmadmin.apply_rules DBMS_RULE_ADM.CREATE_RULE_SET( rule_set_name => 'strmadmin.apply_rules', evaluation_context => 'SYS.STREAMS$_EVALUATION_CONTEXT'); -- Create a rule that transforms all DML changes to the jobs table into -- DML changes for assignments table DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_jobs_dml', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.get_object_name() = ''JOBS'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' ', action_context => action_ctx_dml); -- Add the rule to the rule set DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_jobs_dml', rule_set_name => 'strmadmin.apply_rules'); -- Create an apply process that uses the rule set as its positive rule set DBMS_APPLY_ADM.CREATE_APPLY( queue_name => 'strmadmin.streams_queue', apply_name => 'apply_dbs2', rule_set_name => 'strmadmin.apply_rules', apply_user => 'hr', apply_captured => true, source_database => 'dbs1.net'); END; / /*
Because the hr user was specified as the apply user in the previous step, the hr user requires execute privilege on the positive rule set used by the apply process
*/ BEGIN DBMS_RULE_ADM.GRANT_OBJECT_PRIVILEGE( privilege => SYS.DBMS_RULE_ADM.EXECUTE_ON_RULE_SET, object_name => 'strmadmin.apply_rules', grantee => 'hr'); END; / /*
Set the disable_on_error parameter to n so that the apply process will not be disabled if it encounters an error, and start the apply process for local apply at dbs2.net.
*/ BEGIN DBMS_APPLY_ADM.SET_PARAMETER( apply_name => 'apply_dbs2', parameter => 'disable_on_error', value => 'n'); END; / BEGIN DBMS_APPLY_ADM.START_APPLY( apply_name => 'apply_dbs2'); END; / /*
Configure dbs2.net to apply DML changes to the jobs table at dbs4.net, which is a Sybase database. Remember that these changes originated at dbs1.net.
*/ BEGIN -- Create the rule set DBMS_RULE_ADM.CREATE_RULE_SET( rule_set_name => 'strmadmin.apply_dbs4_rules', evaluation_context => 'SYS.STREAMS$_EVALUATION_CONTEXT'); -- Create rule strmadmin.all_jobs_remote for all modifications -- to the jobs table DBMS_RULE_ADM.CREATE_RULE( rule_name => 'strmadmin.all_jobs_remote', condition => ' :dml.get_object_owner() = ''HR'' AND ' || ' :dml.get_object_name() = ''JOBS'' AND ' || ' :dml.is_null_tag() = ''Y'' AND ' || ' :dml.get_source_database_name() = ''DBS1.NET'' '); -- Add the rule to the rule set DBMS_RULE_ADM.ADD_RULE( rule_name => 'strmadmin.all_jobs_remote', rule_set_name => 'strmadmin.apply_dbs4_rules'); -- Create an apply process that uses the rule set as its positive rule set DBMS_APPLY_ADM.CREATE_APPLY( queue_name => 'strmadmin.streams_queue', apply_name => 'apply_dbs4', rule_set_name => 'strmadmin.apply_dbs4_rules', apply_database_link => 'dbs4.net', apply_captured => true, source_database => 'dbs1.net'); END; / /*
Set the disable_on_error parameter to n so that the apply process will not be disabled if it encounters an error, and start the remote apply for Sybase using database link dbs4.net.
*/ BEGIN DBMS_APPLY_ADM.SET_PARAMETER( apply_name => 'apply_dbs4', parameter => 'disable_on_error', value => 'n'); END; / BEGIN DBMS_APPLY_ADM.START_APPLY( apply_name => 'apply_dbs4'); END; / /*
Connect to dbs1.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs1.net /*
Start the capture process at dbs1.net.
*/ BEGIN DBMS_CAPTURE_ADM.START_CAPTURE( capture_name => 'capture'); END; / /*
Check the streams_share_schema2.out spool file to ensure that all actions finished successfully after this script is completed.
*/ SET ECHO OFF SPOOL OFF /*
You can now make DML and DDL changes to specific tables at dbs1.net and see these changes replicated to the other databases in the environment based on the rules you configured for the Streams processes and propagations in this environment.
| See Also:
"Make DML and DDL Changes to Tables in the hr Schema" for examples of changes that are replicated in this environment |
/*************************** END OF SCRIPT ******************************/
After completing either of the examples described in the "Example Scripts for Sharing Data from One Database" section, you can make DML and DDL changes to the tables in the hr schema at the dbs1.net database. These changes will be replicated to the other databases in the environment based on the rules you configured for Streams processes and propagations. You can check the other databases to see that the changes have been replicated.
For example, complete the following steps to make DML changes to the hr.jobs and hr.locations tables at dbs1.net. You also can make a DDL change to the hr.locations table at dbs1.net.
After you make these changes, you can query the hr.assignments table at dbs2.net to see that the DML change you made to this table at dbs1.net has been replicated. Remember that a rule-based transformation configured for the apply process at dbs2.net transforms DML changes to the hr.jobs table into DML changes to the hr.assignments table. You also can query the hr.locations table at dbs3.net to see that the DML and DDL changes you made to this table at dbs1.net have been replicated.
Make the following changes:
CONNECT hr/hr@dbs1.net UPDATE hr.jobs SET max_salary=10000 WHERE job_id='MK_REP'; COMMIT; INSERT INTO hr.locations VALUES( 3300, '521 Ralston Avenue', '94002', 'Belmont', 'CA', 'US'); COMMIT; ALTER TABLE hr.locations RENAME COLUMN state_province TO state_or_province;
After some time passes to allow for capture, propagation, and apply of the changes performed the previous step, run the following query to confirm that the UPDATE change made to the hr.jobs table at dbs1.net has been applied to the hr.assignments table at dbs2.net.
CONNECT hr/hr@dbs2.net SELECT max_salary FROM hr.assignments WHERE job_id='MK_REP';
You should see 10000 for the value of the max_salary.
Run the following query to confirm that the INSERT change made to the hr.locations table at dbs1.net has been applied at dbs3.net.
CONNECT hr/hr@dbs3.net SELECT * FROM hr.locations WHERE location_id=3300;
You should see the row inserted into the hr.locations table at dbs1.net in the previous step.
Next, describe the hr.locations table at to confirm that the ALTER TABLE change was propagated and applied correctly.
DESC hr.locations
The fifth column in the table should be state_or_province.
This example extends the Streams environment configured in the previous sections by adding replicated objects to an existing database. To complete this example, you must have completed the tasks in one of the previous examples in this chapter.
This example will add the following tables to the hr schema in the dbs3.net database:
When you complete this example, Streams processes changes to these tables with the following series of actions:
dbs1.net and enqueues them at dbs1.net.dbs1.net to the queue at dbs2.net.dbs2.net to the queue at dbs3.net.dbs3.net applies the changes at dbs3.net.When you complete this example, the hr schema at the dbs3.net database will have all of its original tables, because the countries, locations, and regions tables were instantiated at dbs3.net in the previous section.
Figure 13-2 provides an overview of the environment with the added tables.
Text description of the illustration strep003.gif
Complete the following steps to replicate these tables to the dbs3.net database.
/************************* BEGINNING OF SCRIPT ******************************
Run SET ECHO ON and specify the spool file for the script. Check the spool file for errors after you run this script.
*/ SET ECHO ON SPOOL streams_addobjs.out /*
Until you finish adding objects to dbs3.net, you must ensure that the apply process that will apply changes for the added objects does not try to apply changes for these objects. You can do this by stopping the capture process at the source database. Or, you can do this by stopping propagation of changes from dbs2.net to dbs3.net. Yet another alternative is to stop the apply process at dbs3.net. This example stops the apply process at dbs3.net.
Connect to dbs3.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs3.net /*
Stop the apply process at dbs3.net.
*/ BEGIN DBMS_APPLY_ADM.STOP_APPLY( apply_name => 'apply'); END; / /*
Configure the apply process at dbs3.net to apply changes to the tables you are adding.
*/ BEGIN DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.departments', streams_type => 'apply', streams_name => 'apply', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.employees', streams_type => 'apply', streams_name => 'apply', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.job_history', streams_type => 'apply', streams_name => 'apply', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_RULES( table_name => 'hr.jobs', streams_type => 'apply', streams_name => 'apply', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / /*
Connect to dbs2.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs2.net /*
Add the tables to the rules for propagation from the queue at dbs2.net to the queue at dbs3.net.
*/ BEGIN DBMS_STREAMS_ADM.ADD_TABLE_PROPAGATION_RULES( table_name => 'hr.departments', streams_name => 'dbs2_to_dbs3', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs3.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_PROPAGATION_RULES( table_name => 'hr.employees', streams_name => 'dbs2_to_dbs3', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs3.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_PROPAGATION_RULES( table_name => 'hr.job_history', streams_name => 'dbs2_to_dbs3', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs3.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / BEGIN DBMS_STREAMS_ADM.ADD_TABLE_PROPAGATION_RULES( table_name => 'hr.jobs', streams_name => 'dbs2_to_dbs3', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs3.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / /*
Connect to dbs1.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs1.net /*
Prepare the tables for instantiation. These tables will be instantiated at dbs3.net. This step marks the lowest SCN of the tables for instantiation. SCNs subsequent to the lowest SCN can be used for instantiation. Also, this preparation is necessary so that the Streams data dictionary for the relevant propagations and the apply process at dbs3.net contain information about these tables.
| See Also:
"Preparing Database Objects for Instantiation at a Source Database" and Oracle Streams Concepts and Administration |
*/ BEGIN DBMS_CAPTURE_ADM.PREPARE_TABLE_INSTANTIATION( table_name => 'hr.departments'); END; / BEGIN DBMS_CAPTURE_ADM.PREPARE_TABLE_INSTANTIATION( table_name => 'hr.employees'); END; / BEGIN DBMS_CAPTURE_ADM.PREPARE_TABLE_INSTANTIATION( table_name => 'hr.job_history'); END; / BEGIN DBMS_CAPTURE_ADM.PREPARE_TABLE_INSTANTIATION( table_name => 'hr.jobs'); END; / /*
This example performs a network Data Pump import of the following tables:
A network import means that Data Pump imports these tables from dbs1.net without using an export dump file.
| See Also:
Oracle Database Utilities for information about performing an import |
Connect to dbs3.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs3.net /*
This example will do a table import using the DBMS_DATAPUMP package. For simplicity, exceptions from any of the API calls will not be trapped. However, Oracle recommends that you define exception handlers and call GET_STATUS to retrieve more detailed error information if a failure occurs. If you want to monitor the import, then query the DBA_DATAPUMP_JOBS data dictionary view at the import database.
*/ SET SERVEROUTPUT ON SIZE 1000000 DECLARE h1 NUMBER; -- Data Pump job handle sscn NUMBER; -- Variable to hold current source SCN job_state VARCHAR2(30); -- To keep track of job state js ku$_JobStatus; -- The job status from GET_STATUS sts ku$_Status; -- The status object returned by GET_STATUS job_not_exist exception; pragma exception_init(job_not_exist, -31626); BEGIN -- Create a (user-named) Data Pump job to do a table-level import. h1 := DBMS_DATAPUMP.OPEN( operation => 'IMPORT', job_mode => 'TABLE', remote_link => 'DBS1.NET', job_name => 'dp_sing3'); -- A metadata filter is used to specify the schema that owns the tables -- that will be imported. DBMS_DATAPUMP.METADATA_FILTER( handle => h1, name => 'SCHEMA_EXPR', value => '=''HR'''); -- A metadata filter is used to specify the tables that will be imported. DBMS_DATAPUMP.METADATA_FILTER( handle => h1, name => 'NAME_EXPR', value => 'IN(''DEPARTMENTS'', ''EMPLOYEES'', ''JOB_HISTORY'', ''JOBS'')'); -- Get the current SCN of the source database, and set the FLASHBACK_SCN -- parameter to this value to ensure consistency between all of the -- objects included in the import. sscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER@dbs1.net(); DBMS_DATAPUMP.SET_PARAMETER( handle => h1, name => 'FLASHBACK_SCN', value => sscn); -- Start the job. DBMS_DATAPUMP.START_JOB(h1); -- The import job should be running. In the following loop, the job -- is monitored until it completes. job_state := 'UNDEFINED'; BEGIN WHILE (job_state != 'COMPLETED') AND (job_state != 'STOPPED') LOOP sts:=DBMS_DATAPUMP.GET_STATUS( handle => h1, mask => DBMS_DATAPUMP.KU$_STATUS_JOB_ERROR + DBMS_DATAPUMP.KU$_STATUS_JOB_STATUS + DBMS_DATAPUMP.KU$_STATUS_WIP, timeout => -1); js := sts.job_status; DBMS_LOCK.SLEEP(10); job_state := js.state; END LOOP; -- Gets an exception when job no longer exists EXCEPTION WHEN job_not_exist THEN DBMS_OUTPUT.PUT_LINE('Data Pump job has completed'); DBMS_OUTPUT.PUT_LINE('Instantiation SCN: ' ||sscn); END; END; / /*
Start the apply process at dbs3.net. This apply process was stopped in Step 2.
Connect to dbs3.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs3.net /*
Start the apply process at dbs3.net.
*/ BEGIN DBMS_APPLY_ADM.START_APPLY( apply_name => 'apply'); END; / /*
Check the streams_addobjs.out spool file to ensure that all actions finished successfully after this script is completed.
*/ SET ECHO OFF SPOOL OFF /*************************** END OF SCRIPT ******************************/
After completing the examples described in the "Add Objects to an Existing Streams Replication Environment" section, you can make DML and DDL changes to the tables in the hr schema at the dbs1.net database. These changes will be replicated to dbs3.net. You can check these tables at dbs3.net to see that the changes have been replicated.
For example, complete the following steps to make a DML change to the hr.employees table at dbs1.net. Next, query the hr.employees table at dbs3.net to see that the change has been replicated.
Make the following change:
CONNECT hr/hr@dbs1.net UPDATE hr.employees SET job_id='ST_MAN' WHERE employee_id=143; COMMIT;
After some time passes to allow for capture, propagation, and apply of the change performed in the previous step, run the following query to confirm that the UPDATE change made to the hr.employees table at dbs1.net has been applied to the hr.employees table at dbs3.net.
CONNECT hr/hr@dbs3.net SELECT job_id FROM hr.employees WHERE employee_id=143;
You should see ST_MAN for the value of the job_id.
This example extends the Streams environment configured in the previous sections by adding an additional database to the existing configuration. In this example, an existing Oracle database named dbs5.net is added to receive changes to the entire hr schema from the queue at dbs2.net.
Figure 13-3 provides an overview of the environment with the added database.
Text description of the illustration strep001.gif
To complete this example, you must meet the following prerequisites:
dbs5.net database must exist.dbs2.net and dbs5.net databases must be able to communicate with each other through Oracle Net.dbs5.net and dbs1.net databases must be able to communicate with each other through Oracle Net (for optional Data Pump network instantiation)strmadmin) at the dbs5.net database and prompts you for the tablespace you want to use for this user's data. Before you start this example, either create a new tablespace or identify an existing tablespace for the Streams administrator to use at the dbs5.net database. The Streams administrator should not use the SYSTEM tablespace.Complete the following steps to add dbs5.net to the Streams environment.
/************************* BEGINNING OF SCRIPT ******************************
Run SET ECHO ON and specify the spool file for the script. Check the spool file for errors after you run this script.
*/ SET ECHO ON SPOOL streams_adddb.out /*
This example illustrates instantiating the tables in the hr schema by importing them from dbs1.net into dbs5.net using Data Pump. You must delete these tables at dbs5.net for the instantiation portion of this example to work properly.
Connect as hr at dbs5.net.
*/ CONNECT hr/hr@dbs5.net /*
Drop all tables in the hr schema in the dbs5.net database.
*/ DROP TABLE hr.countries CASCADE CONSTRAINTS; DROP TABLE hr.departments CASCADE CONSTRAINTS; DROP TABLE hr.employees CASCADE CONSTRAINTS; DROP TABLE hr.job_history CASCADE CONSTRAINTS; DROP TABLE hr.jobs CASCADE CONSTRAINTS; DROP TABLE hr.locations CASCADE CONSTRAINTS; DROP TABLE hr.regions CASCADE CONSTRAINTS; /*
Connect to dbs5.net as SYS user.
*/ CONNECT SYS/CHANGE_ON_INSTALL@dbs5.net AS SYSDBA /*
Create the Streams administrator named strmadmin and grant this user the necessary privileges. These privileges enable the user to manage queues, execute subprograms in packages related to Streams, create rule sets, create rules, and monitor the Streams environment by querying data dictionary views and queue tables. You may choose a different name for this user.
| See Also:
Oracle Streams Concepts and Administration for more information about configuring a Streams administrator |
*/ GRANT CONNECT, RESOURCE, DBA, SELECT_CATALOG_ROLE TO strmadmin IDENTIFIED BY strmadminpw; ACCEPT streams_tbs PROMPT 'Enter Streams administrator tablespace on dbs5.net: ' ALTER USER strmadmin DEFAULT TABLESPACE &streams_tbs QUOTA UNLIMITED ON &streams_tbs; /*
Connect as the Streams administrator at the database you are adding. In this example, that database is dbs5.net.
*/ CONNECT strmadmin/strmadminpw@dbs5.net /*
Run the SET_UP_QUEUE procedure to create a queue named streams_queue at dbs5.net. This queue will function as the SYS.AnyData queue by holding the changes that will be applied at this database.
Running the SET_UP_QUEUE procedure performs the following actions:
streams_queue_table. This queue table is owned by the Streams administrator (strmadmin) and uses the default storage of this user.streams_queue owned by the Streams administrator (strmadmin).*/ EXEC DBMS_STREAMS_ADM.SET_UP_QUEUE(); /*
Create a database link from dbs5.net to dbs1.net. Later in this example, this database link is used for the instantiation of the database objects that were dropped in Step 2. This example uses the DBMS_DATAPUMP package to perform a network import of these database objects directly from the dbs1.net database. Because this example performs a network import, no dump file is required.
Alternatively, you can perform an export at the source database dbs1.net, transfer the export dump file to the destination database dbs5.net, and then import the export dump file at the destination database. In this case, the database link created in this step is not required.
*/ CREATE DATABASE LINK dbs1.net CONNECT TO strmadmin IDENTIFIED BY strmadminpw USING 'dbs1.net'; /*
While still connected as the Streams administrator at dbs5.net, configure the apply process to apply changes to the hr schema.
*/ BEGIN DBMS_STREAMS_ADM.ADD_SCHEMA_RULES( schema_name => 'hr', streams_type => 'apply', streams_name => 'apply', queue_name => 'strmadmin.streams_queue', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / /*
In this example, the hr user owns all of the database objects for which changes are applied by the apply process at this database. Therefore, hr already has the necessary privileges to change these database objects, and it is convenient to make hr the apply user.
When the apply process was created in the previous step, the Streams administrator strmadmin was specified as the apply user by default, because strmadmin ran the procedure that created the apply process. Instead of specifying hr as the apply user, you could retain strmadmin as the apply user, but then you must grant strmadmin privileges on all of the database objects for which changes are applied and privileges to execute all user procedures used by the apply process. In an environment where an apply process applies changes to database objects in multiple schemas, it may be more convenient to use the Streams administrator as the apply user.
| See Also:
Oracle Streams Concepts and Administration for more information about configuring a Streams administrator |
*/ BEGIN DBMS_APPLY_ADM.ALTER_APPLY( apply_name => 'apply', apply_user => 'hr'); END; / /*
Because the hr user was specified as the apply user in the previous step, the hr user requires execute privilege on the positive rule set used by the apply process
*/ DECLARE rs_name VARCHAR2(64); -- Variable to hold rule set name BEGIN SELECT RULE_SET_OWNER||'.'||RULE_SET_NAME INTO rs_name FROM DBA_APPLY WHERE APPLY_NAME='APPLY'; DBMS_RULE_ADM.GRANT_OBJECT_PRIVILEGE( privilege => SYS.DBMS_RULE_ADM.EXECUTE_ON_RULE_SET, object_name => rs_name, grantee => 'hr'); END; / /*
Connect to dbs2.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs2.net /*
Create the database links to the databases where changes are propagated. In this example, database dbs2.net propagates changes to dbs5.net.
*/ CREATE DATABASE LINK dbs5.net CONNECT TO strmadmin IDENTIFIED BY strmadminpw USING 'dbs5.net'; /*
While still connected as the Streams administrator at dbs2.net, Configure and schedule propagation from the queue at dbs2.net to the queue at dbs5.net. Remember, changes to the hr schema originated at dbs1.net.
*/ BEGIN DBMS_STREAMS_ADM.ADD_SCHEMA_PROPAGATION_RULES( schema_name => 'hr', streams_name => 'dbs2_to_dbs5', source_queue_name => 'strmadmin.streams_queue', destination_queue_name => 'strmadmin.streams_queue@dbs5.net', include_dml => true, include_ddl => true, source_database => 'dbs1.net', inclusion_rule => true); END; / /*
Connect to dbs1.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs1.net /*
Prepare the hr schema for instantiation. These tables in this schema will be instantiated at dbs5.net. This preparation is necessary so that the Streams data dictionary for the relevant propagations and the apply process at dbs5.net contain information about the hr schema and the objects in the schema.
| See Also:
"Preparing Database Objects for Instantiation at a Source Database" and Oracle Streams Concepts and Administration |
*/ BEGIN DBMS_CAPTURE_ADM.PREPARE_SCHEMA_INSTANTIATION( schema_name => 'hr'); END; / /*
This example performs a network Data Pump import of the following tables:
A network import means that Data Pump imports these tables from dbs1.net without using an export dump file.
| See Also:
Oracle Database Utilities for information about performing an import |
Connect to dbs5.net as the strmadmin user.
*/ CONNECT strmadmin/strmadminpw@dbs5.net /*
This example will do a table import using the DBMS_DATAPUMP package. For simplicity, exceptions from any of the API calls will not be trapped. However, Oracle recommends that you define exception handlers and call GET_STATUS to retrieve more detailed error information if a failure occurs. If you want to monitor the import, then query the DBA_DATAPUMP_JOBS data dictionary view at the import database.
*/ SET SERVEROUTPUT ON SIZE 1000000 DECLARE h1 NUMBER; -- Data Pump job handle sscn NUMBER; -- Variable to hold current source SCN job_state VARCHAR2(30); -- To keep track of job state js ku$_JobStatus; -- The job status from GET_STATUS sts ku$_Status; -- The status object returned by GET_STATUS job_not_exist exception; pragma exception_init(job_not_exist, -31626); BEGIN -- Create a (user-named) Data Pump job to do a table-level import. h1 := DBMS_DATAPUMP.OPEN( operation => 'IMPORT', job_mode => 'TABLE', remote_link => 'DBS1.NET', job_name => 'dp_sing4'); -- A metadata filter is used to specify the schema that owns the tables -- that will be imported. DBMS_DATAPUMP.METADATA_FILTER( handle => h1, name => 'SCHEMA_EXPR', value => '=''HR'''); -- Get the current SCN of the source database, and set the FLASHBACK_SCN -- parameter to this value to ensure consistency between all of the -- objects included in the import. sscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER@dbs1.net(); DBMS_DATAPUMP.SET_PARAMETER( handle => h1, name => 'FLASHBACK_SCN', value => sscn); -- Start the job. DBMS_DATAPUMP.START_JOB(h1); -- The import job should be running. In the following loop, the job -- is monitored until it completes. job_state := 'UNDEFINED'; BEGIN WHILE (job_state != 'COMPLETED') AND (job_state != 'STOPPED') LOOP sts:=DBMS_DATAPUMP.GET_STATUS( handle => h1, mask => DBMS_DATAPUMP.KU$_STATUS_JOB_ERROR + DBMS_DATAPUMP.KU$_STATUS_JOB_STATUS + DBMS_DATAPUMP.KU$_STATUS_WIP, timeout => -1); js := sts.job_status; DBMS_LOCK.SLEEP(10); job_state := js.state; END LOOP; -- Gets an exception when job no longer exists EXCEPTION WHEN job_not_exist THEN DBMS_OUTPUT.PUT_LINE('Data Pump job has completed'); DBMS_OUTPUT.PUT_LINE('Instantiation SCN: ' ||sscn); END; END; / /*
Connect as the Streams administrator at dbs5.net.
*/ CONNECT strmadmin/strmadminpw@dbs5.net /*
Set the disable_on_error parameter to n so that the apply process will not be disabled if it encounters an error, and start apply process at dbs5.net.
*/ BEGIN DBMS_APPLY_ADM.SET_PARAMETER( apply_name => 'apply', parameter => 'disable_on_error', value => 'n'); END; / BEGIN DBMS_APPLY_ADM.START_APPLY( apply_name => 'apply'); END; / /*
Check the streams_adddb.out spool file to ensure that all actions finished successfully after this script is completed.
*/ SET ECHO OFF SPOOL OFF /*************************** END OF SCRIPT ******************************/
After completing the examples described in the "Add a Database to an Existing Streams Replication Environment" section, you can make DML and DDL changes to the tables in the hr schema at the dbs1.net database. These changes will be replicated to dbs5.net. You can check these tables at dbs5.net to see that the changes have been replicated.
For example, complete the following steps to make a DML change to the hr.departments table at dbs1.net. Next, query the hr.departments table at dbs5.net to see that the change has been replicated.
Make the following change:
CONNECT hr/hr@dbs1.net UPDATE hr.departments SET location_id=2400 WHERE department_id=270; COMMIT;
After some time passes to allow for capture, propagation, and apply of the change performed in the previous step, run the following query to confirm that the UPDATE change made to the hr.departments table at dbs1.net has been applied to the hr.departments table at dbs5.net.
CONNECT hr/hr@dbs5.net SELECT location_id FROM hr.departments WHERE department_id=270;
You should see 2400 for the value of the location_id.