Oracle stream流复制的配置配置:主库 100.100.100.20 linux系统, 数据库实例名db1 版本10.2.0.1
备库 100.100.100.254 windows系统数据库名 dbwin2版本10.2.0.1
过程为:备库捕捉主库 u1用户下所有表的变化,实时同步
1.1 主库的配置1.1.1 主库oracle参数配置alter system set aq_tm_processes=2 scope=both;
alter system set global_names=true scope=both;
alter system set job_queue_processes=10 scope=both;
alter system set parallel_max_servers=20 scope=both;
alter system set undo_retention=3600 scope=both;
alter system set nls_date_format='YYYY-MM-DD HH24:MI:SS' scope=spfile;
#自动分配
alter system set streams_pool_size=25M scope=spfile;
alter system set utl_file_dir='*' scope=spfile;
alter system set open_links=4 scope=spfile;
打开归档日志
1.1.2 主库创建stream管理用户第一步, 创建streams管理用户表空间stream_tbs
SQL> create tablespace stream_tbs datafile '/home/oracle/oradata/db3/stream01.dbf'
2 size 200m
3 autoextend on
4 extent management local;
第二步,创建stream管理用户(例子中为了简化名称,设置为test),为了简化赋予DBA权限。
create user test identified by test default tablespace stream_tbs;
SQL> grant dba to test;
第三步,将logminer的数据字典从system表空间转移到新建的表空间stream_tbs
System用户执行
SQL> execute dbms_logmnr_d.set_tablespace('stream_tbs');
第四步、授权test用户为stream管理员(system用户执行)
SQL> begin
dbms_streams_auth.grant_admin_privilege(
grantee => 'test',
grant_privileges => true);
end;
/
1.1.3 主库创建dblink和配置主库的TNS网络第一步,在主库(db1)中创建备库(dbwin2)的dblink(stream管理用户test创建)
Connect test/test
create database link dbwin2 connect to test identified by test using 'dbwin2';
第二步,配置主库的TNS网络,加上备库(dbwin2)的tns名称
db1 =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = 100.100.100.20)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = db1)
)
)
dbwin2 =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = 100.100.100.254)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = dbwin2)
)
)
1.1.4 主库创建master流队列使用stream管理用户test创建流队列db1_queue,队列信息的表名称为db1_queue_table
SQL> connect test/test
begin
dbms_streams_adm.set_up_queue(
queue_table => 'db1_queue_table',
queue_name => 'db1_queue');
end;
/
1.1.5 主库创建捕获进程使用stream管理用户test创建捕获进程capture_db1,捕获主库u1(schema_name => 'u1',
指定)用户表的变化,将变化信息传给master队列test.db1_queue(如上一步)
connect test/test
begin
dbms_streams_adm.add_schema_rules(
schema_name => 'u1',
streams_type => 'capture',
streams_name => 'capture_db1',
queue_name => 'test.db1_queue',
include_dml => true,
include_ddl => true,
include_tagged_lcr => false,
source_database => null,
inclusion_rule => true);
end;
/
1.1.6 主库创建传播进程第一步,使用stream管理员用户 test创建传播进程db1_to_dbwin2,将捕获主库变化的master队列(test.db1_queue)传给备库的backup队列(test.dbwin2_queue,创建过程见下一章)。
重点参数为:destination_queue_name => 'test.dbwin2_queue@dbwin2',(备库dbwin2的backup队列.dbwin2_queue),source_queue_name => 'test.db1_queue'主库的记录表变化信息的mater队列db1_queue
connect test/test
begin
dbms_streams_adm.add_schema_propagation_rules(
schema_name => 'u1',
streams_name => 'db1_to_dbwin2',
source_queue_name => 'test.db1_queue',
destination_queue_name => 'test.dbwin2_queue@dbwin2',
include_dml => true,
include_ddl => true,
include_tagged_lcr => false,
source_database => 'db1',
inclusion_rule => true);
end;
第二步,修改propagation休眠时间为0,表示实时传播LCR。
begin
dbms_aqadm.alter_propagation_schedule(
queue_name => 'db1_queue',
destination => 'dbwin2',
latency => 0);
end;
1.2 备库的配置1.2.1 备库oracle参数配置alter system set aq_tm_processes=2 scope=both;
alter system set global_names=true scope=both;
alter system set job_queue_processes=10 scope=both;
alter system set parallel_max_servers=20 scope=both;
alter system set undo_retention=3600 scope=both;
alter system set nls_date_format='YYYY-MM-DD HH24:MI:SS' scope=spfile;
#自动分配
alter system set streams_pool_size=25M scope=spfile;
alter system set utl_file_dir='*' scope=spfile;
alter system set open_links=4 scope=spfile;
打开归档日志
1.2.2 备库创建stream管理用户第一步, 创建streams管理用户表空间stream_tbs
SQL> create tablespace stream_tbs datafile '/home/oracle/oradata/db3/stream01.dbf'
2 size 200m
3 autoextend on
4 extent management local;
第二步,创建stream管理用户(例子中为了简化名称,设置为test),为了简化赋予DBA权限。
create user test identified by test default tablespace stream_tbs;
SQL> grant dba to test;
第三步,将logminer的数据字典从system表空间转移到新建的表空间stream_tbs
System用户执行
SQL> execute dbms_logmnr_d.set_tablespace('stream_tbs');
第四步、授权test用户为stream管理员(system用户执行)
SQL> begin
dbms_streams_auth.grant_admin_privilege(
grantee => 'test',
grant_privileges => true);
end;
/
1.2.3 备库创建dblink和配置备库的TNS网络第一步,在备库(dbwin2)中创建主库(db1)的dblink(stream管理用户test创建)
Connect test/test
create database link db1 connect to test identified by test using 'db1';
第二步,配置备库(dbwin2)的TNS网络,加上主库(db1)的tns名称
db1 =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = 100.100.100.20)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = db1)
)
)
dbwin2 =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = 100.100.100.254)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = dbwin2)
)
)
1.2.4 备库创建backup流队列使用stream管理用户test创建流队列dbwin2_queue,存储队列新表名称为dbwin2_queue_table
SQL> connect test/test
SQL> connect test/test
begin
dbms_streams_adm.set_up_queue(
queue_table => 'dbwin2_queue_table',
queue_name => 'dbwin2_queue');
end;
/
注:
在主库的传播进程db1_to_dbwin2中,将主库中记录变化的master队列db1_queue信息传播到备库的backup队列dbwin2_queue,配置截取如下:
source_queue_name => 'test.db1_queue',
destination_queue_name => 'test.dbwin2_queue@dbwin2',
1.2.5 备库配置apply进程使用stream管理用户test创建备库应用进程apply_dbwin2,同步到备库U1用户的表中
connect test/test
begin
dbms_streams_adm.add_schema_rules(
schema_name => 'u1',
streams_type => 'apply',
streams_name => 'apply_dbwin2',
queue_name => 'test.dbwin2_queue',
include_dml => true,
include_ddl => true,
include_tagged_lcr => false,
source_database => 'db1',
inclusion_rule => true);
end;
/
1.3 oracle stream的启动停止1.3.1 oracle stream的启动和监控第一步,备库使用stream管理用户test启动apply进程
Connect test/test
begin
dbms_apply_adm.start_apply(
apply_name => 'apply_dbwin2');
end;
/
第二步,主库使用stream管理用户test启动capture进程
Connect test/test
begin
dbms_capture_adm.start_capture(
capture_name => 'capture_db1');
end;
第三步,备库监控apply进程为enable
SQL> select apply_name,queue_name,status from dba_apply; APPLY_NAME QUEUE_NAME STATUS ------------------------------ ------------------------------ -------- APPLY_DBWIN2 DBWIN2_QUEUE ENABLED
第四步,主库监控capture进程为enable
SQL> SELECT capture_name, capture_type, status, status_change_time, queue_name, captured_scn, applied_scn, error_message FROM DBA_CAPTURE; CAPTURE_NAME CAPTURE_TYPE STATUS STATUS_CHANGE_TIME QUEUE_NAME CAPTURED_SCN APPLIED_SCN ERROR_MESSAGE ------------------------------ ------------ -------- ------------------ ------------------------------ ------------ ----------- -------------------------------------------------------------------------------- CAPTURE_DB1 LOCAL ENABLED 2014/9/23 13:04:57 DB1_QUEUE 735788 735788
1.3.2 oracle stream的停止第一步,主库关闭capture进程,srream管理用户
Connect test/test
begin
dbms_capture_adm.stop_capture(
capture_name => 'capture_db1');
end;
第二步,备库关闭apply进程,sream管理用户
begin
dbms_apply_adm.stop_apply(
apply_name => 'apply_dbwin2');
end;
1.4 oracle stream的测试主库建表
SQL> create table u3(id3 number(10)); Table created SQL> commit; Commit complete
备库检查
SQL> select * from u3; ID3 -----------
主库插入记录
SQL> insert into u3 values(3); 1 row inserted SQL> commit; Commit complete
备库检查
SQL> select * from u3; ID3 ----------- 3
|