OCP Blog
Super DBA
Step By step procedure for create 2-way replication for Oracle Databases
by Vazha Mantua Sunday, July 24, 2011 1:49 PM

Good Day All,

 

Today we will be talk about oracle streaming.

Oracle Streams is the flow of information either within a single database or from one database to another. Oracle Streams can be set up in homogeneous (all Oracle databases) or heterogeneous (non-Oracle and Oracle databases) environments. The Streams setup uses a set of processes and database objects to share data and messages. The database changes (DDL and DML) are captured at the source; those are then staged and propagated to one or more destination databases to be applied there. Message propagation uses Advanced Queuing mechanism within the Oracle databases.

 

Let see a example: It will be step by step procedure how create 2-way replica(master to master) between 2 oracle databases(Version 10.2.0.4).

We Have 2 identical Database, named ORCL and TEST.

For Step1-Step5 use database user named sys.

 

 

Step 1: Create stream administration user in both databases.

----------ORCL

create user streamadmin identified by streamadmin default tablespace users;

----------TEST

create user streamadmin identified by streamadmin default tablespace users;

Step 2: Required grants to the user streamadmin.

----------on both of the databases(ORCL&TEST)

grant dba,select_catalog_role to streamadmin;

Grants the privileges needed by a user to be an administrator for streams

begin

dbms_streams_auth.grant_admin_privilege('streamadmin',true);

end;

 

Step 3: We will use default HR schema for setting up this replication for table countries

Step 4: Check database parameters required for setting up stream replication

check job_queue_processes parameter , it should not be 0. Also you can set e global_names parameter true, but if you create database links exact as oracle SID’s value true is not necessary.

Step 5: Enable supplemental logging on the tables of the HR user in both of the databases

----------on both of the databases(ORCL&TEST)

ALTER TABLE HR.countries ADD SUPPLEMENTAL LOG DATA (ALL) COLUMNS;

 

Step 6: Create Database Links between the stream administrator users in the both databases.

Logon with streamadmin user…

----------ORCL

CREATE DATABASE LINK TEST CONNECT TO STREAMADMIN IDENTIFIED BY streamadmin USING 'TEST';

----------TEST

CREATE DATABASE LINK ORCL CONNECT TO STREAMADMIN IDENTIFIED BY streamadmin USING 'ORCL';

Step 7: Create Stream Queues under the streamadmin user to apply and capture the database changes to be replicated.

This also needs to be run on both databases as streamadmin user.

----------on both of the databases(ORCL&TEST)

begin

dbms_streams_adm.set_up_queue(queue_table => 'apply_q', queue_name => 'apply_q', queue_user => 'streamadmin');

end;

begin

dbms_streams_adm.set_up_queue(queue_table => 'capture_q',queue_name => 'capture_q',queue_user => 'streamadmin');

end;

Step 8: Setup data capture on both the databases:

Logon with streamadmin user…

----------on both of the databases(ORCL&TEST)

BEGIN

DBMS_STREAMS_ADM.add_table_rules

(table_name => 'HR.COUNTRIES'

,streams_type => 'CAPTURE'

,streams_name => 'CAPTURE_STREAM'

,queue_name => 'CAPTURE_Q'

,include_dml => TRUE

,include_ddl => TRUE

,inclusion_rule => TRUE

);

END;

Step 9: Setup data apply on both the databases:

Logon with streamadmin user…

----------TEST

BEGIN

DBMS_STREAMS_ADM.add_table_rules (

TABLE_NAME => 'HR.COUNTRIES',

STREAMS_TYPE => 'APPLY',

STREAMS_NAME => 'APPLY_STREAM',

QUEUE_NAME => 'APPLY_Q',

INCLUDE_DML => TRUE,

INCLUDE_DDL => TRUE,

SOURCE_DATABASE => 'ORCL');

END;

----------on ORCL

BEGIN

DBMS_STREAMS_ADM.add_table_rules (

TABLE_NAME => 'HR.COUNTRIES',

STREAMS_TYPE => 'APPLY',

STREAMS_NAME => 'APPLY_STREAM',

QUEUE_NAME => 'APPLY_Q',

INCLUDE_DML => TRUE,

INCLUDE_DDL => TRUE,

SOURCE_DATABASE => 'TEST');

END;

Step 10: Setup propagation process on both the databases:

It is basically setting up related between the capture process on one database and apply process on the other database.

Logon with streamadmin user…

----------on ORCL

BEGIN

DBMS_STREAMS_ADM.ADD_TABLE_PROPAGATION_RULES(

TABLE_NAME => 'HR.COUNTRIES',

STREAMS_NAME => 'ORCL_TO_TEST',

SOURCE_QUEUE_NAME =>'CAPTURE_Q',

DESTINATION_QUEUE_NAME => 'APPLY_Q@TEST',

INCLUDE_DML => TRUE,

INCLUDE_DDL => TRUE,

SOURCE_DATABASE => 'ORCL');

END;

----------on TEST

BEGIN

DBMS_STREAMS_ADM.add_table_propagation_rules(

TABLE_NAME => 'HR.COUNTRIES',

STREAMS_NAME => 'TEST_TO_ORCL',

SOURCE_QUEUE_NAME =>'CAPTURE_Q',

DESTINATION_QUEUE_NAME => 'APPLY_Q@ORCL',

INCLUDE_DML => TRUE,

INCLUDE_DDL => TRUE,

SOURCE_DATABASE => 'TEST');

END;

Step 11: Setup schema instantiation SCN on ORCL and TEST DB’s

----------on TEST

DECLARE

ISCN NUMBER;

BEGIN

ISCN := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER();

DBMS_APPLY_ADM.set_table_instantiation_scn@ORCL(source_object_name => 'HR.COUNTRIES',source_database_name => 'TEST',instantiation_scn => ISCN);

END;

----------on ORCL

DECLARE

ISCN NUMBER;

BEGIN

ISCN := DBMS_FLASHBACK.GET_SYSTEM_CHANGE_NUMBER();

DBMS_APPLY_ADM.set_table_instantiation_scn@TEST(source_object_name => 'HR.COUNTRIES',source_database_name => 'ORCL',instantiation_scn => ISCN);

END;

 

Step 12: Start capture and apply process:

Setting the disable_on_error parameter to ‘N’ allows the apply process to continue applying row LCRs even when it encounters errors. The default value is ‘Y’ which disables the apply process automatically on the first error encountered.

----------on both DBs

BEGIN

DBMS_APPLY_ADM.SET_PARAMETER (APPLY_NAME => 'APPLY_STREAM', PARAMETER => 'DISABLE_ON_ERROR', VALUE => 'N');

DBMS_APPLY_ADM.START_APPLY (APPLY_NAME => 'APPLY_STREAM');

DBMS_CAPTURE_ADM.START_CAPTURE (CAPTURE_NAME => 'CAPTURE_STREAM');

END;

------------------------------------------------------------------------

Now you can test your replication 2-way replication which means all changes for HR.COUNTRIES from ORCL DB shipped to TEST DB and , all changes from TEST DB shipped to ORCL DB

 

Useful view’s for monitoring process are:

 

dba_apply,

dba_apply_error,

dba_apply_progress ,

dba_apply_enqueue,

dba_capture,

dba_capture_parameters,

dba_capture_prepared_tables

 

 

 

 

 

Tags: ,

Comments (6) -

9/16/2011 7:54:06 PM #

black jumpsuit

Hi. I needed to drop you a fast note to precise my thanks. Ive been following your blog for a month or so and have picked up a ton of good info and enjoyed the method youve structured your site. I am trying to run my very own weblog nonetheless I think its too general and I need to focus on plenty of smaller topics. Being all things to all people is not all that its cracked up to be.

black jumpsuit United States

1/12/2012 12:28:18 PM #

Boutique PR Agency

Thank you so very much for being kind with us!

Boutique PR Agency United States

3/7/2012 7:34:43 AM #

Mercurial Vapor Superfly III

Ian Jones, whose <strong><a href=www.gotsoccercleats.com/...c-1_3.html>Mercurial Vapor Superfly III</a></strong>six- year-old son Jasper plays for Swansea City under-7s development squad, is hoping to collect <strong><a href=www.gotsoccercleats.com/...lack-p-1206.html>CR7 soccer cleats</a></strong> as many old pairs of boots and trainers for the Boots for Africa appeal as possible.

Mercurial Vapor Superfly III People's Republic of China

3/7/2012 11:33:34 AM #

F50 adizero FG

I WAS deeply saddened to <strong><a href=www.gotsoccercleats.com/...ime-fg-c-31.html>F50 adizero FG</a></strong>hear of the recent death of Shaun Maby, a well-known local footballer. I was at Mangotsfield <strong><a href=www.gotsoccercleats.com/...c-1_3.html>Mercurial 2012</a></strong>    United with Shaun in the mid -90s and appreciated then what a great bloke and talented footballer he was."

F50 adizero FG People's Republic of China

6/10/2012 3:31:18 PM #

Iraqi Dinar

Let see a example: It will be step by step procedure how create 2-way replica(master to master) between 2 oracle databases(Version 10.2.0.4).

Iraqi Dinar United Kingdom

6/20/2012 2:34:17 PM #

Diminished Value

You lost me, buddy. I mean, I assume I get what youre indicating. I have an understanding of what you’re saying, but you just appear to have forgotten that you can find some other individuals within the world who see this matter for what it actually is and may perhaps not agree with you. You might be turning away a lot of persons who may have been lovers of your website.

Diminished Value United Kingdom

Add comment

  Country flag

biuquote
  • Comment
  • Preview
Loading

Filter by APML

Calendar

<<  November 2017  >>
MoTuWeThFrSaSu
303112345
6789101112
13141516171819
20212223242526
27282930123
45678910

View posts in large calendar

TextBox