月度归档:2016年07月

Oracle 11g ADG 配置[RMAN DUPLICATE]

--- 环境描述
--- 1.主库
IP							10.113.128.66
主机名					dbtest5
DB版本					11.2.0.4.0
db_name       	dbpod
db_unique_name	dbpod
instance_name 	dbpod
service_names 	dbpod
--- 2.主库
IP							10.113.128.67
主机名					dbtest6
DB版本					11.2.0.4.0
db_name       	dbpod
db_unique_name	dbsdb
instance_name 	dbsdb
service_names 	dbsdb

--- 备库创建目录【与主库保持相同的目录结构】
$ mkdir -p /u01/app/oracle/admin/dbsdb/adump
$ mkdir -p /u01/app/oracle/admin/dbsdb/dpdump
$ mkdir -p /u01/app/oracle/admin/dbsdb/pfile
$ mkdir -p /u01/app/oracle/cfgtoollogs/dbca/dbsdb
$ mkdir -p /u01/app/oracle/fast_recovery_area
$ mkdir -p /u01/app/oracle/fast_recovery_area/dbsdb
$ mkdir -p /u01/app/oracle/oradata
$ mkdir -p /u01/app/oracle/oradata/dbsdb

--- 主库开启force logging
SQL> alter database force logging;

--- 主备库创建并启动静态监听
$ cat listener.ora 
# listener.ora Network Configuration File: /u01/app/oracle/product/11.2.0/db_1/network/admin/listener.ora
# Generated by Oracle configuration tools.

SID_LIST_LISTENER_POD =
  (SID_LIST =
    (SID_DESC =
      (GLOBAL_DBNAME = dbpod)
      (ORACLE_HOME = /u01/app/oracle/product/11.2.0/db_1)
      (SID_NAME = dbpod)
    )
  )

LISTENER_POD =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 10.113.128.66)(PORT = 1525))
  )

ADR_BASE_LISTENER_POD = /u01/app/oracle

$ cat listener.ora 
# listener.ora Network Configuration File: /u01/app/oracle/product/11.2.0/db_1/network/admin/listener.ora
# Generated by Oracle configuration tools.

SID_LIST_LISTENER_SDB =
  (SID_LIST =
    (SID_DESC =
      (GLOBAL_DBNAME = dbsdb)
      (ORACLE_HOME = /u01/app/oracle/product/11.2.0/db_1)
      (SID_NAME = dbsdb)
    )
  )

LISTENER_SDB =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 10.113.128.67)(PORT = 1525))
  )

ADR_BASE_LISTENER_SDB = /u01/app/oracle

$ lsnrctl start LISTENER_POD
$ lsnrctl start LISTENER_SDB
$ lsnrctl status LISTENER_POD
$ lsnrctl status LISTENER_SDB

--- 主备库创建TNS【主备库相同】
$ cat tnsnames.ora 
# tnsnames.ora Network Configuration File: /u01/app/oracle/product/11.2.0/db_1/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

DBPOD =
  (DESCRIPTION =
    (ADDRESS_LIST =
      (ADDRESS = (PROTOCOL = TCP)(HOST = 10.113.128.66)(PORT = 1525))
    )
    (CONNECT_DATA =
      (SERVICE_NAME = DBPOD)
    )
  )

DBSDB =
  (DESCRIPTION =
    (ADDRESS_LIST =
      (ADDRESS = (PROTOCOL = TCP)(HOST = 10.113.128.67)(PORT = 1525))
    )
    (CONNECT_DATA =
      (SERVICE_NAME = DBSDB)
    )
  )

--- 主库修改DG相关参数
SQL> alter system set LOG_ARCHIVE_CONFIG='DG_CONFIG=(dbpod,dbsdb)' scope=spfile;
SQL> alter system set LOG_ARCHIVE_DEST_1='LOCATION=/u01/app/oracle/fast_recovery_area/arch VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=dbpod' scope=spfile;
SQL> alter system set LOG_ARCHIVE_DEST_2='SERVICE=dbsdb ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=dbsdb' scope=spfile;
SQL> alter system set LOG_ARCHIVE_DEST_STATE_1=ENABLE scope=spfile;
SQL> alter system set LOG_ARCHIVE_DEST_STATE_2=ENABLE scope=spfile;
SQL> alter system set REMOTE_LOGIN_PASSWORDFILE=EXCLUSIVE scope=spfile;
SQL> alter system set FAL_SERVER=dbsdb scope=spfile;
SQL> alter system set DB_FILE_NAME_CONVERT='dbsdb','dbpod' scope=spfile;
SQL> alter system set LOG_FILE_NAME_CONVERT= 'dbsdb','dbpod' scope=spfile;
SQL> alter system set STANDBY_FILE_MANAGEMENT=AUTO scope=spfile;

--- 主库开启归档
SQL> shutdown immediate;
SQL> startup mount;
SQL> alter database archivelog;
SQL> alter database open;

--- 主库创建备库参数文件
SQL> create pfile='/home/oracle/dbsdb.ora' from spfile;

--- 将创建的参数文件拷贝到备库
$ scp /home/oracle/dbsdb.ora dbtest6:/u01/app/oracle/product/11.2.0/db_1/dbs/initdbsdb.ora

--- 备库修改参数文件pfile【根据原主库的参数文件修改将所有dbpod替换成dbsdb除db_name以外】
$ cat /u01/app/oracle/product/11.2.0/db_1/dbs/initdbsdb.ora
dbsdb.__db_cache_size=1157627904
dbsdb.__java_pool_size=16777216
dbsdb.__large_pool_size=419430400
dbsdb.__oracle_base='/u01/app/oracle'#ORACLE_BASE set from environment
dbsdb.__pga_aggregate_target=1325400064
dbsdb.__sga_target=1979711488
dbsdb.__shared_io_pool_size=0
dbsdb.__shared_pool_size=352321536
dbsdb.__streams_pool_size=0
*._index_partition_large_extents='FALSE'
*._optimizer_null_aware_antijoin=FALSE
*._partition_large_extents='FALSE'
*._undo_autotune=FALSE
*._use_adaptive_log_file_sync='FALSE'
*.audit_file_dest='/u01/app/oracle/admin/dbsdb/adump'
*.audit_trail='NONE'
*.compatible='11.2.0.4.0'
*.control_files='/u01/app/oracle/oradata/dbsdb/control01.ctl','/u01/app/oracle/fast_recovery_area/dbsdb/control02.ctl'
*.db_block_size=8192
*.db_domain=''
*.db_name='dbpod'
*.db_recovery_file_dest='/u01/app/oracle/fast_recovery_area'
*.db_recovery_file_dest_size=5218762752
*.deferred_segment_creation=FALSE
*.diagnostic_dest='/u01/app/oracle'
*.event='10949 trace name context forever,level 1'
*.dispatchers='(PROTOCOL=TCP) (SERVICE=dbsdbXDB)'
*.log_archive_dest_state_1='ENABLE'
*.log_archive_dest_state_2='ENABLE'
*.log_archive_format='%t_%s_%r.dbf'
*.memory_target=3300917248
*.open_cursors=300
*.processes=1000
*.remote_login_passwordfile='EXCLUSIVE'
*.sec_case_sensitive_logon=FALSE
*.sessions=1105
*.undo_tablespace='UNDOTBS1'

--- 创建备库spfile文件
SQL> create spfile from pfile;

--- 备库启动到nomount
SQL> startup nomount 

--- 修改备库与DG相关的参数
SQL >alter system set DB_UNIQUE_NAME=dbsdb scope=spfile;
SQL >alter system set LOG_ARCHIVE_CONFIG='DG_CONFIG=(dbpod,dbsdb)' scope=spfile;
SQL >alter system set DB_FILE_NAME_CONVERT='dbpod','dbsdb' scope=spfile;
SQL >alter system set LOG_FILE_NAME_CONVERT='dbpod','dbsdb' scope=spfile;
SQL >alter system set LOG_ARCHIVE_DEST_1='LOCATION=/u01/app/oracle/fast_recovery_area/arch VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=dbsdb' scope=spfile;
SQL >alter system set LOG_ARCHIVE_DEST_2='SERVICE=dbpod ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=dbpod' scope=spfile;
SQL >alter system set STANDBY_FILE_MANAGEMENT=AUTO scope=spfile;
SQL >alter system set FAL_SERVER=dbpod scope=spfile;
SQL >alter system set FAL_CLIENT=dbsdb scope=spfile;

--- 使用RMAN DUPLICATE将主库恢复到备库【此处可以使用active database直接将主库在线复制到备库】
$ rman target sys/oracle@dbpod auxiliary sys/oracle@dbsdb nocatalog
--- 如果使用非catalog则在RMAN连接时加上nocatalog关键字,否则会报如下错误:
PLS-00201: identifier'DBMS_RCVCAT.GETDBID' must be declared
RMAN> duplicate target database for standby from active database dorecover nofilenamecheck;
--- 在执行duplicate的时候,如果源库和目标库目录相同,那么在duplicate 时需要加上nofilenamecheck关键字,否则会报如下错:
RMAN-05001: auxiliary file name conflicts with a file used by the target database
--- 下面为duplicate执行输出过程【此处未使用catalog且主备库目录不同】
[oracle@dbtest6 ~]$ rman target sys/oracle@dbpod auxiliary sys/oracle@dbsdb nocatalog

Recovery Manager: Release 11.2.0.4.0 - Production on Thu Jul 21 15:41:15 2016

Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.

connected to target database: DBPOD (DBID=3530613280)
using target database control file instead of recovery catalog
connected to auxiliary database: DBPOD (not mounted)

RMAN> duplicate target database for standby from active database;

Starting Duplicate Db at 21-JUL-16
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=771 device type=DISK

contents of Memory Script:
{
   backup as copy reuse
   targetfile  '/u01/app/oracle/product/11.2.0/db_1/dbs/orapwdbpod' auxiliary format 
 '/u01/app/oracle/product/11.2.0/db_1/dbs/orapwdbsdb'   ;--- 拷贝主库密码文件到备库
}
executing Memory Script

Starting backup at 21-JUL-16
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=18 device type=DISK
Finished backup at 21-JUL-16

contents of Memory Script:
{
   backup as copy current controlfile for standby auxiliary format  '/u01/app/oracle/oradata/dbsdb/control01.ctl';
   restore clone controlfile to  '/u01/app/oracle/fast_recovery_area/dbsdb/control02.ctl' from 
 '/u01/app/oracle/oradata/dbsdb/control01.ctl'; --- 创建备库控制文件
}
executing Memory Script

Starting backup at 21-JUL-16
using channel ORA_DISK_1
channel ORA_DISK_1: starting datafile copy
copying standby control file
output file name=/u01/app/oracle/product/11.2.0/db_1/dbs/snapcf_dbpod.f tag=TAG20160721T154230 RECID=2 STAMP=917797350
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
Finished backup at 21-JUL-16

Starting restore at 21-JUL-16
using channel ORA_AUX_DISK_1

channel ORA_AUX_DISK_1: copied control file copy
Finished restore at 21-JUL-16

contents of Memory Script:
{
   sql clone 'alter database mount standby database';--- 启动备库到mount
}
executing Memory Script

sql statement: alter database mount standby database

contents of Memory Script:
{
   set newname for tempfile  1 to 
 "/u01/app/oracle/oradata/dbsdb/temp01.dbf";
   switch clone tempfile all;
   set newname for datafile  1 to 
 "/u01/app/oracle/oradata/dbsdb/system01.dbf";
   set newname for datafile  2 to 
 "/u01/app/oracle/oradata/dbsdb/sysaux01.dbf";
   set newname for datafile  3 to 
 "/u01/app/oracle/oradata/dbsdb/undotbs01.dbf";
   set newname for datafile  4 to 
 "/u01/app/oracle/oradata/dbsdb/users01.dbf";
   backup as copy reuse
   datafile  1 auxiliary format 
 "/u01/app/oracle/oradata/dbsdb/system01.dbf"   datafile 
 2 auxiliary format 
 "/u01/app/oracle/oradata/dbsdb/sysaux01.dbf"   datafile 
 3 auxiliary format 
 "/u01/app/oracle/oradata/dbsdb/undotbs01.dbf"   datafile 
 4 auxiliary format 
 "/u01/app/oracle/oradata/dbsdb/users01.dbf"   ;
   sql 'alter system archive log current';
}
executing Memory Script--- 将主库数据文件进行convert后拷贝到备库

executing command: SET NEWNAME

renamed tempfile 1 to /u01/app/oracle/oradata/dbsdb/temp01.dbf in control file

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

Starting backup at 21-JUL-16
using channel ORA_DISK_1
channel ORA_DISK_1: starting datafile copy
input datafile file number=00001 name=/u01/app/oracle/oradata/dbpod/system01.dbf
output file name=/u01/app/oracle/oradata/dbsdb/system01.dbf tag=TAG20160721T154238
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:15
channel ORA_DISK_1: starting datafile copy
input datafile file number=00002 name=/u01/app/oracle/oradata/dbpod/sysaux01.dbf
output file name=/u01/app/oracle/oradata/dbsdb/sysaux01.dbf tag=TAG20160721T154238
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:15
channel ORA_DISK_1: starting datafile copy
input datafile file number=00003 name=/u01/app/oracle/oradata/dbpod/undotbs01.dbf
output file name=/u01/app/oracle/oradata/dbsdb/undotbs01.dbf tag=TAG20160721T154238
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07
channel ORA_DISK_1: starting datafile copy
input datafile file number=00004 name=/u01/app/oracle/oradata/dbpod/users01.dbf
output file name=/u01/app/oracle/oradata/dbsdb/users01.dbf tag=TAG20160721T154238
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
Finished backup at 21-JUL-16

sql statement: alter system archive log current

contents of Memory Script:
{
   switch clone datafile all;
}
executing Memory Script

datafile 1 switched to datafile copy
input datafile copy RECID=2 STAMP=917797396 file name=/u01/app/oracle/oradata/dbsdb/system01.dbf
datafile 2 switched to datafile copy
input datafile copy RECID=3 STAMP=917797396 file name=/u01/app/oracle/oradata/dbsdb/sysaux01.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=4 STAMP=917797396 file name=/u01/app/oracle/oradata/dbsdb/undotbs01.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=5 STAMP=917797396 file name=/u01/app/oracle/oradata/dbsdb/users01.dbf
Finished Duplicate Db at 21-JUL-16

--- duplicate完成后备库处理mount状态
SQL> select status from v$instance;

STATUS
------------
MOUNTED

--- 主库添加standby redo log
SQL> alter database add standby logfile group 4 ('/u01/app/oracle/oradata/dbpod/dbpod_srl01a.log','/u01/app/oracle/fast_recovery_area/dbpod/dbpod_srl01b.log') size 1024M;
SQL> alter database add standby logfile group 5 ('/u01/app/oracle/oradata/dbpod/dbpod_srl02a.log','/u01/app/oracle/fast_recovery_area/dbpod/dbpod_srl02b.log') size 1024M;
SQL> alter database add standby logfile group 6 ('/u01/app/oracle/oradata/dbpod/dbpod_srl03a.log','/u01/app/oracle/fast_recovery_area/dbpod/dbpod_srl03b.log') size 1024M;
SQL> alter database add standby logfile group 7 ('/u01/app/oracle/oradata/dbpod/dbpod_srl04a.log','/u01/app/oracle/fast_recovery_area/dbpod/dbpod_srl04b.log') size 1024M;

--- 备库添加standby redo log
SQL> alter database add standby logfile group 4 ('/u01/app/oracle/oradata/dbsdb/dbsdb_srl01a.log','/u01/app/oracle/fast_recovery_area/dbsdb/dbsdb_srl01b.log') size 1024M;
SQL> alter database add standby logfile group 5 ('/u01/app/oracle/oradata/dbsdb/dbsdb_srl02a.log','/u01/app/oracle/fast_recovery_area/dbsdb/dbsdb_srl02b.log') size 1024M;
SQL> alter database add standby logfile group 6 ('/u01/app/oracle/oradata/dbsdb/dbsdb_srl03a.log','/u01/app/oracle/fast_recovery_area/dbsdb/dbsdb_srl03b.log') size 1024M;
SQL> alter database add standby logfile group 7 ('/u01/app/oracle/oradata/dbsdb/dbsdb_srl04a.log','/u01/app/oracle/fast_recovery_area/dbsdb/dbsdb_srl04b.log') size 1024M;

--- 备库开始实时应用
SQL> alter database recover managed standby database using current logfile disconnect from session;

--- 备库日志应用情况
SQL> select sequence#, first_time, next_time from v$archived_log order by sequence#;
SQL> select sequence#,applied from v$archived_log order by sequence#;

--- 备库日志应用状态
SQL> select open_mode from v$database;

OPEN_MODE
--------------------
READ ONLY WITH APPLY