Skip Headers
Oracle® Database 2 Day + Data Replication and Integration Guide
11g Release 1 (11.1)

Part Number B28324-01
Go to Documentation Home
Home
Go to Book List
Book List
Go to Table of Contents
Contents
Go to Index
Index
Go to Master Index
Master Index
Go to Feedback page
Contact Us

Go to previous page
Previous
Go to next page
Next
View PDF

6 Extending an Oracle Streams Replication Environment

This chapter describes extending an Oracle Streams replication environment by adding database objects or databases.

This chapter contains the following sections:

See Also:

About Extending an Oracle Streams Replication Environment

Sometimes it is necessary to extend an Oracle Streams replication environment when the needs of your organization change. You can extend an Oracle Streams replication environment by adding database objects or databases.

There are two ways to extend an Oracle Streams replication environment:

Use a Single Procedure in the DBMS_STREAMS_ADM Package

The easiest way to extend an Oracle Streams replication environment is to run one of the following procedures in the DBMS_STREAMS_ADM package:

To use one of these procedures to extend an Oracle Streams replication environment, the environment must meet the following conditions:

If your environment meets these conditions, then complete the steps in one of the following sections to extend the environment:

Add the Oracle Streams Components Individually in Multiple Steps

If you cannot extend the Oracle Streams replication environment by using a MAINTAIN_ procedure in the DBMS_STREAMS_ADM package, then you must complete the configuration steps manually. These steps include adding the necessary rules and Oracle Streams components to the environment, as well as other configuration steps.

If you must extend the Oracle Streams replication environment manually, then see the instructions in Oracle Streams Replication Administrator's Guide.

Example: Adding Database Objects to a Replication Environment

This topic includes an example that uses the MAINTAIN_TABLES procedure in the DBMS_STREAMS_ADM package to add tables to an existing hub-and-spoke replication environment. When the example is complete, the Oracle Streams replication environment replicates the changes made to the tables at the databases in the environment.

Specifically, the example in this topic extends the replication environment configured in "Example: Configuring Read/Write Hub-and-Spoke Replication with Capture Processes". That configuration has the following characteristics:

This example adds the following tables to the environment:

This example uses the tables in the oe sample schema. The oe sample schema is installed by default with Oracle Database.

Note:

Before you use a MAINTAIN_ procedure in the DBMS_STREAMS_ADM package to extend an Oracle Streams replication environment, ensure that the environment meets the conditions described in "About Extending an Oracle Streams Replication Environment".

To add database objects to an Oracle Streams replication environment:

  1. Configure latest time conflict resolution for the orders and order_items tables in the oe schema at the hub.net, spoke1.net, and spoke2.net databases. See "Example: Configuring Latest Time Conflict Resolution for a Table" for instructions.

  2. Stop the capture process at the hub database in the hub-and-spoke environment.

    In this example, stop the capture process at the hub.net database. The replicated database objects can remain open to changes while the capture process is stopped. These changes will be captured when the capture process is restarted.

    1. In Oracle Enterprise Manager, log in to the hub database as the Oracle Streams administrator.

    2. Go to the Database Home page.

    3. Click Data Movement to open the Data Movement subpage.

    4. Click Manage in the Streams section.

      The Streams page appears, showing the Overview subpage.

    5. Click Capture to open the Capture subpage.

      Description of tdpii_capture.gif follows
      Description of the illustration tdpii_capture.gif

    6. Select the capture process that you want to stop.

    7. Click Stop.

    8. Click Yes on the confirmation page to stop the capture process.

  3. In SQL*Plus, run the appropriate MAINTAIN_ procedure at the hub database to add each new database object for each spoke database.

    You might need to run the procedure several times if the environment has more than one spoke database. In this example, complete the following steps:

    1. Open SQL*Plus and connect to the hub.net database as the Oracle Streams administrator:

      sqlplus strmadmin/user-password@hub.net
      
    2. Run the MAINTAIN_TABLES procedure to add the oe.orders and oe.order_items tables for replication between hub.net and spoke1.net:

      DECLARE
        tables DBMS_UTILITY.UNCL_ARRAY;
        BEGIN
          tables(1) := 'oe.orders';
          tables(2) := 'oe.order_items';
          DBMS_STREAMS_ADM.MAINTAIN_TABLES(
            table_names                  => tables,
            source_directory_object      => 'hns_dir',
            destination_directory_object => 'hns_dir',
            source_database              => 'hub.net',
            destination_database         => 'spoke1.net',
            capture_name                 => 'capture_hns',
            capture_queue_table          => 'source_hns_qt',
            capture_queue_name           => 'source_hns',
            propagation_name             => 'propagation_spoke1',
            apply_name                   => 'apply_spoke1',
            apply_queue_table            => 'destination_spoke1_qt',
            apply_queue_name             => 'destination_spoke1',
            bi_directional               => TRUE);
      END;
      /
      

      Do not allow data manipulation language (DML) or data definition language (DDL) changes to the specified tables at the destination database while the procedure is running.

    3. Run the MAINTAIN_TABLES procedure to add the oe.orders and oe.order_items tables for replication between hub.net and spoke2.net:

      DECLARE
        tables DBMS_UTILITY.UNCL_ARRAY;
        BEGIN
          tables(1) := 'oe.orders';
          tables(2) := 'oe.order_items';
          DBMS_STREAMS_ADM.MAINTAIN_TABLES(
            table_names                  => tables,
            source_directory_object      => 'hns_dir',
            destination_directory_object => 'hns_dir',
            source_database              => 'hub.net',
            destination_database         => 'spoke2.net',
            capture_name                 => 'capture_hns',
            capture_queue_table          => 'source_hns_qt',
            capture_queue_name           => 'source_hns',
            propagation_name             => 'propagation_spoke2',
            apply_name                   => 'apply_spoke2',
            apply_queue_table            => 'destination_spoke2_qt',
            apply_queue_name             => 'destination_spoke2',
            bi_directional               => TRUE);
      END;
      /
      

      Do not allow data manipulation language (DML) or data definition language (DDL) changes to the specified tables at the destination database while the procedure is running.

  4. Set the instantiation SCN for the replicated tables at the spoke databases:

    Note:

    This step is required in this example because the replicated tables existed at the spoke databases before the MAINTAIN_TABLES procedure was run. If the replicated tables did not exist at the spoke databases before the MAINTAIN_TABLES procedure was run, then the procedure sets the instantiation SCN for the replicated tables and this step is not required.
    1. Open SQL*Plus and connect to the hub.net database as the Oracle Streams administrator:

      sqlplus strmadmin/user-password@hub.net
      
    2. Set the instantiation SCN for the oe.orders table at the spoke1.net database:

      DECLARE
        iscn  NUMBER;    -- Variable to hold instantiation SCN value
      BEGIN
        iscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER();
        DBMS_APPLY_ADM.SET_TABLE_INSTANTIATION_SCN@spoke1.net(
          source_object_name    => 'oe.orders',
          source_database_name  => 'hub.net',
          instantiation_scn     => iscn);
      END;
      /
      
    3. Set the instantiation SCN for the oe.order_items table at the spoke1.net database:

      DECLARE
        iscn  NUMBER;    -- Variable to hold instantiation SCN value
      BEGIN
        iscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER();
        DBMS_APPLY_ADM.SET_TABLE_INSTANTIATION_SCN@spoke1.net(
          source_object_name    => 'oe.order_items',
          source_database_name  => 'hub.net',
          instantiation_scn     => iscn);
      END;
      /
      
    4. Set the instantiation SCN for the oe.orders table at the spoke2.net database:

      DECLARE
        iscn  NUMBER;    -- Variable to hold instantiation SCN value
      BEGIN
        iscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER();
        DBMS_APPLY_ADM.SET_TABLE_INSTANTIATION_SCN@spoke2.net(
          source_object_name    => 'oe.orders',
          source_database_name  => 'hub.net',
          instantiation_scn     => iscn);
      END;
      /
      
    5. Set the instantiation SCN for the oe.order_items table at the spoke2.net database:

      DECLARE
        iscn  NUMBER;    -- Variable to hold instantiation SCN value
      BEGIN
        iscn := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER();
        DBMS_APPLY_ADM.SET_TABLE_INSTANTIATION_SCN@spoke2.net(
          source_object_name    => 'oe.order_items',
          source_database_name  => 'hub.net',
          instantiation_scn     => iscn);
      END;
      /
      

The MAINTAIN_TABLES procedure can take some time to run because it is performing many configuration tasks. When the procedure completes, the new database objects are added to the environment, and the capture process that was stopped in Step 2 is restarted.

If you encounter any errors when you run the MAINTAIN_SCHEMAS procedure, then see Oracle Streams Replication Administrator's Guide for instructions about using the RECOVER_OPERATION procedure in the DBMS_STREAMS_ADM package to recover from these errors.

This example assumes that all of the databases in the replication environment have the hns_dir directory object configured. This directory object holds files that are generated when the MAINTAIN_TABLES procedure runs.

Also, the parameter values that specify Oracle Streams component names must be the same as the values specified in the MAINTAIN_ procedure that configured the replication environment. The Oracle Streams component names specified include the capture process name, queue names, queue table names, the propagation name, and the apply process name. In this example, the Oracle Streams component names match the ones specified in "Example: Configuring Read/Write Hub-and-Spoke Replication with Capture Processes".

Example: Adding Databases to a Replication Environment

This topic includes an example that uses the MAINTAIN_SCHEMAS procedure in the DBMS_STREAMS_ADM package to add a new spoke database to an existing hub-and-spoke replication environment. When the example is complete, the Oracle Streams replication environment replicates the changes made to the schema with the new database.

Specifically, the example in this topic extends the replication environment configured in "Example: Configuring Read/Write Hub-and-Spoke Replication with Capture Processes". That configuration has the following characteristics:

This example adds the spoke3.net database to the environment.

Note:

Before you use a MAINTAIN_ procedure in the DBMS_STREAMS_ADM package to extend an Oracle Streams replication environment, ensure that the environment meets the conditions described in "About Extending an Oracle Streams Replication Environment".

To add a database to an existing Oracle Streams replication environment:

  1. Complete the following tasks to prepare the environment for the new database:

    1. Configure network connectivity so that the hub database can communicate with the new spoke database. In this example, configure network connectivity so that the hub.net database and the spoke3.net databases can communicate with each other.

      See Oracle Database 2 Day DBA for information about configuring network connectivity between databases.

    2. Configure an Oracle Streams administrator at the new spoke database. In this example, configure an Oracle Streams administrator at the spoke3.net database. See "Example: Creating an Oracle Streams Administrator" for instructions. This example assumes that the Oracle Streams administrator is strmadmin.

    3. Configure latest time conflict resolution for all of the tables in the hr schema at the spoke3.net database. This schema includes the countries, departments, employees, jobs, job_history, locations, and regions tables. "Example: Configuring Latest Time Conflict Resolution for a Table" for instructions.

      The MAINTAIN_SCHEMAS procedure instantiates the replicated schemas and database objects at the destination database (spoke3.net). There are two scenarios to consider when you configure conflict resolution for your replication environment:

      Replicated schemas and database objects do not exist at the spoke database: During instantiation, the triggers in the schema and the supplemental logging specifications are configured at the destination database. Therefore, you do not need create the triggers or add supplemental logging manually at the destination databases.

      Replicated schemas and database objects exist at the spoke database: During instantiation, the triggers in the schema and the supplemental logging specifications are not configured at the destination database. Therefore, you must create the triggers or add supplemental logging manually at the destination databases.

      In either case, the instantiation does not configure the update conflict handlers at the destination database. Therefore, you must run the SET_UPDATE_CONFLICT_HANDLER procedure to configure the update conflict handlers.

      In this example, the hr schema already exists at the spoke3.net database. Therefore, you must create the triggers, add supplemental logging, and configure the update conflict handlers at the spoke3.net database.

    4. Create a database link from the hub database to new spoke database and from new spoke database to the hub database. In this example, create the following database links:

      • From the hub.net database to the spoke3.net database

      • From the spoke3.net database to the hub.net database

      Each database link should be created in the Oracle Streams administrator's schema. Also, each database link should connect to the Oracle Streams administrator at the destination database. See "Example: Creating a Database Link" for instructions.

    5. Set initialization parameters properly at the new spoke database. In this example, set initialization parameters properly at the spoke3.net database. See "Preparing for Oracle Streams Replication" for instructions.

    6. Configure the new spoke database to run in ARCHIVELOG mode. For a capture process to capture changes generated at a source database, the source database must be running in ARCHIVELOG mode. In this example, configure the spoke3.net database to run in ARCHIVELOG mode. See Oracle Database Administrator's Guide for information about configuring a database to run in ARCHIVELOG mode.

  2. Open SQL*Plus and connect to the spoke3.net database as the Oracle Streams administrator:

    sqlplus strmadmin/user-password@spoke3.net
    

    See Oracle Database 2 Day DBA for more information about starting SQL*Plus.

  3. Create a directory object to hold files that will be generated by the MAINTAIN_SCHEMAS procedure. The directory object can point to any accessible directory on the computer system. For example, the following statement creates a directory object named hns_dir that points to the /usr/db_files directory:

    CREATE DIRECTORY hns_dir AS '/usr/db_files';
    

    This example assumes that the hns_dir directory object already exists at the hub database.

  4. Stop the capture process at the hub database in the hub-and-spoke environment.

    In this example, stop the capture process at the hub.net database. The replicated database objects can remain open to changes while the capture process is stopped. These changes will be captured when the capture process is restarted.

    1. In Oracle Enterprise Manager, log in to the hub database as the Oracle Streams administrator.

    2. Go to the Database Home page.

    3. Click Data Movement to open the Data Movement subpage.

    4. Click Manage in the Streams section.

      The Streams page appears, showing the Overview subpage.

    5. Click Capture to open the Capture subpage.

      Description of tdpii_capture.gif follows
      Description of the illustration tdpii_capture.gif

    6. Select the capture process that you want to stop.

    7. Click Stop.

    8. Click Yes on the confirmation page to stop the capture process.

  5. In SQL*Plus, run the appropriate MAINTAIN_ procedure at the hub database to add the new spoke database.

    In this example, complete the following steps:

    1. Open SQL*Plus and connect to the hub.net database as the Oracle Streams administrator:

      sqlplus strmadmin/user-password@hub.net
      
    2. Run the MAINTAIN_SCHEMAS procedure to add the spoke3.net database to the Oracle Streams replication environment:

      BEGIN
        DBMS_STREAMS_ADM.MAINTAIN_SCHEMAS(
          schema_names                 => 'hr',
          source_directory_object      => 'hns_dir',
          destination_directory_object => 'hns_dir',
          source_database              => 'hub.net',
          destination_database         => 'spoke3.net',
          capture_name                 => 'capture_hns',
          capture_queue_table          => 'source_hns_qt',
          capture_queue_name           => 'source_hns',
          propagation_name             => 'propagation_spoke3',
          apply_name                   => 'apply_spoke3',
          apply_queue_table            => 'destination_spoke3_qt',
          apply_queue_name             => 'destination_spoke3',
          bi_directional               => TRUE);
      END;
      /
      

      Do not allow data manipulation language (DML) or data definition language (DDL) changes to the database objects in the specified schema at the destination database while the procedure is running.

The parameter values specified in capture_name, capture_queue_table, and capture_queue_name must be the same as the values specified in the MAINTAIN_ procedure that configured the replication environment. In this example, these parameter values match the ones specified in "Example: Configuring Read/Write Hub-and-Spoke Replication with Capture Processes".

The MAINTAIN_SCHEMAS procedure can take some time to run because it is performing many configuration tasks. When the procedure completes, the new database objects are added to the environment, and the capture process that was stopped in Step 4 is restarted.

If you encounter any errors when you run the MAINTAIN_SCHEMAS procedure, then see Oracle Streams Replication Administrator's Guide for instructions about using the RECOVER_OPERATION procedure in the DBMS_STREAMS_ADM package to recover from these errors.