本文记录ADG搭建操作步骤,首先在虚拟机CentOS中安装并配置好oracle 11g R2(具体安装步骤在我的另一篇博客中),然后拷贝一份虚拟机,修改新虚拟机的主机名和ip配置,这时候主库和备库是一模一样的,降低后面配置adg的难度,下面开始ADG的搭建了。
1:主库上检查主库数据库是否启用了强制日志模式并启用归档,如果不是,则启用强制日志模式并开启日志归档。
SQL> select name, log_mode, force_logging from v$database;
NAME LOG_MODE FORCE_
------------------ ------------------------ ------
ORCL NOARCHIVELOG NO
未启用强制日志模式,需要启用,另外,可以看到日志模式是非归档模式,这个也要修改成归档模式。
启用强制日志:
SQL> alter database force logging;
Database altered.
开启归档模式(需要重启实例至mount状态):
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount;
ORACLE instance started.
Total System Global Area 830930944 bytes
Fixed Size 2217912 bytes
Variable Size 641730632 bytes
Database Buffers 180355072 bytes
Redo Buffers 6627328 bytes
Database mounted.
SQL> alter database archivelog;
Database altered.
SQL> alter database open;
Database altered.
检查一下归档是否已开启:
SQL> archive log list;
Database log mode Archive Mode
Automatic archival Enabled
Archive destination USE_DB_RECOVERY_FILE_DEST
Oldest online log sequence 87
Next log sequence to archive 89
Current log sequence 89
2:在主库创建密码文件,将密码文件拷贝至备机。
[oracle@apollo ~]$ cd $ORACLE_HOME/dbs
[oracle@apollo dbs]$ ll
total 24
-rw-rw---- 1 oracle oinstall 1544 Mar 3 2019 hc_DBUA0.dat
-rw-rw---- 1 oracle oinstall 1544 Feb 27 20:12 hc_orcl.dat
-rw-r--r-- 1 oracle oinstall 2851 May 15 2009 init.ora
-rw-r----- 1 oracle oinstall 24 Mar 3 2019 lkORCL
-rw-r----- 1 oracle oinstall 1536 Jan 11 16:17 orapworcl
-rw-r----- 1 oracle oinstall 2560 Feb 27 20:12 spfileorcl.ora
可以看到已经有密码文件了orapworcl,可以再强制重新生成下:
[oracle@apollo dbs]$ orapwd file=orapworcl password=123456 force=y
force=y表示强制覆盖有的密码文件,接下来将密码文件SCP拷贝至备机:
[oracle@apollo dbs]$ scp orapworcl oracle@10.211.55.101:$ORACLE_HOME/dbs/orapworcl
oracle@10.211.55.101's password:
orapworcl 100% 1536 2.3MB/s 00:00
3:主库上创建standby redolog日志组。
standby redo log日志组数量=(每个实例日志组个数+1)*实例数
查询一下当前实例日志组个数:
SQL> select thread#,group#,bytes/1024/1024 from v$log;
THREAD# GROUP# BYTES/1024/1024
---------- ---------- ---------------
1 1 50
1 2 50
1 3 50
当前实例日志组个数为3,所以需要至少需要创建(3+1)*1=4组standby redolog,大小均为50M。
查看当前的日志组及其成员:
SQL> col member for a50
SQL> select group#,member from v$logfile;
GROUP# MEMBER
---------- --------------------------------------------------
3 /u01/app/oracle/oradata/orcl/redo03.log
2 /u01/app/oracle/oradata/orcl/redo02.log
1 /u01/app/oracle/oradata/orcl/redo01.log
新建4个standby redolog日志组,编号从4开始:
SQL> alter database add standby logfile group 4 '/u01/app/oracle/oradata/orcl/standby_redo04.log' size 50M;
Database altered.
SQL> alter database add standby logfile group 5 '/u01/app/oracle/oradata/orcl/standby_redo05.log' size 50M;
Database altered.
SQL> alter database add standby logfile group 6 '/u01/app/oracle/oradata/orcl/standby_redo06.log' size 50M;
Database altered.
SQL> alter database add standby logfile group 7 '/u01/app/oracle/oradata/orcl/standby_redo07.log' size 50M;
Database altered.
再看日志组成员情况:
SQL> set pagesize 100
SQL> col member for a60
SQL> select group#,member from v$logfile order by group#;
GROUP# MEMBER
---------- ------------------------------------------------------------
1 /u01/app/oracle/oradata/orcl/redo01.log
2 /u01/app/oracle/oradata/orcl/redo02.log
3 /u01/app/oracle/oradata/orcl/redo03.log
4 /u01/app/oracle/oradata/orcl/standby_redo04.log
5 /u01/app/oracle/oradata/orcl/standby_redo05.log
6 /u01/app/oracle/oradata/orcl/standby_redo06.log
7 /u01/app/oracle/oradata/orcl/standby_redo07.log
7 rows selected.
查询结果显示添加成功。
4:修改主库和备库监听文件,设置静态监听。
主库的listener.ora文件改成:
[oracle@apollo dbs]$ cd ../network/admin/
[oracle@apollo admin]$ cat listener.ora
SID_LIST_LISTENER=
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME= orcl)
(ORACLE_HOME=/u01/app/oracle/product/11.2.0/dbhome_1)
(SID_NAME=orcl)
)
)
LISTENER =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1521))
(ADDRESS = (PROTOCOL = TCP)(HOST = 10.211.55.100)(PORT = 1521))
)
)
ADR_BASE_LISTENER = /u01/app/oracle
备库的listener.ora文件:
[oracle@neptune admin]$ cat listener.ora
SID_LIST_LISTENER=
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME= orcl)
(ORACLE_HOME=/u01/app/oracle/product/11.2.0/dbhome_1)
(SID_NAME=orcl)
)
)
LISTENER =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1521))
(ADDRESS = (PROTOCOL = TCP)(HOST = 10.211.55.101)(PORT = 1521))
)
)
ADR_BASE_LISTENER = /u01/app/oracle
主库和备库的监听文件listener.ora按照上面改好后,重启监听服务:
重启主库的监听:
[oracle@apollo admin]$ lsnrctl stop
LSNRCTL for Linux: Version 11.2.0.1.0 - Production on 27-FEB-2020 21:12:01
Copyright (c) 1991, 2009, Oracle. All rights reserved.
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=IPC)(KEY=EXTPROC1521)))
The command completed successfully
[oracle@apollo admin]$ lsnrctl start
LSNRCTL for Linux: Version 11.2.0.1.0 - Production on 27-FEB-2020 21:12:09
Copyright (c) 1991, 2009, Oracle. All rights reserved.
Starting /u01/app/oracle/product/11.2.0/dbhome_1/bin/tnslsnr: please wait...
TNSLSNR for Linux: Version 11.2.0.1.0 - Production
System parameter file is /u01/app/oracle/product/11.2.0/dbhome_1/network/admin/listener.ora
Log messages written to /u01/app/oracle/diag/tnslsnr/apollo/listener/alert/log.xml
Listening on: (DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
Listening on: (DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=10.211.55.100)(PORT=1521)))
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=IPC)(KEY=EXTPROC1521)))
STATUS of the LISTENER
------------------------
Alias LISTENER
Version TNSLSNR for Linux: Version 11.2.0.1.0 - Production
Start Date 27-FEB-2020 21:12:09
Uptime 0 days 0 hr. 0 min. 0 sec
Trace Level off
Security ON: Local OS Authentication
SNMP OFF
Listener Parameter File /u01/app/oracle/product/11.2.0/dbhome_1/network/admin/listener.ora
Listener Log File /u01/app/oracle/diag/tnslsnr/apollo/listener/alert/log.xml
Listening Endpoints Summary...
(DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=10.211.55.100)(PORT=1521)))
Services Summary...
Service "orcl" has 1 instance(s).
Instance "orcl", status UNKNOWN, has 1 handler(s) for this service...
The command completed successfully
重启备库的监听:
[oracle@neptune admin]$ lsnrctl stop
LSNRCTL for Linux: Version 11.2.0.1.0 - Production on 27-FEB-2020 21:12:52
Copyright (c) 1991, 2009, Oracle. All rights reserved.
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=IPC)(KEY=EXTPROC1521)))
The command completed successfully
[oracle@neptune admin]$ lsnrctl start
LSNRCTL for Linux: Version 11.2.0.1.0 - Production on 27-FEB-2020 21:13:00
Copyright (c) 1991, 2009, Oracle. All rights reserved.
Starting /u01/app/oracle/product/11.2.0/dbhome_1/bin/tnslsnr: please wait...
TNSLSNR for Linux: Version 11.2.0.1.0 - Production
System parameter file is /u01/app/oracle/product/11.2.0/dbhome_1/network/admin/listener.ora
Log messages written to /u01/app/oracle/diag/tnslsnr/neptune/listener/alert/log.xml
Listening on: (DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
Listening on: (DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=10.211.55.101)(PORT=1521)))
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=IPC)(KEY=EXTPROC1521)))
STATUS of the LISTENER
------------------------
Alias LISTENER
Version TNSLSNR for Linux: Version 11.2.0.1.0 - Production
Start Date 27-FEB-2020 21:13:00
Uptime 0 days 0 hr. 0 min. 0 sec
Trace Level off
Security ON: Local OS Authentication
SNMP OFF
Listener Parameter File /u01/app/oracle/product/11.2.0/dbhome_1/network/admin/listener.ora
Listener Log File /u01/app/oracle/diag/tnslsnr/neptune/listener/alert/log.xml
Listening Endpoints Summary...
(DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=10.211.55.101)(PORT=1521)))
Services Summary...
Service "orcl" has 1 instance(s).
Instance "orcl", status UNKNOWN, has 1 handler(s) for this service...
The command completed successfully
5:编辑主库和备库的网络服务名tnsname.ora文件。
主库的:
备库的:
即主库和备库的tnsnames.ora文件是一模一样的。
配好后,tnsping一下对方,看是否通的:
主库tnsping备库:
[oracle@apollo admin]$ tnsping STANDBY
TNS Ping Utility for Linux: Version 11.2.0.1.0 - Production on 27-FEB-2020 21:23:39
Copyright (c) 1997, 2009, Oracle. All rights reserved.
Used parameter files:
Used TNSNAMES adapter to resolve the alias
Attempting
to contact (DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL =
TCP)(HOST = 10.211.55.101)(PORT = 1521))) (CONNECT_DATA = (SID = orcl)))
OK (0 msec)
备库tnsping主库:
[oracle@neptune admin]$ tnsping PRIMARY
TNS Ping Utility for Linux: Version 11.2.0.1.0 - Production on 27-FEB-2020 21:26:01
Copyright (c) 1997, 2009, Oracle. All rights reserved.
Used parameter files:
Used TNSNAMES adapter to resolve the alias
Attempting
to contact (DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL =
TCP)(HOST = 10.211.55.100)(PORT = 1521))) (CONNECT_DATA = (SID = orcl)))
OK (10 msec)
6:修改主库的pfile文件。
查看主库spfile文件位置:
SQL> show parameter spfile;
NAME TYPE
------------------------------------ ----------------------
VALUE
------------------------------
spfile string
/u01/app/oracle/product/11.2.0
/dbhome_1/dbs/spfileorcl.ora
创建一个pfile用于修改:
SQL> create pfile from spfile;
File created.
去修改创建的pfile文件:
[oracle@apollo admin]$ cd /$ORACLE_HOME/dbs
[oracle@apollo dbs]$ ls
hc_DBUA0.dat hc_orcl.dat init.ora initorcl.ora lkORCL orapworcl spfileorcl.ora
[oracle@apollo dbs]$ vi initorcl.ora
编辑后的文件内容如下(红框部分为新增):
orcl.__db_cache_size=180355072orcl.__java_pool_size=16777216orcl.__large_pool_size=4194304orcl.__oracle_base='/u01/app/oracle'#ORACLE_BASE set from environment orcl.__pga_aggregate_target=289406976orcl.__sga_target=545259520orcl.__shared_io_pool_size=0orcl.__shared_pool_size=322961408orcl.__streams_pool_size=8388608*.audit_file_dest='/u01/app/oracle/admin/orcl/adump'*.audit_trail='db'*.compatible='11.2.0.0.0'*.control_files='/u01/app/oracle/oradata/orcl/control01.ctl','/u01/app/oracle/flash_recovery_area/orcl/control02.ctl'*.db_block_size=8192*.db_domain=''*.db_name='orcl'*.db_recovery_file_dest='/u01/app/oracle/flash_recovery_area'*.db_recovery_file_dest_size=4070572032*.diagnostic_dest='/u01/app/oracle'*.dispatchers='(PROTOCOL=TCP) (SERVICE=orclXDB)'*.memory_target=834666496*.open_cursors=300*.processes=150*.remote_login_passwordfile='EXCLUSIVE'*.undo_tablespace='UNDOTBS1'*.fal_client='PRIMARY'*.fal_server='STANDBY'*.log_archive_config='DG_CONFIG=(PRIMARY,STANDBY)'*.log_archive_dest_1='location=/u01/app/oracle/oradata/orcl/arc valid_for=(all_logfiles,all_roles) db_unique_name=PRIMARY'*.log_archive_dest_2='service=STANDBY lgwr async valid_for=(online_logfiles,primary_role) db_unique_name=STANDBY'*.standby_file_management='AUTO'*.db_unique_name='PRIMARY'
在主库手动创建arc目录:
[oracle@apollo dbs]$ cd /u01/app/oracle/oradata/orcl
[oracle@apollo orcl]$ mkdir arc
从pfile创建spfile,然后从spfile重启数据库:
[oracle@apollo orcl]$ sqlplus / as sysdba
SQL*Plus: Release 11.2.0.1.0 Production on Thu Feb 27 22:05:25 2020
Copyright (c) 1982, 2009, Oracle. All rights reserved.
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> create spfile from pfile;
File created.
启动数据库,检查对pfile的修改已经生效:
SQL> startup
ORACLE instance started.
Total System Global Area 830930944 bytes
Fixed Size 2217912 bytes
Variable Size 641730632 bytes
Database Buffers 180355072 bytes
Redo Buffers 6627328 bytes
Database mounted.
Database opened.
SQL> archive log list;
Database log mode Archive Mode
Automatic archival Enabled
Archive destination /u01/app/oracle/oradata/orcl/arc
Oldest online log sequence 96
Next log sequence to archive 98
Current log sequence 98
从上面的Archive destination /u01/app/oracle/oradata/orcl/arc可以看出pfile已经生效了。
查看数据库是否用spfile启动:
SQL> show parameter spfile;
NAME TYPE
------------------------------------ ----------------------
VALUE
------------------------------
spfile string
/u01/app/oracle/product/11.2.0
/dbhome_1/dbs/spfileorcl.ora
可以看到spfile的路径,说明是从spfile启动的。
7:修改备库的pfile文件,并用新的pfile创建spfile后重启备库。
直接将pfile从主库拷贝到备库,然后在备库修改pfile文件:
[oracle@apollo dbs]$ ls
hc_DBUA0.dat hc_orcl.dat init.ora initorcl.ora lkORCL lkPRIMARY orapworcl spfileorcl.ora
[oracle@apollo dbs]$ pwd
/u01/app/oracle/product/11.2.0/dbhome_1/dbs
[oracle@apollo dbs]$ scp initorcl.ora oracle@10.211.55.101:/u01/app/oracle/product/11.2.0/dbhome_1/dbs
oracle@10.211.55.101's password:
initorcl.ora 100% 1305 1.7MB/s 00:00
去备库修改文件:
orcl.__db_cache_size=180355072orcl.__java_pool_size=16777216orcl.__large_pool_size=4194304orcl.__oracle_base='/u01/app/oracle'#ORACLE_BASE set from environment orcl.__pga_aggregate_target=289406976orcl.__sga_target=545259520orcl.__shared_io_pool_size=0orcl.__shared_pool_size=322961408orcl.__streams_pool_size=8388608*.audit_file_dest='/u01/app/oracle/admin/orcl/adump'*.audit_trail='db'*.compatible='11.2.0.0.0'*.control_files='/u01/app/oracle/oradata/orcl/control01.ctl','/u01/app/oracle/flash_recovery_area/orcl/control02.ctl'*.db_block_size=8192*.db_domain=''*.db_name='orcl'*.db_recovery_file_dest='/u01/app/oracle/flash_recovery_area'*.db_recovery_file_dest_size=4070572032*.diagnostic_dest='/u01/app/oracle'*.dispatchers='(PROTOCOL=TCP) (SERVICE=orclXDB)'*.memory_target=834666496*.open_cursors=300*.processes=150*.remote_login_passwordfile='EXCLUSIVE'*.undo_tablespace='UNDOTBS1'*.fal_client='STANDBY'*.fal_server='PRIMARY'*.log_archive_config='DG_CONFIG=(PRIMARY,STANDBY)'*.log_archive_dest_1='location=/u01/app/oracle/oradata/orcl/arc valid_for=(all_logfiles,all_roles) db_unique_name=STANDBY'*.log_archive_dest_2='service=STANDBY lgwr async valid_for=(online_logfiles,primary_role) db_unique_name=PRIMARY'*.standby_file_management='AUTO'*.db_unique_name='STANDBY'*.db_file_name_convert='/u01/app/oracle/oradata/orcl','/u01/app/oracle/oradata/orcl'*.log_file_name_convert='/u01/app/oracle/oradata/orcl','/u01/app/oracle/oradata/orcl'
备库上手工创建相应目录:
[oracle@neptune dbs]$ pwd
/u01/app/oracle/product/11.2.0/dbhome_1/dbs
[oracle@neptune dbs]$ cd /u01/app/oracle/oradata/
[oracle@neptune oradata]$ mkdir arc
[oracle@neptune orcl]$ pwd
/u01/app/oracle/oradata/orcl
[oracle@neptune orcl]$ mkdir adump
备库上从pfile创建spfile,重启数据库至nomount状态
SQL> create spfile from pfile;
File created.
SQL> startup nomount;
ORACLE instance started.
Total System Global Area 830930944 bytes
Fixed Size 2217912 bytes
Variable Size 641730632 bytes
Database Buffers 180355072 bytes
Redo Buffers 6627328 bytes
8:利用RMAN在备库上恢复主库。
oracle@neptune orcl]$ rman target sys/123456@primary auxiliary sys/123456@standby
Recovery Manager: Release 11.2.0.1.0 - Production on Thu Feb 27 22:46:44 2020
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
connected to target database: ORCL (DBID=1529715921)
connected to auxiliary database: ORCL (not mounted)
执行恢复:
RMAN> duplicate target database for standby from active database nofilenamecheck;
Starting Duplicate Db at 27-FEB-20
using target database control file instead of recovery catalog
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=134 device type=DISK
contents of Memory Script:
{
backup as copy reuse
targetfile '/u01/app/oracle/product/11.2.0/dbhome_1/dbs/orapworcl' auxiliary format
'/u01/app/oracle/product/11.2.0/dbhome_1/dbs/orapworcl' ;
}
executing Memory Script
Starting backup at 27-FEB-20
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=145 device type=DISK
Finished backup at 27-FEB-20
contents of Memory Script:
{
backup as copy current controlfile for standby auxiliary format '/u01/app/oracle/oradata/orcl/control01.ctl';
restore clone controlfile to '/u01/app/oracle/flash_recovery_area/orcl/control02.ctl' from
'/u01/app/oracle/oradata/orcl/control01.ctl';
}
executing Memory Script
Starting backup at 27-FEB-20
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/dbhome_1/dbs/snapcf_orcl.f tag=TAG20200227T224847 RECID=1 STAMP=1033512527
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
Finished backup at 27-FEB-20
Starting restore at 27-FEB-20
using channel ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: copied control file copy
Finished restore at 27-FEB-20
contents of Memory Script:
{
sql clone 'alter database mount standby database';
}
executing Memory Script
sql statement: alter database mount standby database
contents of Memory Script:
{
set newname for tempfile 1 to
"/u01/app/oracle/oradata/orcl/temp01.dbf";
switch clone tempfile all;
set newname for datafile 1 to
"/u01/app/oracle/oradata/orcl/system01.dbf";
set newname for datafile 2 to
"/u01/app/oracle/oradata/orcl/sysaux01.dbf";
set newname for datafile 3 to
"/u01/app/oracle/oradata/orcl/undotbs01.dbf";
set newname for datafile 4 to
"/u01/app/oracle/oradata/orcl/users01.dbf";
set newname for datafile 5 to
"/u01/app/oracle/oradata/orcl/pides_01.dbf";
backup as copy reuse
datafile 1 auxiliary format
"/u01/app/oracle/oradata/orcl/system01.dbf" datafile
2 auxiliary format
"/u01/app/oracle/oradata/orcl/sysaux01.dbf" datafile
3 auxiliary format
"/u01/app/oracle/oradata/orcl/undotbs01.dbf" datafile
4 auxiliary format
"/u01/app/oracle/oradata/orcl/users01.dbf" datafile
5 auxiliary format
"/u01/app/oracle/oradata/orcl/pides_01.dbf" ;
sql 'alter system archive log current';
}
executing Memory Script
executing command: SET NEWNAME
renamed tempfile 1 to /u01/app/oracle/oradata/orcl/temp01.dbf in control file
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
Starting backup at 27-FEB-20
using channel ORA_DISK_1
channel ORA_DISK_1: starting datafile copy
input datafile file number=00004 name=/u01/app/oracle/oradata/orcl/users01.dbf
output file name=/u01/app/oracle/oradata/orcl/users01.dbf tag=TAG20200227T224855
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:35
channel ORA_DISK_1: starting datafile copy
input datafile file number=00005 name=/u01/app/oracle/oradata/orcl/pides_01.dbf
output file name=/u01/app/oracle/oradata/orcl/pides_01.dbf tag=TAG20200227T224855
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile copy
input datafile file number=00001 name=/u01/app/oracle/oradata/orcl/system01.dbf
output file name=/u01/app/oracle/oradata/orcl/system01.dbf tag=TAG20200227T224855
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07
channel ORA_DISK_1: starting datafile copy
input datafile file number=00002 name=/u01/app/oracle/oradata/orcl/sysaux01.dbf
output file name=/u01/app/oracle/oradata/orcl/sysaux01.dbf tag=TAG20200227T224855
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile copy
input datafile file number=00003 name=/u01/app/oracle/oradata/orcl/undotbs01.dbf
output file name=/u01/app/oracle/oradata/orcl/undotbs01.dbf tag=TAG20200227T224855
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
Finished backup at 27-FEB-20
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=1 STAMP=1033512627 file name=/u01/app/oracle/oradata/orcl/system01.dbf
datafile 2 switched to datafile copy
input datafile copy RECID=2 STAMP=1033512627 file name=/u01/app/oracle/oradata/orcl/sysaux01.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=3 STAMP=1033512627 file name=/u01/app/oracle/oradata/orcl/undotbs01.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=4 STAMP=1033512627 file name=/u01/app/oracle/oradata/orcl/users01.dbf
datafile 5 switched to datafile copy
input datafile copy RECID=5 STAMP=1033512627 file name=/u01/app/oracle/oradata/orcl/pides_01.dbf
Finished Duplicate Db at 27-FEB-20
RMAN>
至此,ADG搭建完成,补充说明下duplicate target database for standby from active database nofilenamecheck;这个命令,这个命令可以直接恢复数据文件、standby日志文件和控制文件。
9:检查主库和备库的归档序列号是否一致。
主库(先手动切换一下日志文件):
SQL> alter system switch logfile;
System altered.
SQL> archive log list;
Database log mode Archive Mode
Automatic archival Enabled
Archive destination /u01/app/oracle/oradata/orcl/arc
Oldest online log sequence 100
Next log sequence to archive 102
Current log sequence 102
SQL>
备库:
RMAN> quit
Recovery Manager complete.
[oracle@neptune orcl]$ sqlplus / as sysdba
SQL*Plus: Release 11.2.0.1.0 Production on Thu Feb 27 22:53:20 2020
Copyright (c) 1982, 2009, Oracle. All rights reserved.
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
SQL> archive log list;
Database log mode Archive Mode
Automatic archival Enabled
Archive destination /u01/app/oracle/oradata/orcl/arc
Oldest online log sequence 100
Next log sequence to archive 0
Current log sequence 102
可见主库和备库的归档序列号是一致的。
10:后续操作。
备库恢复完成后,数据库的状态是mounted,并且此时DG的保护模式是最高性能,查询备库:
SQL> select database_role,protection_mode,protection_level,open_mode from v$database;
DATABASE_ROLE PROTECTION_MODE
-------------------------------- ----------------------------------------
PROTECTION_LEVEL
----------------------------------------
OPEN_MODE
----------------------------------------
PHYSICAL STANDBY MAXIMUM PERFORMANCE
MAXIMUM PERFORMANCE
MOUNTED
SQL>
一般的可以将备库设置成只读模式以便启用备机实时查询:
在备库上执行:
SQL> shutdown immediate
ORA-01109: database not open
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.
Total System Global Area 830930944 bytes
Fixed Size 2217912 bytes
Variable Size 641730632 bytes
Database Buffers 180355072 bytes
Redo Buffers 6627328 bytes
Database mounted.
Database opened.
SQL>
SQL> select process,client_process,sequence#,status from v$managed_standby;
PROCESS CLIENT_PROCESS SEQUENCE# STATUS
------------------ ---------------- ---------- ------------------------
ARCH ARCH 103 CLOSING
ARCH ARCH 0 CONNECTED
ARCH ARCH 0 CONNECTED
ARCH ARCH 102 CLOSING
RFS N/A 0 IDLE
RFS LGWR 104 IDLE
6 rows selected.
SQL> recover managed standby database using current logfile disconnect from session
Media recovery complete.
SQL> select process,client_process,sequence#,status from v$managed_standby;
PROCESS CLIENT_PROCESS SEQUENCE# STATUS
------------------ ---------------- ---------- ------------------------
ARCH ARCH 103 CLOSING
ARCH ARCH 0 CONNECTED
ARCH ARCH 0 CONNECTED
ARCH ARCH 102 CLOSING
RFS N/A 0 IDLE
RFS LGWR 104 IDLE
MRP0 N/A 104 APPLYING_LOG
7 rows selected.
SQL>
在主库创建一个表并执行插入数据:
SQL> create table test_sync(id varchar2(100));
Table created.
SQL> insert into test_sync values('111');
1 row created.
SQL> commit;
Commit complete.
去备库查询:
[oracle@neptune orcl]$ sqlplus orcl/123456
SQL*Plus: Release 11.2.0.1.0 Production on Thu Feb 27 23:21:04 2020
Copyright (c) 1982, 2009, Oracle. All rights reserved.
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
SQL> select * from test_sync;
ID
--------------------------------------------------------------------------------
111
SQL>
可以正常同步!
日常维护,只需要使用下面的语句检查主库和备库的v$archived_log视图即可:
select * from (select SEQUENCE#,FIRST_TIME,NEXT_TIME,APPLIED from v$archived_log order by 1 desc) where rownum<10 ;
主库:
SQL> select * from (select SEQUENCE#,FIRST_TIME,NEXT_TIME,APPLIED from v$archived_log order by 1 desc) where rownum<10 ;
SEQUENCE# FIRST_TIME NEXT_TIME APPLIED
---------- ------------ ------------ ------------------
103 27-FEB-20 27-FEB-20 NO
103 27-FEB-20 27-FEB-20 NO
102 27-FEB-20 27-FEB-20 NO
102 27-FEB-20 27-FEB-20 YES
101 27-FEB-20 27-FEB-20 YES
101 27-FEB-20 27-FEB-20 NO
100 27-FEB-20 27-FEB-20 NO
100 27-FEB-20 27-FEB-20 YES
99 27-FEB-20 27-FEB-20 NO
9 rows selected.
SQL>
备库:
SQL> select * from (select SEQUENCE#,FIRST_TIME,NEXT_TIME,APPLIED from v$archived_log order by 1 desc) where rownum<10 ;
SEQUENCE# FIRST_TIME NEXT_TIME APPLIED
---------- ------------ ------------ ------------------
103 27-FEB-20 27-FEB-20 IN-MEMORY
102 27-FEB-20 27-FEB-20 YES
101 27-FEB-20 27-FEB-20 YES
100 27-FEB-20 27-FEB-20 YES
99 27-FEB-20 27-FEB-20 YES
98 27-FEB-20 27-FEB-20 YES
6 rows selected.
SQL>
有部分日志还没有被应用,主要是因为日志还没归档,可以执行alter system switch logfile;后再查看。
因为是自己的电脑上搭建的,避免不了要经常关闭和启动ADG环境:
关闭ADG环境步骤:
主库shutdown——备库取消应用归档日志——关闭备库——关闭主库和备库的lsnrctl监听。
1:主库上:SQL> shutdown immediate
2:备库上:SQL> alter database recover managed standby database cancel;
3:备库上:SQL> shutdown immediate
4:主库和备库:
[oracle@apollo ~]$ lsnrctl stop
[oracle@neptune ~]$ lsnrctl stop
启动ADG环境步骤:
启动主库和备库lsnrctl监听——启动备库——启动主库——切换主库日志
1:主库和备库:
[oracle@apollo ~]$ lsnrctl start
[oracle@neptune ~]$ lsnrctl start
2:启动备库:
SQL> startup nomount
SQL> alter database mount standby database;
SQL> alter database open;
SQL> alter database recover managed standby database using current logfile disconnect from session;
3:启动主库:
SQL> startup
4:切换主库日志
SQL> alter system switch logfile;
备库将开始应用主库传输过来的归档日志。
具体的ADG运维又是另一块内容了,涉及较多知识,后续再在此基础上研究。
发表评论