oracle 11g PHYSICAL STANDBY配置
时间:2014-05-06 04:05:13 作者:beebol 标签: primary standby 分类: Oracle
1、环境:
primary:activity01.cyou.com 已经安装数据库
netname:actvdbbak db_unique_name:actvdb01
standby:actvnew.cyou.com 只安装数据库软件,没有创建数据库
netname:actvdb db_unique_name:actvdb02
2、在primary\standby中的/etc/hosts中做好两个主机名的解析。
3、配置listener.ora 和 tnsnames.ora
listener.ora:
LISTENER1532 = (DESCRIPTION_LIST = (DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL = TCP)(HOST = activity01.cyou.com)(PORT = 1532)) ) ) ) SID_LIST_LISTENER1532 = (SID_LIST = (SID_DESC = (GLOBAL_DBNAME = actvdb) (ORACLE_HOME = /data/U01/app/oracle/product/11.2.0.4) (SID_NAME = actvdb) )) )
tnsnames.ora:
actvdb = (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = actvnew.cyou.com)(PORT = 1532)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = actvdb) ) ) actvdbbak = (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = activity01.cyou.com)(PORT = 1532)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = actvdb) )) )
4、primary参数设置
alter database force logging; alter system set db_unique_name='actvdb01' scope=spfile;#这个名字primary与standby不能一样 alter system set db_recovery_file_dest='/data/U01/app/oracle/flash_recovery_area' scope=spfile; alter system set log_archive_config='DG_CONFIG=(actvdb01,actvdb02)';#这个填写的是db_unique_name alter system set log_archive_dest_1='location=/data/U01/app/oracle/oradata/actvdb/archive valid_for=(ONLINE_LOGFILE,ALL_ROLES) db_unique_name=actvdb01' scope=spfile; alter system set log_archive_dest_2='location=USE_DB_RECOVERY_FILE_DEST valid_for=(STANDBY_LOGFILE,STANDBY_ROLE) db_unique_name=actvdb01' scope=spfile; alter system set log_archive_dest_3='service=actvdb LGWR ASYNC db_unique_name=actvdb02 valid_for=(all_logfiles,primary_role)' scope=spfile; #service配置的是发送日志的standby的net名称,后面的db_unique_name也是standby的 alter system set fal_client='actvdbbak'; alter system set fal_server='actvdb'; alter system set standby_file_management=auto;#这里最好设置成auto alter database add standby logfile group 7 ('/data/U01/app/oracle/oradata/actvdb/redo07.log') size 50M; alter database add standby logfile group 8 ('/data/U01/app/oracle/oradata/actvdb/redo08.log') size 50M; alter database add standby logfile group 9 ('/data/U01/app/oracle/oradata/actvdb/redo09.log') size 50M; alter database add standby logfile group 10 ('/data/U01/app/oracle/oradata/actvdb/redo10.log') size 50M; alter database add standby logfile group 11 ('/data/U01/app/oracle/oradata/actvdb/redo11.log') size 50M; alter database add standby logfile group 12 ('/data/U01/app/oracle/oradata/actvdb/redo12.log') size 50M; alter database add standby logfile group 13 ('/data/U01/app/oracle/oradata/actvdb/redo13.log') size 50M; alter database add standby logfile group 14 ('/data/U01/app/oracle/oradata/actvdb/redo14.log') size 50M;alter system set local_listener='actvdbbak'; alter system set local_listener='actvdbbak';
特别注意log_archive_dest_n的配置内容的空格和逗号问题。
SQL> alter system set log_archive_dest_2='location=USE_DB_RECOVERY_FILE_DEST,valid_for=(STANDBY_LOGFILE,STANDBY_ROLE)' scope=spfile; alter system set log_archive_dest_2='location=USE_DB_RECOVERY_FILE_DEST,valid_for=(STANDBY_LOGFILE,STANDBY_ROLE)' scope=spfile * ERROR at line 1: ORA-32017: failure in updating SPFILE ORA-16179: incremental changes to "log_archive_dest_2" not allowed with SPFILE这个错误是valid_for前没有空格的原因 这个错误是valid_for前没有空格的原因
配置好了后,可以通过如下语句查询是否正常
select * from v$archive_dest_status;
如出现如下图的bad param就能确定这log_archive_dest_3配置有问题。
5、设置好参数后,需要重启shutdown immediate --->startup
6、在primary中生成文本的参数文件
create pfile='/home/oracle/1.pfile' from spfile;
这里需要修改1.pfile的内容:
*.db_unique_name='actvdb02' *.fal_client='actvdb' *.fal_server='actvdbbak' *.log_archive_dest_1='location=/data/U01/app/oracle/oradata/actvdb/archive valid_for=(ONLINE_LOGFILE,ALL_ROLES) db_unique_name=actvdb02' *.log_archive_dest_2='location=USE_DB_RECOVERY_FILE_DEST valid_for=(STANDBY_LOGFILE,STANDBY_ROLE) db_unique_name=actvdb02' *.log_archive_dest_3='service=actvdbbak LGWR ASYNC db_unique_name=actvdb01 valid_for=(all_logfiles,primary_role)'*.local_listener='ACTVDB' *.local_listener='ACTVDB'
主要修改这几个参数,将actvdb与actvdbbak进行调换
7、再将生成的pfile文件及密码文件拷贝到standby中
[oracle@activity01.cyou.com ~]$scp 1.pfile actvnew.cyou.com:~/ [oracle@activity01.cyou.com ~]$scp /data/U01/app/oracle/product/11.2.0.4/dbs/orapwactvdb actvnew.cyou.com:/data/U01/app/oracle/product/11.2.0.4/dbs/ SQL> create spfile from pfile='/home/oracle/1.pfile'; File created. 然后通过pfile生成spfile,启动到nomount状态 SQL> startup nomountORACLE instance started. ORACLE instance started.
8、然后进行第一次数据同步
[oracle@actvnew.cyou.com admin]$rman target sys/123456@actvdbbak auxiliary sys/123456@actvdb Recovery Manager: Release 11.2.0.4.0 - Production on Mon May 5 17:33:35 2014 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: ACTVDB (DBID=2845198203) connected to auxiliary database: ACTVDB (not mounted)RMAN> duplicate target database for standby from active database nofilenamecheck; RMAN> duplicate target database for standby from active database nofilenamecheck;
查看这两个库的状态,一个是open状态,一个是nomount状态,这是正常的。然后执行duplicate进行复制数据。
注意后面的nofilenamecheck,如果不加这个参数的话,会报错:
sql statement: alter database mount standby database RMAN-00571: =========================================================== RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS =============== RMAN-00571: =========================================================== RMAN-03002: failure of Duplicate Db command at 05/05/2014 17:24:08 RMAN-05501: aborting duplication of target database RMAN-05001: auxiliary file name /data/U01/app/oracle/oradata/actvdb/audit_tab01.dbf conflicts with a file used by the target database RMAN-05001: auxiliary file name /data/U01/app/oracle/oradata/actvdb/users01.dbf conflicts with a file used by the target database RMAN-05001: auxiliary file name /data/U01/app/oracle/oradata/actvdb/undotbs01.dbf conflicts with a file used by the target database RMAN-05001: auxiliary file name /data/U01/app/oracle/oradata/actvdb/sysaux01.dbf conflicts with a file used by the target databaseRMAN-05001: auxiliary file name /data/U01/app/oracle/oradata/actvdb/system01.dbf conflicts with a file used by the target database RMAN-05001: auxiliary file name /data/U01/app/oracle/oradata/actvdb/system01.dbf conflicts with a file used by the target database
9、然后将standby打开,这个时候打开是read only状态的
[oracle@actvnew.cyou.com admin]$sqlplus / as sysdba SQL> alter database open; Database altered. SQL> alter database recover managed standby database using current logfile disconnect from session; Database altered. SQL> !ps -ef | grep mrp oracle 22754 1 0 17:40 ? 00:00:00 ora_mrp0_actvdb oracle 22789 22143 0 17:40 pts/0 00:00:00 /bin/bash -c ps -ef | grep mrp oracle 22791 22789 0 17:40 pts/0 00:00:00 grep mrp SQL> select sequence#,applied from v$archived_log; SEQUENCE# APPLIED ---------- --------- 312 YES 在primary中查看中最大的是: SEQUENCE# APPLIED ---------- ---------312 NO 312 NO
通过 alter database recover managed standby database using current logfile disconnect from session;语句启动mrp进程,开启日志实时应用。
可以查看下两个库的状态:
primary: SQL> select db_unique_name,database_role,open_mode from v$database; DB_UNIQUE_NAME DATABASE_ROLE OPEN_MODE ------------------------------ ---------------- -------------------- actvdb01 PRIMARY READ WRITE standby: SQL> select db_unique_name,database_role,open_mode from v$database; DB_UNIQUE_NAME DATABASE_ROLE OPEN_MODE ------------------------------ ---------------- --------------------actvdb02 PHYSICAL STANDBY READ ONLY WITH APPLY actvdb02 PHYSICAL STANDBY READ ONLY WITH APPLY
standby显示为:read only with aplly表示正处理日志应用状态
10、如下就可以进行测试了,在primary创建用户、表空间、表,然后到standby中查看是否也存在。
SQL> create user test identified by test_test; User created. SQL> create tablespace test 2 datafile '/data/U01/app/oracle/oradata/actvdb/test01.dbf' size 10M; Tablespace created. SQL> alter user test quota unlimited on test; User altered. SQL> create table test_table tablespace test as select * from dba_objects;Table created. Table created.
在standby中能够看到相应的用户、表空间、表了,这表示oracle 11G的主从已经搭建好了。
最后就是要设置下数据保护模式:
Data Guard 允许定义3钟数据保护模式,分别是最大保护(Maximum Protection),最大可用(Maximum Availability)和 最大性能(Maximum Performance)。
1. 最大保护(Maximum Protection)
这种模式能够确保绝无数据丢失。要实现这一步当然是有代价的,它要求所有的事务在提交前其REDO不仅被写入到本地的Online Redologs,还要同时写入到Standby数据库的Standby Redologs,并确认REDO数据至少在一个Standby数据库中可用(如果有多个的话),然后才会在Primary数据库上提交。如果出现了什么故障导致Standby数据库不可用的话(比如网络中断),Primary数据库会被Shutdown,以防止数据丢失。
使用这种方式要求Standby Database 必须配置Standby Redo Log,而Primary Database必须使用LGWR,SYNC,AFFIRM 方式归档到Standby Database.
2. 最高可用性(Maximum availability)
这种模式在不影响Primary数据库可用前提下,提供最高级别的数据保护策略。其实现方式与最大保护模式类似,也是要求本地事务在提交前必须至少写入一台Standby数据库的Standby Redologs中,不过与最大保护模式不同的是,如果出现故障导致Standby数据库无法访问,Primary数据库并不会被Shutdown,而是自动转为最高性能模式,等Standby数据库恢复正常之后,Primary数据库又会自动转换成最高可用性模式。
这种方式虽然会尽量避免数据丢失,但不能绝对保证数据完全一致。这种方式要求Standby Database 必须配置Standby Redo Log,而Primary Database必须使用LGWR,SYNC,AFFIRM 方式归档到Standby Database.
3. 最高性能(Maximum performance)
缺省模式。 这种模式在不影响Primary数据库性能前提下,提供最高级别的数据保护策略。事务可以随时提交,当前Primary数据库的REDO数据至少需要写入一个Standby数据库,不过这种写入可以是不同步的。如果网络条件理想的话,这种模式能够提供类似最高可用性的数据保护,而仅对Primary数据库的性能有轻微影响。这也是创建Standby数据库时,系统的默认保护模式。
这种方式可以使用LGWR ASYNC 或者 ARCH 进程实现,Standby Database也不要求使用Standby Redo Log。
4. 修改数据保护模式步骤
1)关闭数据库,重启到Mount 状态,如果是RAC,需要关闭所有实例,然后只启动一个实例到mount状态。
2)修改模式:
语法:ALTER DATABASE SET STANDBY DATABASE TO MAXIMIZE {PROTECTION | AVAILABILITY | PERFORMANCE};
如:SQL>ALTER DATABASE SET STANDBY DATABASE TO MAXIMIZE PROTECTION;
3) 打开数据库: alter database open;
4) 确认修改数据保护模式:
SQL>select protection_mode,protection_level from v$database;