一、数据库
1、db_name:mesorcl(主备一致)
2、db_unique_name:mesorcl,mesorclstd
3、instance_name:mesorcl,mesorcl(主备一致)
二、主库
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=200G;
2、查看force logging是否开启
SQL> select name,log_mode,force_logging from v$database;
3、启动强制
SQL> alter database force logging;
4、增加standby的redolog
查看日志文件获取redolog文件路径和大小,保证主备redolog的大小是一致的
查看日志文件获取redolog文件路径和大小,保证主备redolog的大小是一致的
(1)查看当前logfile的数量
SQL>select member from v$logfile;
(2)查看当前logfile的大小
SQL>select bytes/1024/1024 as filesize from v$log;
(3)增加standby的logfile
standby logfile的要求:
①大小与主机大小一致,
②文件数量
Standby redo log数量>=(每个instance日志组个数+1)*instance实例个数。我们通常为单实例:
Standby redo log数量=(3+1)*1=4即可。
SQL>alter database add standby logfile group 6 '/oracle/app/oracle/oradata/mesorcl/std_redo06.log' size 200m; SQL>alter database add standby logfile group 7 '/oracle/app/oracle/oradata/mesorcl/std_redo07.log' size 200m; SQL>alter database add standby logfile group 8 '/oracle/app/oracle/oradata/mesorcl/std_redo08.log' size 200m; SQL>alter database add standby logfile group 9 '/oracle/app/oracle/oradata/mesorcl/std_redo09.log' size 200m; SQL>alter database add standby logfile group 10 '/oracle/app/oracle/oradata/mesorcl/std_redo10.log' size 200m; SQL>alter database add standby logfile group 11 '/oracle/app/oracle/oradata/mesorcl/std_redo11.log' size 200m;
5、查看一下数据文件
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
6、创建主备转换目录
【使用当前即可:/oracle/app/oracle/oradata/mesorcl/】
7、主库创建密码并拷贝至备库
主库创建密码: orapwd file=/oracle/app/oracle/product/11.2.0/db_1/dbs/orapwmesorcl password=1qaz2WSX force=y;
备库改名:因为双方SID一样的,所以无需改名:PWDMESORCL.ora
8、主库参数文件配置
(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='/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;
重启数据库,是上述配置生效:
SQL>shutdown immediate SQL>startup
8、主库增加如下红色listener静态监听,并重启监听
SID_LIST_LISTENER = (SID_LIST = (SID_DESC = (GLOBAL_DBNAME = mesorcl) (ORACLE_HOME = /oracle/app/oracle/product/11.2.0/db_1/) (SID_NAME = mesorcl) ) )
9、修改tnsnames.ora文件,增加备库信息MESORCLSTD
MESORCL= ( DESCRIPTION= (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.0.33)(PORT = 1521)) (CONNECT_DATA= (SERVER = DEDICATED) (SERVICE_NAME = MESORCL) ) )
MESORCLSTD= ( DESCRIPTION= (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.10.41)(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;
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.0.33)(PORT = 1521)) (CONNECT_DATA= (SERVER = DEDICATED) (SERVICE_NAME = MESORCL) ) )
MESORCLSTD= ( DESCRIPTION= (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.10.41)(PORT = 1521)) (CONNECT_DATA= (SERVER = DEDICATED) (SERVICE_NAME = MESORCLSTD) ) )
五、测试下面是否都通:
主库:tnsping mesorcl和tnsping mesorclstd
备库:tnsping mesorcl和tnsping mesorclstd
两者都通即可,如果不通,检查listener.ora和tnsnames.ora
六、数据恢复、同步(备库操作)
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的搭建成.
文章评论