目录
一、主备环境
1、主库
操作系统: Windows Server 2003 64bit IP 地址: 192.168.20.148 数据库版本: Oracle 11.2.0.4.0 数据库sid 名: mesorcl 数据库名: mesorcl 数据库db_unique_name : mesorcl 数据文件路径:D:\app\Administrator\oradata\mesorcl 归档路径: D:\app\Administrator\fast_recovery_area\mesorcl\ARCHIVELOG
2、备库
操作系统: Centos Linux 7.9 IP 地址: 192.168.20.248 数据库版本: Oracle 11.2.0.4.0 数据库sid 名: mesorcl 数据库名: mesorcl 数据库db_unique_name:mesorclstd 数据文件路径:/oracle/app/oracle/oradata/和/oracle/oradata/ 归档路径: /oracle/archivelog
二、DG搭建要求
1、db_name:
mesorcl(主备一致)
2、db_unique_name:
主库:mesorcl 备库:mesorclstd
3、instance_name:
mesorcl,mesorcl(主备一致)
三、主库配置
1、启动归档日志
(1)启动归档需要在mount阶段
shutdown immediate; startup mount; alter database archivelog; alter database open;
(2)增大恢复区空间:
SQL>alter system set db_recovery_file_dest_size=200G;
2、查看force logging是否开启并启动
select name,log_mode,force_logging from v$database; alter database force logging;
3、增加standby的redolog
查看日志文件获取redolog文件路径和大小,保证主备redolog的大小是一致的。
(1)查看当前logfile的数量及大小
SQL>select member from v$logfile;
SQL>select bytes/1024/1024 as filesize from v$log;
(2)增加standby的logfile(standby logfile的要求)
①大小与主机大小一致。
②文件数量:
Standby redo log数量>=(每个instance日志组个数+1)*instance实例个数。我们通常为单实例:Standby redo log数量=(3+1)*1=4即可。
alter database add standby logfile group 4 'D:\APP\ADMINISTRATOR\ORADATA\MESORCL\std_redlog04.log' size 50m; alter database add standby logfile group 5 'D:\APP\ADMINISTRATOR\ORADATA\MESORCL\std_redlog05.log' size 50m; alter database add standby logfile group 6 'D:\APP\ADMINISTRATOR\ORADATA\MESORCL\std_redlog06.log' size 50m; alter database add standby logfile group 7 'D:\APP\ADMINISTRATOR\ORADATA\MESORCL\std_redlog07.log' size 50m;
4、查看一下数据文件
SQL> select file_name from dba_data_files; FILE_NAME --------------------------------------------------- D:\APP\ADMINISTRATOR\ORADATA\MESORCL\USERS01.DBF D:\APP\ADMINISTRATOR\ORADATA\MESORCL\UNDOTBS01.DBF D:\APP\ADMINISTRATOR\ORADATA\MESORCL\SYSAUX01.DBF D:\APP\ADMINISTRATOR\ORADATA\MESORCL\SYSTEM01.DBF D:\APP\ADMINISTRATOR\ORADATA\MESORCL\EXAMPLE01.DBF D:\APP\MESDATA\MES_PRD01.DBF
5、创建主备转换目录
根据4中的文件目录,确定所有的数据存放路径
D:\APP\ADMINISTRATOR\ORADATA\MESORCL\
6、主库创建密码并拷贝至备库(或在备库单独创建也可以)
(1)主库创建密码:
orapwd file=D:\app\Administrator\product\11.2.0\dbhome_1\NETWORK\ADMIN\PWDMESORCL.ora password=1qaz2WSX force=y;
(2)备库创建密码:
orapwd file=/oracle/app/oracle/product/11.2.0/db_1/dbs/orapwmesorcl password=1qaz2WSX force=y;
备库改名:因为双方SID一样的,所以无需改名:PWDMESORCL.ora
7、主库参数文件配置
(1)查看配置文件位置,并备份spfile文件
SQL>show parameter spfile;
(2)创建pfie
SQL>create pfile from spfile;
(3)配置pfile
--基本配置
alter system set db_unique_name='mesorcl' scope=spfile; alter system set LOG_ARCHIVE_CONFIG='DG_CONFIG=(mesorcl,mesorclstd)' scope=both; alter system set LOG_ARCHIVE_DEST_1='LOCATION=USE_DB_RECOVERY_FILE_DEST VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=mesorcl' scope=both; alter system set LOG_ARCHIVE_DEST_2='SERVICE=mesorclstd LGWR ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=mesorclstd' scope=both; alter system set fal_client='mesorcl' scope=both;#自己作为备机时填的信息,此处client端填自己的tnsnames的名 alter system set FAL_SERVER='mesorclstd' scope=both;#自己作为备机时填的信息,此处client端填自己的tnsnames的名
--数据目录配置
#注:此处如果数据文件有多个路径,则向后增加对应路径即可如:
alter system set DB_FILE_NAME_CONVERT='D:\APP\ADMINISTRATOR\ORADATA\MESORCL\','/oracle/app/oracle/oradata/mesorcl/','D:\APP\MESData\','/oracle/app/oracle/oradata' scope=spfile; alter system set LOG_FILE_NAME_CONVERT='D:\APP\ADMINISTRATOR\ORADATA\MESORCL\','/oracle/app/oracle/oradata/mesorcl/' scope=spfile; alter system set standby_file_management='AUTO' scope=both;
--重启数据库,是上述配置生效:
SQL>shutdown immediate SQL>startup
8、主库增加如下红色listener静态监听,并重启监听
SID_LIST_LISTENER =
(SID_LIST =
(SID_DESC =
(SID_NAME = CLRExtProc)
(ORACLE_HOME = D:\app\Administrator\product\11.2.0\dbhome_1)
(PROGRAM = extproc)
(ENVS = "EXTPROC_DLLS=ONLY:D:\app\Administrator\product\11.2.0\dbhome_1\bin\oraclr11.dll")
)
(SID_DESC =
(GLOBAL_DBNAME = mesorcl) #此处建议设置为unique_name的值,便于统一和区分主机配置
(ORACLE_HOME = D:\app\Administrator\product\11.2.0\dbhome_1)
(SID_NAME = mesorcl)
)
)
9、修改tnsnames.ora文件,增加备库信息MESORCLSTD
MESORCL= ( DESCRIPTION= (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.20.248)(PORT = 1521)) (CONNECT_DATA= (SERVER = DEDICATED) (SERVICE_NAME = MESORCL) ) )
MESORCLSTD= ( DESCRIPTION= (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.20.245)(PORT = 1521)) (CONNECT_DATA= (SERVER = DEDICATED) (SERVICE_NAME = MESORCLSTD) ) )
四、备库配置
1、启动归档
启动归档需要在mount阶段
SQL> shutdown immediate; SQL> startup mount; SQL> alter database archivelog; SQL> alter database open;
增大恢复区空间:
SQL>alter system set db_recovery_file_dest_size=100G;
2、查看一下数据文件
SQL> select file_name from dba_data_files; /oracle/app/oracle/oradata/mesorcl/system01.dbf /oracle/app/oracle/oradata/mesorcl/sysaux01.dbf /oracle/app/oracle/oradata/mesorcl/undotbs01.dbf /oracle/app/oracle/oradata/mesorcl/users01.dbf
3、创建主备转换目录
【/oracle/app/oracle/oradata/mesorcl/即可】
4、备库参数文件
(1)查看配置文件位置,并备份sfpile文件
SQL>show parameter spfile;
(2)创建pfie
SQL>create pfile from spfile;
(3)通过alter直接配置spfile;
alter system set db_unique_name='mesorclstd' scope=spfile; alter system set LOG_ARCHIVE_CONFIG='DG_CONFIG=(mesorclstd,mesorcl)' scope=both; 下述需要重启数据库,才能把db_unique_name生效; alter system set LOG_ARCHIVE_DEST_1='LOCATION=USE_DB_RECOVERY_FILE_DEST VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=mesorclstd' scope=both; alter system set LOG_ARCHIVE_DEST_2='SERVICE=mesorcl LGWR ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=mesorcl' scope=both; alter system set fal_client='mesorclstd' scope=both; #自己作为备机时填的信息,此处client端填自己的tnsnames的名 alter system set FAL_SERVER='mesorcl' scope=both;#自己作为备机时填的信息,此处server端填对方的tnsnames的名
#注:此处如果数据文件有多个路径,则向后增加对应路径即可如: alter system set DB_FILE_NAME_CONVERT='/oracle/app/oracle/oradata/mesorcl/','/oracle/app/oracle/oradata/mesorcl/' scope=spfile; alter system set LOG_FILE_NAME_CONVERT='/oracle/app/oracle/oradata/mesorcl/','/oracle/app/oracle/oradata/mesorcl/' scope=spfile; alter system set standby_file_management='AUTO' scope=both;
(4)重启数据库
shutdown immediate startup
5、备库增加listener静态监听,并重启监听【此处:global_name=mesorcl 作为静态注册的服务名称】
SID_LIST_LISTENER = (SID_LIST = (SID_DESC = (GLOBAL_DBNAME = mesorclstd) (ORACLE_HOME = /oracle/app/oracle/product/11.2.0/db_1) (SID_NAME = mesorcl) ) )
6、修改tnsnames.ora文件,增加主备的tnsname信
MESORCL= ( DESCRIPTION= (ADDRESS = (PROTOCOL = TCP)(HOST =192.168.20.248)(PORT = 1521)) (CONNECT_DATA= (SERVER = DEDICATED) (SERVICE_NAME = MESORCL) ) )
MESORCLSTD= ( DESCRIPTION= (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.20.245)(PORT = 1521)) (CONNECT_DATA= (SERVER = DEDICATED) (SERVICE_NAME = MESORCLSTD) ) )
五、测试下面是否都通:
1、主库:
tnsping mesorcl和tnsping mesorclstd
2、备库:
tnsping mesorcl和tnsping mesorclstd
六、数据恢复、同步(备库操作)
1、利用RMAN在备库上恢复主库
SQL>shutdown immediate SYS > startup nomount
[oracle@std ~]$ rman target sys/1qaz2WSX@mesorcl auxiliary sys/1qaz2WSX@mesorclstd
原库:sys/1qaz2WSX@mesorcl
备库:sys/1qaz2WSX@mesorclstd
RMAN> duplicate target database for standby from active database nofilenamecheck;#【nofilenamecheck 这个参数在出现RMAN-05001再加上】
这条命令可以直接恢复数据文件,standby控制文件,standby日志组,非常霸道,查看如下日志,上述备库数据同步完成,下面进行登录检查:
2、尝试开启
登陆并查看数据库当前状态
[oracle@std ~]$ sqlplus / as sysdba SYS@std> select status from v$instance;
MOUNTED (RMAN恢复完直接就是mount状态)
七、检查、开启、关闭数据库同步
1、检查Dataguard 状态
SQL>select database_role,protection_mode,protection_level,open_mode from v$database; SQL>select name,open_mode,protection_mode,database_role,switchover_status from v$database;
2、启动dataguard数据库
(备库执行),开启后,数据开始从主库同步至备库[最好手动执行一下SQL> alter system switch logfile;手动归档,数据会立即传输到备库
SQL> alter database recover managed standby database disconnect from session; --归档方式同步(只有主库进行归档了,才会传输最新变更到备库)
或
SQL>alter database recover managed standby database using current logfile disconnect from session; --实时同步(只要主库redolog进行了变化就会变更到备库)
3、关闭datagurade数据同
(备库执行),关闭后,数据不再同步至备库(如果关闭了数据同步功能,即使archivelog从主库同步过来,也不会像备库表中写入数据)
SQL>alter database recover managed standby database cancel;
4、打开数据库,再开启同步数据
SQL>alter database open; SQL>alter database recover managed standby database using current logfile disconnect from session;
5、主库redo 日志归档到archive 日志
SQL> alter system switch logfile;(主库执行)
6、主备库检查dataguard 状态【查看archivelog序列号是否一致,下面两种都可以查看】
SQL>select unique thread#,max(sequence#) over(partition by thread#)last from v$archived_log; SQL>archive log list;【此命令在备库可以用于11g中,在12c及以上就不好用了)
7、检查dataguard日志
主库日志:tail -100f /home/oracle/app/oracle/diag/rdbms/pri/pri/trace/alert_std.log
备库日志:tail -100f /home/oracle/app/oracle/diag/rdbms/std/std/trace/alert_std.log
或使用命令:SQL>select * from v$dataguard_status;
SQL>select * from v$diag_instance;
8、查看日志应用情
SYS@std> set pagesize 10; SYS@std> select sequence#,applied from v$archived_log order by sequence#;
如上,如果发现有个NO的,也是正常的,说明该日志在主库上还没有归档,可以在主库上运行alter system switch logfile;命令来进行日志切换,再到备库查看日志应用
至此,DataGuard的搭建成。
二、 DG 配置准备
1、 DG 配置
3.1 、将主库设置为归档模式
Ø 略
3.2 、设置主库为强制归档模式
Ø SQL>alter database force logging;
3.3 、主库监听配置
Ø listener.ora
SID_LIST_LISTENER=
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME=demo1)
(ORACLE_HOME=/oracle/product/11.2.0/db_1)
(SID_NAME=demo1)
)
(SID_DESC=
(SID_NAME=PLSExtProc)
(ORACLE_HOME=/oracle/product/11.2.0/db_1)
(PROGRAM=extproc)
)
)
LISTENER =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = dg231)(PORT = 1521))
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1521))
)
)
Ø tnsnames.ora
DEMO231 =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 172.168.10.231)(PORT = 1521))
)
(CONNECT_DATA =
(SERVICE_NAME = demo1)
)
)
DEMO233 =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 172.168.10.233)(PORT = 1521))
)
(CONNECT_DATA =
(SERVICE_NAME = demo1)
)
)
3.4 、备库监听配置
Ø listener.ora
SID_LIST_LISTENER=
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME=demo1)
(ORACLE_HOME=C:\oracle\product\11.2.0.3/db_1)
(SID_NAME=demo1)
)
(SID_DESC=
(SID_NAME=PLSExtProc)
(ORACLE_HOME=C:\oracle\product\11.2.0.3/db_1)
(PROGRAM=extproc)
)
)
LISTENER =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = ygdg)(PORT = 1521))
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1521))
)
)
Ø tnsnames.ora
DEMO231 =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 172.168.10.231)(PORT = 1521))
)
(CONNECT_DATA =
(SERVICE_NAME = demo1)
)
)
DEMO233 =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = ygdg)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = demo1)
)
)
3.5 、主库初始化参数修改
Ø 生成pfile 文件( create pfile from spfile )
Ø 修改生成的pfile 文件,添加如下红色部分内容
demo1.__db_cache_size=205520896
demo1.__java_pool_size=4194304
demo1.__large_pool_size=4194304
demo1.__oracle_base='/oracle'#ORACLE_BASE set from environment
demo1.__pga_aggregate_target=218103808
demo1.__sga_target=327155712
demo1.__shared_io_pool_size=0
demo1.__shared_pool_size=104857600
demo1.__streams_pool_size=0
*.audit_file_dest='/oracle/admin/demo1/adump'
*.audit_trail='db'
*.compatible='11.2.0.0.0'
*.control_files='/oradata/demo1/control01.ctl','/oradata/demo1/control02.ctl'
*.db_block_size=8192
*.db_domain=''
*.db_name='demo1'
*.diagnostic_dest='/oracle'
*.dispatchers='(PROTOCOL=TCP) (SERVICE=demo1XDB)'
*.log_archive_dest_1='LOCATION=/oracle/arch'
*.log_archive_format='%t_%s_%r.dbf'
*.memory_target=545259520
*.open_cursors=300
*.processes=150
*.remote_login_passwordfile='EXCLUSIVE'
*.undo_tablespace='UNDOTBS1'
*.db_unique_name=demo231
*.log_archive_config='dg_config=(demo231,demo233)'
*.log_archive_dest_1='location=/oracle/arch VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=demo231'
*.log_archive_dest_2='SERVICE=demo233 LGWR ASYNC VALID_FOR=(ONLINE_LOGFILE,PRIMARY_ROLE) DB_UNIQUE_NAME=demo233'
*.fal_server=demo233
*.fal_client=demo231
*.log_archive_dest_state_1=ENABLE
*.log_archive_dest_state_2=ENABLE
*.log_archive_max_processes=10
*.standby_file_management=AUTO
*.db_file_name_convert='C:\oradata\demo1','/oradata/demo1'
*.log_file_name_convert='C:\oradata\demo1','/oradata/demo1'
Ø 由pfile 文件生成 spfile
SQL>shutdown immediate
SQL>create spfile from pfile;
SQL>startup
3.6 、备库初始化参数修改
Ø 将主库生成的pfile 文件传到备库,修改如下红色部分内容
demo1.__db_cache_size=205520896
demo1.__java_pool_size=4194304
demo1.__large_pool_size=4194304
demo1.__oracle_base='C:\oracle'#ORACLE_BASE set from environment
demo1.__pga_aggregate_target=218103808
demo1.__sga_target=327155712
demo1.__shared_io_pool_size=0
demo1.__shared_pool_size=104857600
demo1.__streams_pool_size=0
*.audit_file_dest='C:\oracle\admin\demo1\adump'
*.audit_trail='db'
*.compatible='11.2.0.0.0'
*.control_files='C:\oradata\demo1\control01.ctl','C:\oradata\demo1\control02.ctl'
*.db_block_size=8192
*.db_domain=''
*.db_name='demo1'
*.diagnostic_dest='C:\oracle'
*.dispatchers='(PROTOCOL=TCP) (SERVICE=demo1XDB)'
*.log_archive_dest_1='LOCATION=C:\oracle\arch'
*.log_archive_format='%t_%s_%r.dbf'
*.memory_target=545259520
*.open_cursors=300
*.processes=150
*.remote_login_passwordfile='EXCLUSIVE'
*.undo_tablespace='UNDOTBS1'
*.db_unique_name=demo233
*.log_archive_config='dg_config=(demo233,demo231)'
*.log_archive_dest_1='location=C:\oracle\arch VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=demo233'
*.log_archive_dest_2='SERVICE=demo231 LGWR ASYNC VALID_FOR=(ONLINE_LOGFILE,PRIMARY_ROLE) DB_UNIQUE_NAME=demo231'
*.fal_server=demo231
*.fal_client=demo233
*.log_archive_dest_state_1=ENABLE
*.log_archive_dest_state_2=ENABLE
*.log_archive_max_processes=10
*.standby_file_management=AUTO
*.db_file_name_convert='/oradata/demo1','C:\oradata\demo1'
*.log_file_name_convert='/oradata/demo1','C:\oradata\demo1'
Ø 生成备库spfile文件
SQL>create spfile from pfile= ’ c:\oracle\initdemo1.ora ’ ;
Ø 将备库启动到nomount状态
SQL>startup nomount
3.7 、添加 standby 日志组
SQL>alter database add standby logfile group 4
>( ‘ /oradata/demo1/redo04.log ’ ) size 50M ;
SQL>alter database add standby logfile group 5
>(‘/oradata/ demo1 /redo05.log’) size 5 0 M;
SQL>alter database add standby logfile group 6
>(‘/oradata/ demo1 /redo06.log’) size 50 M;
SQL>alter database add standby logfile group 7
>( ‘ /oradata/demo1/redo07.log ’ ) size 50M;
3.8 、在主库上使用 rman 进行 duplicate 操作
$ rman target sys/oracle auxiliary sys/oracle@demo233
RMAN> DUPLICATE TARGET DATABASE FOR STANDBY FROM ACTIVE DATABASE NOFILENAMECHECK;
RMAN 恢复完以后会自动将 standby 数据库自动切换到 mount 状态。
3.9 、将备库置于 ADG 模式下
SQL> alter database open read only;
SQL> alter database recover managed standby database using current logfile disconnect from session;
3.10 、数据同步测试
Ø 在主库上以scott 用户执行
SQL>create table emp_test as select * from emp;
SQL>commit;
Ø 在备库上以scott 用执行查询
SQL>select * from emp_test;
4 、主备切换测试
4.1 、主库上查询切换状态(要有 TO STANDBY )
SQL> select switchover_status from v$database ;
SWITCHOVER_STATUS
--------------------
T O STANDBY
查询关闭多余会话
SQL> select program,type from v$session where type='USER';
PROGRAM TYPE
-------------------- ----------
sqlplus@node1 (TNS V1-V3) USER
4.2 、在主库上执行切换
SQL>alter database commit to switchover to physical standby;
4.3 、在备库上执行切换
SQL> alter database commit to switchover to primary ;
如果数据库处于read only 状态,则重启数据库到 open 状态
SQL>shutdown immediate
SQL>startup
否则
SQL>alter database open;
4.4 、重启原主库到 mount 状态,并将其置于 ADG 模式下
SQL> alter database recover managed standby database using current logfile disconnect from session;
4.5 、在新主库上执行日志切换,查看日志是否正常
SQL>ALTER SYSTEM SWITCH LOGFILE;