ORACLE 11gR2 DG(Physical Standby)日常维护02

环境:RHEL 6.5 + Oracle 11.2.0.4

三、监控DG的状态

四、备库切换为snapshot standby

五、备库还原为physical standby

三、监控DG的状态

3.1 监控DG备库的状态

在备库查询v$dataguard_stats视图信息:

--format
set linesize 120
col NAME for a25
col VALUE for a18
col UNIT for a30
col TIME_COMPUTED for a20
col DATUM_TIME for a20
--select v$dataguard_stats
select * from v$dataguard_stats;

上面语句的查询结果类似下面输出:

SQL> select * from v$dataguard_stats;

NAME                      VALUE              UNIT                           TIME_COMPUTED        DATUM_TIME
------------------------- ------------------ ------------------------------ -------------------- --------------------
transport lag             +00 00:00:00       day(2) to second(0) interval   11/18/2016 21:49:47  11/18/2016 21:49:47
apply lag                 +00 00:00:00       day(2) to second(0) interval   11/18/2016 21:49:47  11/18/2016 21:49:47
apply finish time         +00 00:00:00.000   day(2) to second(3) interval   11/18/2016 21:49:47
estimated startup time    23                 second                         11/18/2016 21:49:47

理解v$dataguard_stats视图信息含义:

参考11.2版本的官方文档,

Name of the metric:
APPLY FINISH TIME – An estimate of the time needed to apply all received, but unapplied redo from the primary database. If there are one or more redo gaps on the standby database, an estimate of the time needed to apply all received, but unapplied redo up to the end of the last archived redo log before the beginning of the earliest redo gap.
APPLY LAG – Apply lag is a measure of the degree to which the data in a standby database lags behind the data in the primary database, due to delays in propagating and applying redo to the standby database.
TRANSPORT LAG – Transport lag is a measure of the degree to which the transport of redo to the standby database lags behind the generation of redo on the primary database. If there are one or more redo gaps on the standby database, the transport lag is calculated as if no redo has been received after the beginning of the earliest redo gap.
ESTIMATED STARTUP TIME – An estimate of the time needed to start and open the database.

如果是10.2版本的官方文档,有一些差异:

APPLY FINISH TIME: Estimated time before log apply services will finish applying the redo data available on the standby database. If there are gaps in the log files, this parameter shows the time it will take to resolve the gap with the lowest SCN.
APPLY LAG: Amount of time that the application of redo data on the standby database lags behind the primary database.
TRANSPORT LAG: How much redo data (in time units) generated by the primary database is not available or applicable on the standby database at the time of computation.
Note: This parameter includes the redo data that has not been transmitted to the standby database and redo data that is available on the standby database but has not been applied yet, such as the redo data for resolving a gap.
ESTIMATED STARTUP TIME: Estimated time the physical standby database was started. This is not displayed for logical standby databases.
STANDBY HAS BEEN OPEN: Indicates if the physical standby database was opened in read-only mode at any time since the last time the database was started. The parameter value indicates if the instance must be stopped and restarted after a failover. If the physical standby database has been opened in read-only mode since the last time it was started and it is the target of a failover, you must shut down the database and restart it in read/write mode. If the primary database must be shutdown and restarted, use the sum of APPLY FINISH TIME and ESTIMATED STARTUP TIME to obtain an estimated failover time (the estimate assumes SHUTDOWN ABORT).

3.2 监控主库传输日志链路的状态

监控主库传输日志链路的状态:

show parameter log_archive_dest_
show parameter log_archive_dest_state_
select value from v$parameter where name='log_archive_dest_state_3';
select value from v$parameter where name='log_archive_dest_3';
select error from v$archive_dest where dest_id=3;

查询结果类似下面输出:

SQL> select value from v$parameter where name='log_archive_dest_state_3';

VALUE
--------------------------------------------------------------------------------
enable

SQL> select value from v$parameter where name='log_archive_dest_3';

VALUE
--------------------------------------------------------------------------------
SERVICE=jyzhao_s LGWR ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) db_unique_n
ame=jyzhao_s


SQL> select error from v$archive_dest where dest_id=3;

ERROR
-----------------------------------------------------------------

四、备库切换为snapshot standby后测试

4.1 备库切换为snapshot standby

查看参数值:

show parameter db_recovery_file_dest
--如果返回值为空,则设置一个合理的值:
Alter system set db_recovery_file_dest_size=1000G scope=spfile;
Alter system set db_recovery_file_dest='+DATA' scope=spfile;

核心步骤:

--取消日志应用
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE CANCEL;
--查询当前数据库SCN
select to_char(current_scn) from v$database; 
--确定job_queue_processes值为0
show parameter job_queue_processes
alter system set job_queue_processes=0;
--重启数据库到mount状态
shutdown immediate
startup mount;
select database_role, open_mode from v$database;
--切换数据库到snapshot standby
alter database convert to snapshot standby;
--重新启动数据库
shutdown immediate
startup;
select database_role, open_mode from v$database;

操作过程类似如下:

SQL> show parameter db_recovery_file_dest

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
db_recovery_file_dest                string      /u01/app/oracle/fra
db_recovery_file_dest_size           big integer 4407M
SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE CANCEL;


Database altered.

SQL> SQL> select to_char(current_scn) from v$database; 

TO_CHAR(CURRENT_SCN)
----------------------------------------
1935528

SQL> show parameter job_queue_processes

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
job_queue_processes                  integer     1000
SQL> alter system set job_queue_processes=0;

System altered.

SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount;
ORACLE instance started.

Total System Global Area  221331456 bytes
Fixed Size                  2251856 bytes
Variable Size             163578800 bytes
Database Buffers           50331648 bytes
Redo Buffers                5169152 bytes
Database mounted.
SQL> select database_role, open_mode from v$database;

DATABASE_ROLE    OPEN_MODE
---------------- --------------------
PHYSICAL STANDBY MOUNTED

SQL> alter database convert to snapshot standby;

Database altered.

SQL> select database_role, open_mode from v$database;

DATABASE_ROLE    OPEN_MODE
---------------- --------------------
SNAPSHOT STANDBY MOUNTED

SQL> shutdown immediate
ORA-01109: database not open


Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.

Total System Global Area  221331456 bytes
Fixed Size                  2251856 bytes
Variable Size             163578800 bytes
Database Buffers           50331648 bytes
Redo Buffers                5169152 bytes
Database mounted.
Database opened.
SQL> select open_mode, database_role from v$database;

OPEN_MODE            DATABASE_ROLE
-------------------- ----------------
READ WRITE           SNAPSHOT STANDBY

4.2 开始读写测试

连接到业务用户jingyu下,删除原有的test表并清空用户回收站:

SQL> conn jingyu/jingyu
Connected.
SQL> select * from cat;

TABLE_NAME                     TABLE_TYPE
------------------------------ -----------
BIN$QSRM4jesEATgU544qMBwAw==$0 TABLE
T1                             TABLE
T2                             TABLE
TEST                           TABLE

SQL> drop table test;

Table dropped.

SQL> select * from cat;

TABLE_NAME                     TABLE_TYPE
------------------------------ -----------
BIN$QSRM4jesEATgU544qMBwAw==$0 TABLE
BIN$QaFQkzu4C/XgU544qMAz3Q==$0 TABLE
T1                             TABLE
T2                             TABLE

SQL> purge user_recyclebin;

Recyclebin purged.

SQL> select * from cat;

TABLE_NAME                     TABLE_TYPE
------------------------------ -----------
T1                             TABLE
T2                             TABLE

五、备库还原为physical standby

5.1 备库还原为physical standby

参数值确定:

--确定db_recovery_file_dest值及其大小
--选择取消db_recovery_file_dest参数值及其大小的设定
alter system reset db_recovery_file_dest_size sid='*' scope=spfile; 
alter system reset db_recovery_file_dest sid='*' scope=spfile;

--或者选择设置db_recovery_file_dest参数值及其大小为合理值
alter system set db_recovery_file_dest='/u01/app/oracle/fra' sid='*' scope=spfile;
alter system set db_recovery_file_dest_size=4407M sid='*' scope=spfile; 

核心步骤:

--重启数据库至mount状态
SQL> shutdown immediate
SQL> startup mount
--切换数据库到physical standby
SQL> alter database convert to physical standby; 
--重启数据库
SQL> shutdown immediate 
SQL> startup 
--查看当前数据库的scn
select current_scn||'' from v$database
--开启日志应用
alter database recover managed standby database using current logfile disconnect; 
--确定job_queue_processes值
alter system set job_queue_processes=1000;
--查看standby的进程和状态
select process, status from v$managed_standby; 
select database_role, open_mode from v$database;

验证备库的状态信息:

--format
set linesize 120
col NAME for a25
col VALUE for a18
col UNIT for a30
col TIME_COMPUTED for a20
col DATUM_TIME for a20
--select v$dataguard_stats
select * from v$dataguard_stats;

--确定闪回数据库是否开启
SQL> select flashback_on from v$database;

FLASHBACK_ON
------------------
NO

5.2 验证数据还原到切换前状态

--确定snapshot standby期间的所有操作都是回退的;
SQL> conn jingyu/jingyu
Connected.
SQL> select * from cat;

TABLE_NAME                     TABLE_TYPE
------------------------------ -----------
BIN$QSRM4jesEATgU544qMBwAw==$0 TABLE
T1                             TABLE
T2                             TABLE
TEST                           TABLE

实验证明: 11g snapshot standby的确可以很方便的实现读写测试;之后也可以方便的切换回测试前的状态继续做为physical standby使用。

This entry was posted in Oracle日常运维 and tagged . Bookmark the permalink.