技术活动
CUUG学员就业信息
学员感言、就业资讯
报名热线
文档
当前您的位置:首页 > 技术活动 > 技术中心 > 文档
RAC 环境下修改归档模式-CUUG

  RAC环境下的归档模式切换与单实例稍有不同,主要是共享存储所产生的差异。在这种情况下,我们可以将RAC数据库切换到非集群状态下,仅仅在一个实例上来实施归档模式切换即可完成RAC数据库的归档模式转换问题。本文主要描述了由非归档模式切换到归档模式,而由非归档切换的归档步骤相同,不再赘述。

  1、主要步骤:

  备份spfile,以防止参数修改失败导致数据库无法启动

  修改集群参数cluster_database为false

  启动单实例到mount状态

  将数据库置于归档模式(alter database archivelog/noarchivelog)

  修改集群参数cluster_database为true

  关闭单实例

  启动集群数据库

  2、环境

  oracle@bo2dbp:~> cat /etc/issue

  Welcome to SUSE Linux Enterprise Server 10 SP3 (x86_64) - Kernel \r (\l).

  oracle@bo2dbp:~> sqlplus -v

  SQL*Plus: Release 10.2.0.3.0 - Production

  使用asm存储方式存放归档日志

  3、修改集群数据库到归档模式

  oracle@bo2dbp:~> export ORACLE_SID=ora10g1

  oracle@bo2dbp:~> sqlplus / as sysdba

  SQL*Plus: Release 10.2.0.3.0 - Production on Mon Dec 24 16:53:18 2012

  Copyright (c) 1982, 2006, Oracle. All Rights Reserved.

  Connected to:

  Oracle Database 10g Release 10.2.0.3.0 - 64bit Production

  With the Real Application Clusters option

  SQL> archive log list; -->查看当前数据库的归档模式

  Database log mode No Archive Mode -->非归档模式

  Automatic archival Disabled

  Archive destination USE_DB_RECOVERY_FILE_DEST

  Oldest online log sequence 59

  Current log sequence 60

  SQL> select instance_name,host_name,status from gv$instance;

  INSTANCE_NAME HOST_NAME STATUS

  ---------------- -------------------- ------------

  ora10g1 bo2dbp OPEN

  ora10g2 bo2dbs OPEN

  SQL> show parameter cluster -->查看集群的参数,cluster_database为true表示为集群数据库,否则,非集群数据库

  NAME TYPE VALUE

  ------------------------------------ ----------- ------------------------------

  cluster_database boolean TRUE

  cluster_database_instances integer 2

  cluster_interconnects string

  SQL> create pfile='/u01/oracle/db/dbs/ora10g_robin.ora' from spfile; -->先备份spfile

  File created.

  SQL> alter system set cluster_database=false scope=spfile sid='*'; -->修改为非集群数据库,该参数为静态参数,需要使用scope=spfile

  System altered.

  oracle@bo2dbp:~> srvctl stop database -d ora10g -->关闭数据库

  oracle@bo2dbp:~> srvctl start instance -d ora10g -i ora10g1 -o mount -->启动单个实例到mount状态

  oracle@bo2dbp:~> sqlplus / as sysdba

  SQL> select instance_name,status from v$instance;

  INSTANCE_NAME STATUS

  ---------------- ------------

  ora10g1 MOUNTED

  SQL> alter database archivelog; -->改变数据库到归档模式

  Database altered.

  SQL> alter system set cluster_database=true scope=spfile sid='*'; -->在将数据库改为集群模式

  System altered.

  SQL> ho srvctl stop instance -d ora10g -i ora10g1 -->关闭当前实例

  SQL> ho srvctl start database -d ora10g -->启动集群数据库

  SQL> archive log list;

  ORA-03135: connection lost contact

  SQL> conn / as sysdba

  Connected.

  SQL> archive log list; -->查看归档模式

  Database log mode Archive Mode -->已经处于归档模式

  Automatic archival Enabled -->自动归档

  Archive destination USE_DB_RECOVERY_FILE_DEST -->归档位置为参数DB_RECOVERY_FILE_DEST的值

  Oldest online log sequence 60 -->下面是sequence相关信息

  Next log sequence to archive 61

  Current log sequence 61

  SQL> show parameter db_recovery_file

  NAME TYPE VALUE

  ------------------------------------ ----------- ------------------------------

  db_recovery_file_dest string +REV

  db_recovery_file_dest_size big integer 2G

  4、归档验证

  SQL> select inst_id,name,thread#,sequence#,status from gv$archived_log; -->当前无任何归档日志

  no rows selected

  SQL> alter system switch logfile; -->在实例1上进行归档

  System altered.

  SQL> col name format a65

  SQL> select inst_id,name,thread#,sequence#,status from gv$archived_log; -->查看到sequence为61的日志已经归档

  INST_ID NAME THREAD# SEQUENCE# S

  ---------- ----------------------------------------------------------------- ---------- ---------- -

  1 +REV/ora10g/archivelog/2012_12_24/thread_1_seq_61.459.802892953 1 61

  SQL> select name,thread#,sequence#,status from v$archived_log; -->下面是从实例级别的视图来查看

  NAME THREAD# SEQUENCE# S

  ----------------------------------------------------------------- ---------- ---------- -

  +REV/ora10g/archivelog/2012_12_24/thread_1_seq_61.459.802892953 1 61 A

  SQL> conn system/oracle@ora10g2 -->连接到实例2

  Connected.

  SQL> show parameter instance_name;

  NAME TYPE VALUE

  ------------------------------------ ----------- ------------------------------

  instance_name string ora10g2

  SQL> alter system switch logfile; -->在实例2上进行归档

  System altered.

  SQL> select inst_id,name,thread#,sequence#,status from gv$archived_log;

  -->可以看到sequence为43的日志已经归档

  -->注意这个视图查询时同一个归档日志除了出现在自身实例中外,对另外的实例也是可见的

  INST_ID NAME THREAD# SEQUENCE# S

  ---------- ----------------------------------------------------------------- ---------- ---------- -

  1 +REV/ora10g/archivelog/2012_12_24/thread_1_seq_61.459.802892953 1 61 A

  1 +REV/ora10g/archivelog/2012_12_24/thread_2_seq_43.458.802893283 2 43 A

  2 +REV/ora10g/archivelog/2012_12_24/thread_1_seq_61.459.802892953 1 61 A

  2 +REV/ora10g/archivelog/2012_12_24/thread_2_seq_43.458.802893283 2 43 A

  -->查看日志的状态

  -->注意这个v$log视图将两个实例上的组及状态都显示出来了

  -->在这里用thread#来区分,thread#为1表示实例1上的日志组有1,2,且1处于current状态.thread#2类似.

  SQL> select * from v$log;

  GROUP# THREAD# SEQUENCE# BYTES MEMBERS ARC STATUS FIRST_CHANGE# FIRST_TIM

  ---------- ---------- ---------- ---------- ---------- --- ---------------- ------------- ---------

  1 1 62 52428800 2 NO CURRENT 4314741 24-DEC-12

  2 1 61 52428800 2 YES ACTIVE 4312116 24-DEC-12

  3 2 43 52428800 2 YES ACTIVE 4312300 24-DEC-12

  4 2 44 52428800 2 NO CURRENT 4315097 24-DEC-12

  -->Author: Robinson

  -->归档当前日志,注意该命令在单实例下等同于alter system switch logfile

  -->在rac环境下则不同,那就是所有实例上的current日志都将会被归档

  SQL> alter system archive log current;

  System altered.

  -->下面的查询正好验证了上面的描述

  -->日志62与44正是刚刚上面的命令同时产生的归档日志

  SQL> select inst_id,name,thread#,sequence#,status from gv$archived_log;

  INST_ID NAME THREAD# SEQUENCE# S

  ---------- ----------------------------------------------------------------- ---------- ---------- -

  2 +REV/ora10g/archivelog/2012_12_24/thread_1_seq_61.459.802892953 1 61 A

  2 +REV/ora10g/archivelog/2012_12_24/thread_2_seq_43.458.802893283 2 43 A

  2 +REV/ora10g/archivelog/2012_12_24/thread_2_seq_44.456.802894343 2 44 A

  2 +REV/ora10g/archivelog/2012_12_24/thread_1_seq_62.457.802894341 1 62 A

  1 +REV/ora10g/archivelog/2012_12_24/thread_1_seq_61.459.802892953 1 61 A

  1 +REV/ora10g/archivelog/2012_12_24/thread_2_seq_43.458.802893283 2 43 A

  1 +REV/ora10g/archivelog/2012_12_24/thread_2_seq_44.456.802894343 2 44 A

  1 +REV/ora10g/archivelog/2012_12_24/thread_1_seq_62.457.802894341 1 62 A

  8 rows selected.