Friday 14 October 2011

create 2-way replication STREAMS


Step procedure for create 2-way replication for oracle databases

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

No comments:

Post a Comment