Pages

Thursday, September 27, 2012

How to recover from a loss of the SYSTEM tablespace on the original location

The following scenario will describe how to proceed when you lose a system critical tablespace.
I'll simulate the loss of SYSTEM tablespace, I mean datafile 1... which always contains the data dictionary tables for the entire database.
In particular this example will restore the lost tablespace to its original location.
When you lose the SYSTEM tablespace the instance could crash or hang: anyway the instance will alert you as soon as possible.

It's not rare the case when you cannot even shutdown the instance and proceed with a kill or a shutdown abort command.

If you have a good backup you can of course restore it, but the database could not be open untill the recovery process finish.
No problem for your committed transactions because your production database is always running in ARCHIVELOG mode and they will be available as soon as the database open.

Let's begin simulating the loss of SYSTEM tablespace.
In my case the instance was not running as you can see when I deleted the file.
[oracle@localhost ~]$ ps -ef|grep smon
oracle    7867     1  0 06:17 ?        00:00:01 ora_smon_orcl
Here are my sys* datafiles
[oracle@localhost ~]$ ll -h /home/oracle/app/oracle/oradata/orcl/sys*
-rw-rw---- 1 oracle oracle 1.1G Jul 27 07:11 /home/oracle/app/oracle/oradata/orcl/sysaux01.dbf
-rw-rw---- 1 oracle oracle 832M Jul 27 07:11 /home/oracle/app/oracle/oradata/orcl/system01.dbf
I remove just the datafile of the SYSTEM tablespace.
[oracle@localhost ~]$ rm /home/oracle/app/oracle/oradata/orcl/system01.dbf
Let's try to start up the instance.
[oracle@localhost ~]$ sqlplus / as sysdba

SQL*Plus: Release 11.2.0.2.0 Production on Fri Jul 27 07:12:37 2012

Copyright (c) 1982, 2010, Oracle.  All rights reserved.

ERROR:
ORA-01075: you are currently logged on

Enter user-name: sys
Enter password: 
ERROR:
ORA-00604: error occurred at recursive SQL level 2
ORA-01116: error in opening database file 1
ORA-01110: data file 1: '/home/oracle/app/oracle/oradata/orcl/system01.dbf'
ORA-27041: unable to open file
Linux Error: 2: No such file or directory
Additional information: 3
ORA-00604: error occurred at recursive SQL level 1
ORA-01116: error in opening database file 1
ORA-01110: data file 1: '/home/oracle/app/oracle/oradata/orcl/system01.dbf'
ORA-27041: unable to open file
Linux Error: 2: No such file or directory
Additional information: 3
ORA-00604: error occurred at recursive SQL level 2
ORA-01116: error in opening database file 1
ORA-01110: data file 1: '/home/oracle/app/oracle/oradata/orcl/system01.dbf'
ORA-27041: unable to open file
Linux Error: 2: No such file or directory
Additional information: 3
I'm not able to login and a clear error message is showed on screen. Let's use then RMAN...
[oracle@localhost ~]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Fri Jul 27 07:14:41 2012

Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.

RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-00554: initialization of internal recovery manager package failed
RMAN-04005: error from target database: 
ORA-01116: error in opening database file 1
ORA-01110: data file 1: '/home/oracle/app/oracle/oradata/orcl/system01.dbf'
ORA-27041: unable to open file
Linux Error: 2: No such file or directory
Additional information: 3
Of course even RMAN shows you the same error.
The instance tried to start, shared memory were successfully attached by the Oracle processes, but the instance doesn't work as expected: the SYSTEM tablespace is missing for RMAN too... I need to kill the instance.
[oracle@localhost ~]$ ps -ef|grep smon
oracle    7867     1  0 06:17 ?        00:00:01 ora_smon_orcl
oracle    8446  2875  0 07:16 pts/1    00:00:00 grep smon
[oracle@localhost ~]$ kill -9 7867
[oracle@localhost ~]$ ps -ef|grep orcl
Let's use RMAN again...
[oracle@localhost ~]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Fri Jul 27 07:17:33 2012

Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.

connected to target database (not started)
... so we can start up the database in MOUNT mode
RMAN> startup mount;

Oracle instance started
database mounted

Total System Global Area     456146944 bytes

Fixed Size                     1344840 bytes
Variable Size                381684408 bytes
Database Buffers              67108864 bytes
Redo Buffers                   6008832 bytes
Now we can issue the restore command for the SYSTEM tablespace
RMAN> restore tablespace system;

Starting restore at 27-07-2012 07:18:28
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=19 device type=DISK

channel ORA_DISK_1: restoring datafile 00001
input datafile copy RECID=17 STAMP=789551585 file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_system_81020mvz_.dbf
destination for restore of datafile 00001: /home/oracle/app/oracle/oradata/orcl/system01.dbf
channel ORA_DISK_1: copied datafile copy of datafile 00001
output file name=/home/oracle/app/oracle/oradata/orcl/system01.dbf RECID=0 STAMP=0
Finished restore at 27-07-2012 07:20:15
The previous restore command try to restore the datafile of SYSTEM tablespace to its original location. Then it's time to issue the recover command ...
RMAN> recover tablespace system;

Starting recover at 27-07-2012 07:20:41
using channel ORA_DISK_1

starting media recovery
media recovery complete, elapsed time: 00:00:04

Finished recover at 27-07-2012 07:20:46
... and finally open the database.
RMAN> alter database open;

database opened
Now the database is available again to all the users and the SYSTEM tablespace is fully recovered.

That's all.

Wednesday, September 26, 2012

How to recover from a loss of a non-system tablespace

The following scenario will describe how to proceed when you lose a non-system tablespace, I mean not the SYSTEM and UNDO tablespace. In particular this example will restore the lost tablespace to its original location. When you lose a non-system tablespace you cannot access and query only objects that were created on their datafiles;
meanwhile users can continue to query and use all the others objects in the database and you can restore it while the database is open.
Moreover because your database is running in ARCHIVELOG mode any committed transactions don't need to be inserted again.
Let's simulate a loss of the EXAMPLE tablespace, in my case formed by only one datafile:
[oracle@localhost ~]$ ll /home/oracle/app/oracle/oradata/orcl/example01.dbf*
-rw-rw---- 1 oracle oracle 85991424 Jul 26 06:34 /home/oracle/app/oracle/oradata/orcl/example01.dbf
[oracle@localhost ~]$ mv /home/oracle/app/oracle/oradata/orcl/example01.dbf /home/oracle/app/oracle/oradata/orcl/example01.dbf.bck
The database is still open and I query for the very first time an object located on the EXAMPLE tablespace. I receive an error stating the instance was not able to open the example01.dbf (data)file
SQL> select count(*) from ix.ORDERS_QUEUETABLE;
select count(*) from ix.ORDERS_QUEUETABLE
  *
ERROR at line 1:
ORA-01116: error in opening database file 5
ORA-01110: data file 5: '/home/oracle/app/oracle/oradata/orcl/example01.dbf'
ORA-27041: unable to open file
Linux Error: 2: No such file or directory
Additional information: 3
If you look at the alert log the same error and a trace file are generated
...
Thu Jul 26 06:49:51 2012
Errors in file /home/oracle/app/oracle/diag/rdbms/orcl/orcl/trace/orcl_m000_6858.trc:
ORA-01116: error in opening database file 5
ORA-01110: data file 5: '/home/oracle/app/oracle/oradata/orcl/example01.dbf'
ORA-27041: unable to open file
Linux Error: 2: No such file or directory
Additional information: 3
Thu Jul 26 06:49:53 2012
Checker run found 1 new persistent data failures
...
As you can see the objects located on EXAMPLE tablespace are no more available. So it's time to recover our tablespace: I'd like to remind you that all the following steps are executed while the database is OPEN as you can see even from the screen log of rman console (connected to target database: ORCL (DBID=1229390655)):
[oracle@localhost ~]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Tue Sep 25 23:09:23 2012

Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.

connected to target database: ORCL (DBID=1229390655)
First thing to do is to put the lost tablespace OFFLINE.
RMAN> sql 'alter tablespace example offline immediate';

sql statement: alter tablespace example offline immediate
Second step is to issue the restore command providing the name of your lost tablespace
RMAN> restore tablespace example;

Starting restore at 26-07-2012 06:54:15
using channel ORA_DISK_1

channel ORA_DISK_1: restoring datafile 00005
input datafile copy RECID=22 STAMP=789633285 file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_example_812kvfk3_.dbf
destination for restore of datafile 00005: /home/oracle/app/oracle/oradata/orcl/example01.dbf
channel ORA_DISK_1: copied datafile copy of datafile 00005
output file name=/home/oracle/app/oracle/oradata/orcl/example01.dbf RECID=0 STAMP=0
Finished restore at 26-07-2012 06:54:19
After your tablespace was restored from your backup pieces it's time to execute the recover command.
RMAN> recover tablespace example;

Starting recover at 26-07-2012 06:54:27
using channel ORA_DISK_1

starting media recovery
media recovery complete, elapsed time: 00:00:02

Finished recover at 26-07-2012 06:54:29
The tablespace is now recovered and you can put it again online and available for your users.
RMAN> sql 'alter tablespace example online';

sql statement: alter tablespace example online
An extract of the alert log taken during the restore and recover process...
...
Thu Jul 26 06:53:38 2012
alter tablespace example offline immediate
Completed: alter tablespace example offline immediate
Thu Jul 26 06:54:16 2012
Checker run found 2 new persistent data failures
Thu Jul 26 06:54:18 2012
Restore of datafile copy /home/oracle/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_example_812kvfk3_.dbf complete to datafile 5 /home/oracle/app/oracle/oradata/orcl/example01.dbf
checkpoint is 13657207
Thu Jul 26 06:54:28 2012
alter database recover datafile list clear
Completed: alter database recover datafile list clear
alter database recover if needed
tablespace EXAMPLE
Media Recovery Start
Serial Media Recovery started
Recovery of Online Redo Log: Thread 1 Group 1 Seq 1 Reading mem 0
Mem# 0: /home/oracle/app/oracle/oradata/orcl/redo01.log
Media Recovery Complete (orcl)
Completed: alter database recover if needed
tablespace EXAMPLE
Thu Jul 26 06:54:40 2012
alter tablespace example online
Completed: alter tablespace example online
...
That's all.

Saturday, September 22, 2012

How to recover from a loss of a temporary tablespace

This scenario was created after a colleague of mine asked if temporary tablespace is considered an important tablespace by Oracle software like SYSTEM or UNDO during recovery scenarios. I answered with another question: "Do we backup any temporary tablespaces ?" :) Let's look on how to proceed when you lose a temporary tablespace. First of all consider I have just a temporary tablespace formed by one single datafile.
select file_name 
from dba_temp_files 
where tablespace_name = 'TEMP';
                
FILE_NAME
---------
/home/oracle/app/oracle/oradata/orcl/temp01.dbf
Now let's shutdown the instance.
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
Simulate a loss of your temporary datafile
[oracle@localhost orcl]$ mv temp01.dbf temp01.dbf.20120903_222335.bck
Now start again your database and look at the alert log.
[oracle@localhost ~]$ tail -f -n100 /home/oracle/app/oracle/diag/rdbms/orcl/orcl/trace/alert_orcl.log
Here are some lines... look at each of them carefully...
...
Completed: ALTER DATABASE   MOUNT
Mon Sep 03 22:25:42 2012
ALTER DATABASE OPEN
Beginning crash recovery of 1 threads
Started redo scan
Completed redo scan
 read 73 KB redo, 47 data blocks need recovery
Started redo application at
 Thread 1: logseq 19, block 4124
Recovery of Online Redo Log: Thread 1 Group 1 Seq 19 Reading mem 0
  Mem# 0: /home/oracle/app/oracle/oradata/orcl/redo01.log
Completed redo application of 0.05MB
Completed crash recovery at
 Thread 1: logseq 19, block 4271, scn 14003253
 47 data blocks read, 47 data blocks written, 73 redo k-bytes read
LGWR: STARTING ARCH PROCESSES
...
Verifying file header compatibility for 11g tablespace encryption..
Verifying 11g file header compatibility for tablespace encryption completed
SMON: enabling cache recovery
SMON: enabling tx recovery
Re-creating tempfile /home/oracle/app/oracle/oradata/orcl/temp01.dbf
Database Characterset is AL32UTF8
No Resource Manager plan active
replication_dependency_tracking turned off (no async multimaster replication found)
Starting background process QMNC
Completed: ALTER DATABASE OPEN
Mon Sep 03 22:25:46 2012
...
After the process of mounting the database is completed and during the opening of it you can find an interesting line... I know you already have noticed it, the alert log traces:
...
Re-creating tempfile /home/oracle/app/oracle/oradata/orcl/temp01.dbf
...
Starting from version 10g, Oracle is able to detect the missing temporary datafile and recreate it on the same location. Indeed you can notice there's a new temporary datafile under my default location:
[oracle@localhost orcl]$ ll temp01.dbf*
-rw-rw---- 1 oracle oracle 20979712 Sep  3 22:25 temp01.dbf
-rw-rw---- 1 oracle oracle 20979712 Sep  3 22:03 temp01.dbf.20120903_222335.bck
Let's see what happens when we have two temporary datafiles and we lose one of them. Is Oracle still able to verify a temporary datafile is missing or it would let you open the database using just the other temporary datafile ? Let's add a new temporary datafile to the same temporary tablespace.
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE '/home/oracle/app/oracle/oradata/orcl/temp02.dbf' SIZE 20M REUSE AUTOEXTEND ON NEXT 5M  MAXSIZE 50M;

Tablespace altered.
Now simulate again the loss of temp01.dbf datafile and kill the instance. Here is described my situation:
[oracle@localhost orcl]$ ll temp0*
-rw-rw---- 1 oracle oracle 20979712 Sep  3 22:25 temp01.dbf
-rw-rw---- 1 oracle oracle 20979712 Sep  3 22:03 temp01.dbf.20120903_222335.bck
-rw-rw---- 1 oracle oracle 20979712 Sep  3 22:33 temp02.dbf
[oracle@localhost orcl]$ mv temp01.dbf temp01.dbf.20120903_224005.bck
[oracle@localhost orcl]$ ps -ef|grep smon
oracle    3744     1  0 22:35 ?        00:00:00 ora_smon_orcl
oracle    3874  2850  0 22:40 pts/2    00:00:00 grep smon
[oracle@localhost orcl]$ kill -9 3744
Startup the instance
[oracle@localhost ~]$ sqlplus / as sysdba

SQL*Plus: Release 11.2.0.2.0 Production on Mon Sep 3 22:41:33 2012

Copyright (c) 1982, 2010, Oracle.  All rights reserved.

Connected to an idle instance.

SQL> startup
Again have a look at the alert log
[oracle@localhost ~]$ tail -f -n100 /home/oracle/app/oracle/diag/rdbms/orcl/orcl/trace/alert_orcl.log
You can find again Oracle detects the missing temporary datafile and recreate it in the same location.
...
Verifying 11g file header compatibility for tablespace encryption completed
SMON: enabling tx recovery
Re-creating tempfile /home/oracle/app/oracle/oradata/orcl/temp01.dbf
Database Characterset is AL32UTF8
No Resource Manager plan active
replication_dependency_tracking turned off (no async multimaster replication found)
Starting background process QMNC
Completed: ALTER DATABASE OPEN
Mon Sep 03 22:41:52 2012
...
Querying the database you can verify the two temporary datafiles are there.
SQL> col file_name format a70
SQL> select file_name from dba_temp_files;

FILE_NAME
----------------------------------------------------------------------
/home/oracle/app/oracle/oradata/orcl/temp01.dbf
/home/oracle/app/oracle/oradata/orcl/temp02.dbf
That's all.

Monday, September 10, 2012

How to recover from a loss of all redo log members of the CURRENT group

When your database loses all members of the CURRENT redo log group, it means you have lost transactions contained in that group: to be able opening your database you have to perform an incomplete recovery until latest valid SCN. Let's simulate this scenario with an example. I will get information about redo log groups, create a table, insert some rows and commit them, force a log switch, create another table, insert other rows and commit them on the second table. I'm expecting dropping the CURRENT redo log group will force me to perform an incomplete recovery, being able to get back rows of first table, but no rows of the second... Here is the script:
set linesize 180
set pagesize 999
col member format a60
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
declare
begin
execute immediate 'create table hr.test_active7 (a number)';
for i in 1 .. 100
loop
execute immediate 'insert into hr.test_active7 values (:a)' using i;
end loop;
commit;
execute immediate 'alter system switch logfile';
end;
/
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
declare
begin
execute immediate 'create table hr.test_active8 (a number)';
for i in 1 .. 100
loop
execute immediate 'insert into hr.test_active8 values (:a)' using i;
end loop;
commit;
end;
/
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
The output of the script:
SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO

6 rows selected.

SQL>   2    3    4    5    6    7    8    9   10   11  

PL/SQL procedure successfully completed.

SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 ACTIVE                   NO

6 rows selected.

SQL>   2    3    4    5    6    7    8    9   10  
PL/SQL procedure successfully completed.

SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 ACTIVE                   YES
My CURRENT redo log group is number 1 and rows are inserted.
select a, b from (select count(*) a from hr.test_active7), (select count(*) b from hr.test_active8);

         A          B
---------- ----------
       100        100
Let's remove all members of the CURRENT redo log group
[oracle@localhost orcl]$ rm redo01*
[oracle@localhost orcl]$ ll redo0*
-rw-rw---- 1 oracle oracle 52429312 Sep  9 08:43 redo02b.log
-rw-rw---- 1 oracle oracle 52429312 Sep  9 08:43 redo02.log
-rw-rw---- 1 oracle oracle 52429312 Sep  9 08:49 redo03b.log
-rw-rw---- 1 oracle oracle 52429312 Sep  9 08:49 redo03.log
Killing the instance
[oracle@localhost orcl]$ ps -ef|grep smon
oracle   13562     1  0 08:28 ?        00:00:02 ora_smon_orcl
oracle   13848  3164  0 08:49 pts/5    00:00:00 grep smon
[oracle@localhost orcl]$ kill -9 13562
Let's start up the instance
SQL> startup
ORACLE instance started.

Total System Global Area  456146944 bytes
Fixed Size                  1344840 bytes
Variable Size             373295800 bytes
Database Buffers           75497472 bytes
Redo Buffers                6008832 bytes
Database mounted.
ORA-00313: open failed for members of log group 1 of thread 1
ORA-00312: online log 1 thread 1:
'/home/oracle/app/oracle/oradata/orcl/redo01b.log'
ORA-27037: unable to obtain file status
Linux Error: 2: No such file or directory
Additional information: 3
ORA-00312: online log 1 thread 1:
'/home/oracle/app/oracle/oradata/orcl/redo01.log'
ORA-27037: unable to obtain file status
Linux Error: 2: No such file or directory
Additional information: 3
The instance alerts you it cannot open your database because of the missing files. It's time to perform an incomplete recovery. Query the v$log view to obtain the latest valid SCN of the missing group. In my case it was 14133031
SQL> select group#, status, archived, thread#, sequence#, first_change# from v$log;

    GROUP# STATUS           ARC    THREAD#  SEQUENCE# FIRST_CHANGE#
---------- ---------------- --- ---------- ---------- -------------
         1 CURRENT          NO           1          4      14133031
         3 ACTIVE           YES          1          3      14132968
         2 ACTIVE           YES          1          2      14132860
Issue the following commands from RMAN
[oracle@localhost orcl]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Sun Sep 9 09:16:48 2012

Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.

connected to target database: ORCL (DBID=1229390655, not open)

RMAN> restore database until scn 14133031;

Starting restore at 09-09-2012 09:16:53
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=21 device type=DISK

skipping datafile 7; already restored to file /home/oracle/app/oracle/oradata/orcl/read_only01.dbf
channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_DISK_1: restoring datafile 00001 to /home/oracle/app/oracle/oradata/orcl/system01.dbf
channel ORA_DISK_1: restoring datafile 00002 to /home/oracle/app/oracle/oradata/orcl/sysaux01.dbf
channel ORA_DISK_1: restoring datafile 00003 to /home/oracle/app/oracle/oradata/orcl/undotbs01.dbf
channel ORA_DISK_1: restoring datafile 00004 to /home/oracle/app/oracle/oradata/orcl/users01.dbf
channel ORA_DISK_1: restoring datafile 00005 to /home/oracle/app/oracle/oradata/orcl/example01.dbf
channel ORA_DISK_1: restoring datafile 00006 to /home/oracle/app/oracle/oradata/orcl/APEX_1930613455248703.dbf
channel ORA_DISK_1: reading from backup piece /home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_09_09/o1_mf_nnndf_TAG20120909T090659_84sho4fc_.bkp
channel ORA_DISK_1: piece handle=/home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_09_09/o1_mf_nnndf_TAG20120909T090659_84sho4fc_.bkp tag=TAG20120909T090659
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:03:20
Finished restore at 09-09-2012 09:20:15

RMAN> recover database until scn 14133031;

Starting recover at 09-09-2012 09:27:45
using channel ORA_DISK_1
datafile 7 not processed because file is read-only

starting media recovery
media recovery complete, elapsed time: 00:00:02

Finished recover at 09-09-2012 09:27:49

RMAN> alter database open resetlogs;

database opened

As you can see I've lost table and rows "recorded" in the previous CURRENT redo log group I have "inadvertently" deleted; the first table and its rows is instead recovered...
SQL> select a, b from (select count(*) a from hr.test_active7), (select count(*) b from hr.test_active8);
select a, b from (select count(*) a from hr.test_active7), (select count(*) b from hr.test_active8)
                                                                                      *
ERROR at line 1:
ORA-00942: table or view does not exist


SQL> select count(*) a from hr.test_active7;

         A
----------
       100

That's all.

How to recover from a loss of all redo log members of an ACTIVE group

According to the Oracle documentation there are more steps to complete when you lose all redo log members of an ACTIVE group and exists the possibility to have lost some transactions.
If you are able to force the database to perform a checkpoint then you can clear the missing redo log group, otherwise you need to execute an incomplete recovery.
I was able to recreate both the scenarios using some scripts and verify when you lose transactions.
Dealing with the loss of ACTIVE and, in the next post, CURRENT redo log group could mean discovering to have lost some transactions.

To simulate the loss of ACTIVE redo log group I use a script and, with a query, I try to identify the redo log members to be deleted manually.

The first scenario, while the instance was still up and running, I was able to execute a checkpoint and perform a complete recovery;
to simulate the second scenario, that is an incomplete recovery, I needed to kill the instance so no checkpoint could be completed.

Let's see the examples.
Take a look at the script first. It executes for three times a query on v$log and v$logfile to show the status of the redo log group, insert 100 rows in three different tables, commit and force a logfile switch.
After the last insert it executes again the previous query.
set linesize 180
set pagesize 999
col member format a60
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
declare
begin
execute immediate 'create table hr.test_active4 (a number)';
for i in 1 .. 100
loop
execute immediate 'insert into hr.test_active4 values (:a)' using i;
end loop;
commit;
execute immediate 'alter system switch logfile';
end;
/
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
declare
begin
execute immediate 'create table hr.test_active5 (a number)';
for i in 1 .. 100
loop
execute immediate 'insert into hr.test_active5 values (:a)' using i;
end loop;
commit;
execute immediate 'alter system switch logfile';
end;
/
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
declare
begin
execute immediate 'create table hr.test_active6 (a number)';
for i in 1 .. 100
loop
execute immediate 'insert into hr.test_active6 values (:a)' using i;
end loop;
commit;
execute immediate 'alter system switch logfile';
end;
/
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
Then I executed the script and this was the output:
SQL>
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO

6 rows selected.

SQL>   2    3    4    5    6    7    8    9   10   11  
PL/SQL procedure successfully completed.

SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 ACTIVE                   NO

6 rows selected.

SQL>   2    3    4    5    6    7    8    9   10   11  
PL/SQL procedure successfully completed.

SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 ACTIVE                   YES

6 rows selected.

SQL>   2    3    4    5    6    7    8    9   10   11  
PL/SQL procedure successfully completed.

SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO

6 rows selected.

At this moment redo log group number 2 was ACTIVE and still NOT ARCHIVED... but few second later it was simply ACTIVE and ARCHIVED:
SQL> select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO
Have a look at the contents of the three table before simulating the lost:
SQL> select a, b, c from (select count(*) a from hr.test_active1), (select count(*) b from hr.test_active2), (select count(*) c from hr.test_active3);

         A          B          C
---------- ---------- ----------
       100        100        100
It was time to delete all redo log members of group 2:
[oracle@localhost orcl]$ mv redo02.log redo02.log.bck
[oracle@localhost orcl]$ mv redo02b.log redo02b.log.bck
[oracle@localhost orcl]$ ll redo*
-rw-rw---- 1 oracle oracle 52429312 Sep  7 11:42 redo01b.log
-rw-rw---- 1 oracle oracle 52429312 Sep  7 11:42 redo01.log
-rw-rw---- 1 oracle oracle 52429312 Sep  7 11:42 redo02b.log.bck
-rw-rw---- 1 oracle oracle 52429312 Sep  7 11:42 redo02.log.bck
-rw-rw---- 1 oracle oracle 52429312 Sep  7 11:53 redo03b.log
-rw-rw---- 1 oracle oracle 52429312 Sep  7 11:53 redo03.log
The instance was still up and running and I was able to complete a checkpoint as Oracle documentation suggests. Because the operation was successful, the active redo log became inactive.
SQL> alter system checkpoint;

System altered.

SQL> select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO
And now it's time to clear the redo logfile group 2
SQL> alter database clear logfile group 2;

Database altered.
The query shows those members are just created and never used.
SQL> select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 UNUSED                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 UNUSED                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO
Will the rows still be there if we perform a restore of our database ? Let's look with an example
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
Connecting with RMAN I restore and recover the database:
[oracle@localhost ~]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Fri Sep 7 12:51:18 2012

Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.

connected to target database (not started)

RMAN> startup mount;

Oracle instance started
database mounted

Total System Global Area     456146944 bytes

Fixed Size                     1344840 bytes
Variable Size                394267320 bytes
Database Buffers              54525952 bytes
Redo Buffers                   6008832 bytes

RMAN> restore database;

Starting restore at 07-09-2012 12:51:57
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=18 device type=DISK

skipping datafile 7; already restored to file /home/oracle/app/oracle/oradata/orcl/read_only01.dbf
channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_DISK_1: restoring datafile 00001 to /home/oracle/app/oracle/oradata/orcl/system01.dbf
channel ORA_DISK_1: restoring datafile 00002 to /home/oracle/app/oracle/oradata/orcl/sysaux01.dbf
channel ORA_DISK_1: restoring datafile 00003 to /home/oracle/app/oracle/oradata/orcl/undotbs01.dbf
channel ORA_DISK_1: restoring datafile 00004 to /home/oracle/app/oracle/oradata/orcl/users01.dbf
channel ORA_DISK_1: restoring datafile 00005 to /home/oracle/app/oracle/oradata/orcl/example01.dbf
channel ORA_DISK_1: restoring datafile 00006 to /home/oracle/app/oracle/oradata/orcl/APEX_1930613455248703.dbf
channel ORA_DISK_1: reading from backup piece /home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_09_07/o1_mf_nnndf_TAG20120907T100935_84nblj6n_.bkp
channel ORA_DISK_1: piece handle=/home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_09_07/o1_mf_nnndf_TAG20120907T100935_84nblj6n_.bkp tag=TAG20120907T100935
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:03:30
Finished restore at 07-09-2012 12:55:30

RMAN> recover database;

Starting recover at 07-09-2012 12:55:52
using channel ORA_DISK_1
datafile 7 not processed because file is read-only

starting media recovery

archived log for thread 1 with sequence 2 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_2_84nbr9nj_.arc
archived log for thread 1 with sequence 3 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_3_84nj18pt_.arc
archived log for thread 1 with sequence 4 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_4_84nj19gn_.arc
archived log for thread 1 with sequence 5 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_5_84nj1b58_.arc
archived log file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_2_84nbr9nj_.arc thread=1 sequence=2
archived log file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_3_84nj18pt_.arc thread=1 sequence=3
archived log file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_5_84nj1b58_.arc thread=1 sequence=5
media recovery complete, elapsed time: 00:00:07
Finished recover at 07-09-2012 12:56:05

RMAN> alter database open;

database opened
The database is open and the rows are still there.
SQL> select a, b, c from (select count(*) a from hr.test_active1), (select count(*) b from hr.test_active2), (select count(*) c from hr.test_active3);

         A          B          C
---------- ---------- ----------
       100        100        100
So our rows are all there. Now it's time to simulate the second scenario. First of all I need to find the process id of the smon process.
[oracle@localhost ~]$ ps -ef|grep smon
oracle   12048     1  0 12:51 ?        00:00:01 ora_smon_orcl
oracle   12408  2803  1 13:27 pts/1    00:00:00 grep smon
Then in three different Unix terminals I prepared the following commands (each on one terminal of course). In this way with just one RETURN button I'm able to remove the ACTIVE redo log group and kill the instance, without any checkpoint and "perhaps" loosing transactions.
[oracle@localhost orcl]$ mv redo01.log redo01.log.bck; mv redo01b.log redo01b.log.bck; kill -9 12048
[oracle@localhost orcl]$ mv redo02.log redo02.log.bck; mv redo02b.log redo02b.log.bck; kill -9 12048
[oracle@localhost orcl]$ mv redo03.log redo03.log.bck; mv redo03b.log redo03b.log.bck; kill -9 12048
The script I'm going to execute inserting rows on others three different tables:
set linesize 180
set pagesize 999
col member format a60
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
declare
begin
execute immediate 'create table hr.test_active4 (a number)';
for i in 1 .. 100
loop
execute immediate 'insert into hr.test_active4 values (:a)' using i;
end loop;
commit;
execute immediate 'alter system switch logfile';
end;
/
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
declare
begin
execute immediate 'create table hr.test_active5 (a number)';
for i in 1 .. 100
loop
execute immediate 'insert into hr.test_active5 values (:a)' using i;
end loop;
commit;
execute immediate 'alter system switch logfile';
end;
/
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
declare
begin
execute immediate 'create table hr.test_active6 (a number)';
for i in 1 .. 100
loop
execute immediate 'insert into hr.test_active6 values (:a)' using i;
end loop;
commit;
execute immediate 'alter system switch logfile';
end;
/
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
The output of the script just executed:
SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 UNUSED                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 UNUSED                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO

6 rows selected.

SQL>   2    3    4    5    6    7    8    9   10   11  
PL/SQL procedure successfully completed.

SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 ACTIVE                   NO

6 rows selected.

SQL>   2    3    4    5    6    7    8    9   10   11  
PL/SQL procedure successfully completed.

SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 ACTIVE                   NO

6 rows selected.

SQL>   2    3    4    5    6    7    8    9   10   11  

PL/SQL procedure successfully completed.

SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 ACTIVE                   NO
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO
Querying again v$log and v$logfile views, we see there are two groups ACTIVE and ARCHIVED.
SQL> select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO
I'm going to remove all members of redo log group number 1 and kill the instance.
[oracle@localhost orcl]$ mv redo01.log redo01.log.bck; mv redo01b.log redo01b.log.bck; kill -9 12048;
[oracle@localhost orcl]$ ps -ef|grep smon
[oracle@localhost orcl]$ 
Let's start the instance in MOUNT mode and query the v$ views as we don't know what happened. I try to issue a checkpoint but it cannot complete because the database is not open.
SQL> startup mount;
ORACLE instance started.

Total System Global Area  456146944 bytes
Fixed Size                  1344840 bytes
Variable Size             394267320 bytes
Database Buffers           54525952 bytes
Redo Buffers                6008832 bytes
Database mounted.
SQL> set linesize 180
set pagesize 999
col member format a60
select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;
SQL> SQL> SQL> 
MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE                   YES
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT                  NO

6 rows selected.

SQL> alter system checkpoint;
alter system checkpoint
*
ERROR at line 1:
ORA-01109: database not open
The Oracle documentation says we have to perform an incomplete recovery up to the latest valid SCN that is indicated into FIRST_CHANGE# column of v$log view of the missing redo log group.
SQL> select group#, status, archived, thread#, sequence#, first_change# from v$log;

    GROUP# STATUS           ARC    THREAD#  SEQUENCE# FIRST_CHANGE#
---------- ---------------- --- ---------- ---------- -------------
         1 ACTIVE           YES          1          8      14126367
         3 CURRENT          NO           1          9      14126384
         2 ACTIVE           YES          1          7      14126349
In my case I can restore and recover until SCN 14126367. Let's look the following steps:
[oracle@localhost orcl]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Fri Sep 7 13:48:47 2012

Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.

connected to target database: ORCL (DBID=1229390655, not open)

RMAN> restore database until scn 14126367;

Starting restore at 07-09-2012 13:48:56
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=18 device type=DISK

skipping datafile 7; already restored to file /home/oracle/app/oracle/oradata/orcl/read_only01.dbf
channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_DISK_1: restoring datafile 00001 to /home/oracle/app/oracle/oradata/orcl/system01.dbf
channel ORA_DISK_1: restoring datafile 00002 to /home/oracle/app/oracle/oradata/orcl/sysaux01.dbf
channel ORA_DISK_1: restoring datafile 00003 to /home/oracle/app/oracle/oradata/orcl/undotbs01.dbf
channel ORA_DISK_1: restoring datafile 00004 to /home/oracle/app/oracle/oradata/orcl/users01.dbf
channel ORA_DISK_1: restoring datafile 00005 to /home/oracle/app/oracle/oradata/orcl/example01.dbf
channel ORA_DISK_1: restoring datafile 00006 to /home/oracle/app/oracle/oradata/orcl/APEX_1930613455248703.dbf
channel ORA_DISK_1: reading from backup piece /home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_09_07/o1_mf_nnndf_TAG20120907T100935_84nblj6n_.bkp
channel ORA_DISK_1: piece handle=/home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_09_07/o1_mf_nnndf_TAG20120907T100935_84nblj6n_.bkp tag=TAG20120907T100935
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:03:29
Finished restore at 07-09-2012 13:52:27

RMAN> recover database until scn 14126367;

Starting recover at 07-09-2012 13:52:59
using channel ORA_DISK_1
datafile 7 not processed because file is read-only

starting media recovery

archived log for thread 1 with sequence 2 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_2_84nbr9nj_.arc
archived log for thread 1 with sequence 3 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_3_84nj18pt_.arc
archived log for thread 1 with sequence 4 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_4_84nj19gn_.arc
archived log for thread 1 with sequence 5 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_5_84nj1b58_.arc
archived log for thread 1 with sequence 6 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_6_84nprq6y_.arc
archived log for thread 1 with sequence 7 is already on disk as file /home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_7_84nprqtl_.arc
archived log file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_2_84nbr9nj_.arc thread=1 sequence=2
archived log file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_3_84nj18pt_.arc thread=1 sequence=3
archived log file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_4_84nj19gn_.arc thread=1 sequence=4
archived log file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_5_84nj1b58_.arc thread=1 sequence=5
archived log file name=/home/oracle/app/oracle/flash_recovery_area/ORCL/archivelog/2012_09_07/o1_mf_1_6_84nprq6y_.arc thread=1 sequence=6
media recovery complete, elapsed time: 00:00:06
Finished recover at 07-09-2012 13:53:09

RMAN> alter database open resetlogs;

database opened
The database is open... but I'm missing a table and its rows.
SQL> select a, b, c from (select count(*) a from hr.test_active4), (select count(*) b from hr.test_active5), (select count(*) c from hr.test_active6);
select a, b, c from (select count(*) a from hr.test_active4), (select count(*) b from hr.test_active5), (select count(*) c from hr.test_active6)
                                                                                                                                   *
ERROR at line 1:
ORA-00942: table or view does not exist
There are instead the two other tables. As you can see above following the output of the running script the missing table was created just on the redo log group number 1
SQL> select a, b from (select count(*) a from hr.test_active4), (select count(*) b from hr.test_active5);

         A          B
---------- ----------
       100        100
To summarize:
1. Try to perform "alter system checkpoint". If successful clear the lost redo log group: "alter database clear logfile group " (you have completely recovered your database) 
2. If unsuccessful query FIRST_CHANGE# column of v$log to know the latest SCN for the missing redo log group. Then using RMAN: startup mount; restore database until scn ; recover database until scn ; alter database open (you have lost some transactions) 

That's all.

Saturday, September 8, 2012

How to recover from a loss of all redo log members of an INACTIVE group

Let's simulate a loss of all redo log members of an inactive group.
If you have completely lost one redo log group your database won't be able to open.
Next thing is to know the STATUS of the lost redo log group (we know it because we are simulating the loss, but...) and, just because this information is on V$LOG view, try to get also the ARCHIVED column.
Now if the redo log group lost was INACTIVE and archived (YES value) we can simply recreate all members with the "alter database clear logfile" command;
if it was INACTIVE and not archived (NO value) we'll execute the "alter database clear unarchived logfile" command.

Let's look at the example. Here is my redo log group state
SQL> select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 INACTIVE                 YES
Delete all members of redo log group 1 and kill your instance.
[oracle@localhost ~]$ rm /home/oracle/app/oracle/oradata/orcl/redo01*
[oracle@localhost ~]$ ps -ef |grep smon
oracle    8176     1  0 06:44 ?        00:00:03 ora_smon_orcl
oracle    9057  3164  0 08:10 pts/5    00:00:00 grep smon
[oracle@localhost ~]$ kill -9 8176
Try to open your database ...
SQL> startup
ORACLE instance started.

Total System Global Area  456146944 bytes
Fixed Size                  1344840 bytes
Variable Size             385878712 bytes
Database Buffers           62914560 bytes
Redo Buffers                6008832 bytes
Database mounted.
ORA-03113: end-of-file on communication channel
Process ID: 9184
Session ID: 17 Serial number: 7
... and look at your alert log
...
ORA-00313: open failed for members of log group 1 of thread 
ORA-00312: online log 1 thread 1: '/home/oracle/app/oracle/oradata/orcl/redo01.log'
ORA-00312: online log 1 thread 1: '/home/oracle/app/oracle/oradata/orcl/redo01b.log'
USER (ospid: 9184): terminating the instance due to error 313
...
Start your database in MOUNT mode
SQL> startup mount
ORACLE instance started.

Total System Global Area  456146944 bytes
Fixed Size                  1344840 bytes
Variable Size             385878712 bytes
Database Buffers           62914560 bytes
Redo Buffers                6008832 bytes
Database mounted.
Query the V$LOG view
SQL> select member, a.group#, a.status, b.status, a.archived  from v$log a, v$logfile b where  a.group# = b.group# order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS  ARC
------------------------------------------------------------ ---------- ---------------- ------- ---
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 CURRENT                  NO
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 INACTIVE                 YES
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 INACTIVE                 YES
The redo log group 1 is INACTIVE and ARCHIVED so simply issue the following command:
SQL> alter database clear logfile group 1;

Database altered.
Open your database
SQL> alter database open;

Database altered.
If you are in the situation to have lost an INACTIVE and NOT already ARCHIVED redo log group then your command should be the following:
SQL> alter database clear unarchived logfile group 1;

Database altered.
Next step is to perform a complete backup
RMAN> backup database;
That's all.

How to recover from a loss of one redo log member of a multiplexed group

This scenario describes what happens when you lose one redo log member of a multiplexed group.
It could happen for a simply media failure or because some one "needed" to free some space and saw that .log file!!!
It happens to me years ago and that was told to me by a system administrator.

Anyway when you have multiplexed your redo log group using several members as Oracle best practices suggest and your disks begin to experience problems your database will continue to function since it's still able to write to one redo log member.
If your disk is completely out you can opt to some options whether or not you have a new disk!
With a new disk you can drop and create again the "lost" redo log member to the original location, otherwise you have to perform the same two steps (drop and create) choosing a different location.
Even if you have already lost your redo log member Oracle will arise the ORA-01609 error when you try to drop a member of a CURRENT group. Querying the status column of V$LOG view you can have several results and generally they are:
CURRENT when that log file is "currently" written by the log writer process (ps -ef|grep lgwr),
ACTIVE when that log file is required in case of a crash recovery (even if it's already archived)
INACTIVE when that log file is not required in case of a crash recovery.

So when you try to drop your "failed" redo log member and you receive the ORA-01609 error just force the database to switch to the next redo log group. 

Let's look it with an example. Here is my redo log configuration:
SQL> select member, a.group#, a.status, b.status from v$log a, v$logfile b where  a.group# = b.group#
  2  order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS
------------------------------------------------------------ ---------- ---------------- -------
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 INACTIVE
As you can see I have three redo log groups formed by two multiplexed members and currently the redo log group number 2 is the CURRENT one. Now I simulate the lost of the redo log member named 'redo02b.log'.
[oracle@localhost ~]$ cd /home/oracle/app/oracle/oradata/orcl/
[oracle@localhost orcl]$ rm redo02b.log
[oracle@localhost orcl]$ ll redo*
-rw-rw---- 1 oracle oracle 52429312 Sep  5 12:58 redo01b.log
-rw-rw---- 1 oracle oracle 52429312 Sep  5 12:58 redo01.log
-rw-rw---- 1 oracle oracle 52429312 Sep  5 22:30 redo02.log
-rw-rw---- 1 oracle oracle 52429312 Sep  5 12:55 redo03b.log
-rw-rw---- 1 oracle oracle 52429312 Sep  5 12:55 redo03.log
As you cann see from the alert log appears the error
...
Errors in file /home/oracle/app/oracle/diag/rdbms/orcl/orcl/trace/orcl_lgwr_8172.trc:
ORA-00313: open failed for members of log group 2 of thread 1
ORA-00312: online log 2 thread 1: '/home/oracle/app/oracle/oradata/orcl/redo02b.log'
ORA-27037: unable to obtain file status
Linux Error: 2: No such file or directory
...
Now have a look at how the status column of V$LOGFILE view change (from NULL to INVALID) for the lost member
SQL> select member, a.group#, a.status, b.status from v$log a, v$logfile b where  a.group# = b.group#
  2  order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS
------------------------------------------------------------ ---------- ---------------- -------
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 CURRENT          INVALID
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 INACTIVE
I've lost a member of the CURRENT redo log group so I cannot drop it
SQL> alter database drop logfile member '/home/oracle/app/oracle/oradata/orcl/redo02b.log';
alter database drop logfile member '/home/oracle/app/oracle/oradata/orcl/redo02b.log'
*
ERROR at line 1:
ORA-01609: log 2 is the current log for thread 1 - cannot drop members
ORA-00312: online log 2 thread 1: '/home/oracle/app/oracle/oradata/orcl/redo02.log'
ORA-00312: online log 2 thread 1: '/home/oracle/app/oracle/oradata/orcl/redo02b.log'
I have to force a redo log switch:
SQL> alter system switch logfile;

System altered.
Now my redo log group state is as the following:
SQL> select member, a.group#, a.status, b.status from v$log a, v$logfile b where  a.group# = b.group#
  2  order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS
------------------------------------------------------------ ---------- ---------------- -------
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE           INVALID
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT
And I can successfully drop and recreate my lost redo log member:
SQL> alter database drop logfile member '/home/oracle/app/oracle/oradata/orcl/redo02b.log';

Database altered.

SQL> select member, a.group#, a.status, b.status from v$log a, v$logfile b where  a.group# = b.group#
  2  order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS
------------------------------------------------------------ ---------- ---------------- -------
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT

SQL> alter database add logfile member  '/home/oracle/app/oracle/oradata/orcl/redo02b.log' to group 2;

Database altered.

SQL> select member, a.group#, a.status, b.status from v$log a, v$logfile b where  a.group# = b.group#
  2  order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS
------------------------------------------------------------ ---------- ---------------- -------
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 ACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 ACTIVE           INVALID
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 CURRENT

What's happening ? My new redo log member is still INVALID ? What does it mean ?
If you look at the Oracle documentation INVALID could mean: inaccessible (as it was before) or just created (as I did few lines above).
Let's look what it happens when I force logfiles to switch:

SQL> alter system switch logfile;

System altered.

SQL> select member, a.group#, a.status, b.status from v$log a, v$logfile b where  a.group# = b.group#
  2  order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS
------------------------------------------------------------ ---------- ---------------- -------
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 INACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 INACTIVE         INVALID
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 ACTIVE
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 ACTIVE

6 rows selected.

SQL> alter system switch logfile;

System altered.

SQL> select member, a.group#, a.status, b.status from v$log a, v$logfile b where  a.group# = b.group#
  2  order by a.group#, member;

MEMBER                                                           GROUP# STATUS           STATUS
------------------------------------------------------------ ---------- ---------------- -------
/home/oracle/app/oracle/oradata/orcl/redo01.log                       1 ACTIVE
/home/oracle/app/oracle/oradata/orcl/redo01b.log                      1 ACTIVE
/home/oracle/app/oracle/oradata/orcl/redo02.log                       2 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo02b.log                      2 CURRENT
/home/oracle/app/oracle/oradata/orcl/redo03.log                       3 ACTIVE
/home/oracle/app/oracle/oradata/orcl/redo03b.log                      3 ACTIVE

6 rows selected.
As you can see the database marked the 'redo02b.log' as NULL and this means available to be used. That's all.

Tuesday, September 4, 2012

How to recover from a loss of a read-only tablespace

This time I want to test how to restore and recover my database from a loss of a read-only tablespace. I can anticipate there is a new feature introduced since Oracle Database 11gR1 that inverted the logic used untill 10gR2. Let's start with the examples. I've created a read-only tablespace named READ_ONLY using the following command:
SQL> CREATE TABLESPACE READ_ONLY DATAFILE '/home/oracle/app/oracle/oradata/orcl/read_only01.dbf' SIZE 1M AUTOEXTEND ON NEXT 1M MAXSIZE 10M;
SQL> ALTER TABLESPACE READ_ONLY READ ONLY;
The "report schema" command shows READ_ONLY tablespace information
RMAN> report schema;

Report of database schema for database with db_unique_name ORCL

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    831      SYSTEM               ***     /home/oracle/app/oracle/oradata/orcl/system01.dbf
2    1105     SYSAUX               ***     /home/oracle/app/oracle/oradata/orcl/sysaux01.dbf
3    40       UNDOTBS1             ***     /home/oracle/app/oracle/oradata/orcl/undotbs01.dbf
4    225      USERS                ***     /home/oracle/app/oracle/oradata/orcl/users01.dbf
5    82       EXAMPLE              ***     /home/oracle/app/oracle/oradata/orcl/example01.dbf
6    7        APEX_1930613455248703 ***     /home/oracle/app/oracle/oradata/orcl/APEX_1930613455248703.dbf
7    1        READ_ONLY            ***     /home/oracle/app/oracle/oradata/orcl/read_only01.dbf

List of Temporary Files
=======================
File Size(MB) Tablespace           Maxsize(MB) Tempfile Name
---- -------- -------------------- ----------- --------------------
1    20       TEMP                 32767       /home/oracle/app/oracle/oradata/orcl/temp01.dbf
The following are my current backup pieces:
RMAN> list backup summary;


List of Backups
===============
Key     TY LV S Device Type Completion Time     #Pieces #Copies Compressed Tag
------- -- -- - ----------- ------------------- ------- ------- ---------- ---
20      B  A  A DISK        28-08-2012 23:27:18 1       1       YES        TAG20120828T232717
21      B  F  A DISK        28-08-2012 23:31:06 1       1       YES        TAG20120828T232719
22      B  A  A DISK        28-08-2012 23:31:18 1       1       YES        TAG20120828T233118
23      B  F  A DISK        28-08-2012 23:31:20 1       1       NO         TAG20120828T233119
24      B  F  A DISK        29-08-2012 08:25:11 1       1       NO         TAG20120829T082509
25      B  F  A DISK        02-09-2012 21:46:12 1       1       NO         TAG20120902T214611
26      B  F  A DISK        02-09-2012 22:11:24 1       1       NO         TAG20120902T221123
I want to list all the datafiles included in one of my backup, so you can verify I haven't any backup of my read-only tablespace.
RMAN> list backup tag TAG20120828T232719;


List of Backup Sets
===================


BS Key  Type LV Size       Device Type Elapsed Time Completion Time    
------- ---- -- ---------- ----------- ------------ -------------------
21      Full    759.52M    DISK        00:03:47     28-08-2012 23:31:06
        BP Key: 21   Status: AVAILABLE  Compressed: YES  Tag: TAG20120828T232719
        Piece Name: /home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_08_28/o1_mf_nnndf_TAG20120828T232719_83vfl839_.bkp
  List of Datafiles in backup set 21
  File LV Type Ckp SCN    Ckp Time            Name
  ---- -- ---- ---------- ------------------- ----
  1       Full 13907792   28-08-2012 23:27:19 /home/oracle/app/oracle/oradata/orcl/system01.dbf
  2       Full 13907792   28-08-2012 23:27:19 /home/oracle/app/oracle/oradata/orcl/sysaux01.dbf
  3       Full 13907792   28-08-2012 23:27:19 /home/oracle/app/oracle/oradata/orcl/undotbs01.dbf
  4       Full 13907792   28-08-2012 23:27:19 /home/oracle/app/oracle/oradata/orcl/users01.dbf
  5       Full 13907792   28-08-2012 23:27:19 /home/oracle/app/oracle/oradata/orcl/example01.dbf
  6       Full 13907792   28-08-2012 23:27:19 /home/oracle/app/oracle/oradata/orcl/APEX_1930613455248703.dbf
It's confirmed even when you issue the "report need backup" command, showing which datafiles, according to your rman backup policy configuration, need to be backed up. The command says datafile read_only01.dbf belonging to READ_ONLY tablespace must still be backed up.
RMAN> report need backup;

RMAN retention policy will be applied to the command
RMAN retention policy is set to redundancy 1
Report of files with less than 1 redundant backups
File #bkps Name
---- ----- -----------------------------------------------------
7    0     /home/oracle/app/oracle/oradata/orcl/read_only01.dbf
Now let's simulate a loss of that datafile
[oracle@localhost ~]$ cd /home/oracle/app/oracle/oradata/orcl
[oracle@localhost orcl]$ ll
total 2512876
-rw-rw---- 1 oracle oracle    7348224 Aug 29 07:39 APEX_1930613455248703.dbf
-rw-rw---- 1 oracle oracle    9814016 Sep  2 22:22 control01.ctl
-rw-rw---- 1 oracle oracle   85991424 Aug 29 07:39 example01.dbf
drwxrwxr-x 2 oracle oracle       4096 Jul 27 07:53 non_default_location
-rw-rw---- 1 oracle oracle    1056768 Sep  2 22:03 read_only01.dbf
-rw-rw---- 1 oracle oracle   52429312 Aug 29 07:39 redo01.log
-rw-rw---- 1 oracle oracle   52429312 Aug 29 07:39 redo02.log
-rw-rw---- 1 oracle oracle   52429312 Sep  2 22:22 redo03.log
-rw-rw---- 1 oracle oracle 1158684672 Sep  2 22:22 sysaux01.dbf
-rw-rw---- 1 oracle oracle  871374848 Sep  2 22:22 system01.dbf
-rw-rw---- 1 oracle oracle   20979712 Sep  2 21:56 temp01.dbf
-rw-rw---- 1 oracle oracle   41951232 Sep  2 22:22 undotbs01.dbf
-rw-rw---- 1 oracle oracle  235937792 Aug 29 07:39 users01.dbf

[oracle@localhost orcl]$ mv read_only01.dbf read_only01.dbf.20120902_222234.bck
If i try to start the database some errors are shown:
[oracle@localhost ~]$ sqlplus / as sysdba
SQL> startup
ORACLE instance started.

Total System Global Area  456146944 bytes
Fixed Size                  1344840 bytes
Variable Size             352324280 bytes
Database Buffers           96468992 bytes
Redo Buffers                6008832 bytes
Database mounted.
ORA-01157: cannot identify/lock data file 7 - see DBWR trace file
ORA-01110: data file 7: '/home/oracle/app/oracle/oradata/orcl/read_only01.dbf'
Now the first recovery scenario. Let's shutdown the instance
SQL> shutdown immediate;
ORA-01109: database not open

Database dismounted.
ORACLE instance shut down.
Connect with RMAN and start the instance in MOUNT mode
[oracle@localhost dbs]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Sun Sep 2 22:31:25 2012

Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.

connected to target database (not started)

RMAN> startup mount;

Oracle instance started
database mounted

Total System Global Area     456146944 bytes

Fixed Size                     1344840 bytes
Variable Size                352324280 bytes
Database Buffers              96468992 bytes
Redo Buffers                   6008832 bytes
Issue a simply "restore tablespace" command. RMAN will create again the tablespace looking in the redo log.
RMAN> restore tablespace read_only;

Starting restore at 02-09-2012 22:33:02
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=19 device type=DISK

creating datafile file number=7 name=/home/oracle/app/oracle/oradata/orcl/read_only01.dbf
restore not done; all files read only, offline, or already restored
Finished restore at 02-09-2012 22:33:04
If I try to open the database it says of course one datafile needs to be recovered.
RMAN> alter database open;

RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of alter db command at 09/02/2012 22:33:57
ORA-01113: file 7 needs media recovery
ORA-01110: data file 7: '/home/oracle/app/oracle/oradata/orcl/read_only01.dbf'
Issue the recover command so you can be able to open your database.
RMAN> recover tablespace read_only;

Starting recover at 02-09-2012 22:34:35
using channel ORA_DISK_1

starting media recovery
media recovery complete, elapsed time: 00:00:00

Finished recover at 02-09-2012 22:34:36

RMAN> alter database open;

database opened
Now have a look at the second recovery scenario. What it really makes the difference is when you have to recover a read-only tablespace after a restore of the entire database. Until a certain release Oracle didn't restore the read-only tablespace: you had to expressly issue the restore command.Let's simulate a lost of all datafiles.
[oracle@localhost orcl]$ rm APEX_1930613455248703.dbf example01.dbf sysaux01.dbf system01.dbf undotbs01.dbf users01.dbf
[oracle@localhost orcl]$ mv read_only01.dbf read_only01.dbf.20120903_074547.bck
[oracle@localhost orcl]$ ll
total 165544
-rw-rw---- 1 oracle oracle  9814016 Sep  3 07:47 control01.ctl
drwxrwxr-x 2 oracle oracle     4096 Jul 27 07:53 non_default_location
-rw-rw---- 1 oracle oracle  1056768 Sep  2 22:34 read_only01.dbf.20120903_074547.bck
-rw-rw---- 1 oracle oracle 52429312 Sep  3 07:45 redo01.log
-rw-rw---- 1 oracle oracle 52429312 Sep  3 07:45 redo02.log
-rw-rw---- 1 oracle oracle 52429312 Sep  3 07:45 redo03.log
-rw-rw---- 1 oracle oracle 20979712 Sep  2 21:56 temp01.dbf
Start again RMAN and open your instance in MOUNT mode.
[oracle@localhost orcl]$ rman target /

Recovery Manager: Release 11.2.0.2.0 - Production on Mon Sep 3 07:47:09 2012

Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.

connected to target database (not started)

RMAN> startup mount

Oracle instance started
database mounted

Total System Global Area     456146944 bytes

Fixed Size                     1344840 bytes
Variable Size                360712888 bytes
Database Buffers              88080384 bytes
Redo Buffers                   6008832 bytes
Now it's time to restore and recover the entire database
RMAN> restore database;

Starting restore at 03-09-2012 07:48:05
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=19 device type=DISK

creating datafile file number=7 name=/home/oracle/app/oracle/oradata/orcl/read_only01.dbf
channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_DISK_1: restoring datafile 00001 to /home/oracle/app/oracle/oradata/orcl/system01.dbf
channel ORA_DISK_1: restoring datafile 00002 to /home/oracle/app/oracle/oradata/orcl/sysaux01.dbf
channel ORA_DISK_1: restoring datafile 00003 to /home/oracle/app/oracle/oradata/orcl/undotbs01.dbf
channel ORA_DISK_1: restoring datafile 00004 to /home/oracle/app/oracle/oradata/orcl/users01.dbf
channel ORA_DISK_1: restoring datafile 00005 to /home/oracle/app/oracle/oradata/orcl/example01.dbf
channel ORA_DISK_1: restoring datafile 00006 to /home/oracle/app/oracle/oradata/orcl/APEX_1930613455248703.dbf
channel ORA_DISK_1: reading from backup piece /home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_08_28/o1_mf_nnndf_TAG20120828T232719_83vfl839_.bkp
channel ORA_DISK_1: piece handle=/home/oracle/app/oracle/flash_recovery_area/ORCL/backupset/2012_08_28/o1_mf_nnndf_TAG20120828T232719_83vfl839_.bkp tag=TAG20120828T232719
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:04:15
Finished restore at 03-09-2012 07:52:22

RMAN> recover database;

Starting recover at 03-09-2012 07:52:59
using channel ORA_DISK_1

starting media recovery
media recovery complete, elapsed time: 00:00:27

Finished recover at 03-09-2012 07:53:27
Open your database
RMAN> alter database open;

database opened
RMAN is able to gather information about READ_ONLY tablespace
RMAN> report schema;

Report of database schema for database with db_unique_name ORCL

List of Permanent Datafiles
===========================
File Size(MB) Tablespace           RB segs Datafile Name
---- -------- -------------------- ------- ------------------------
1    831      SYSTEM               ***     /home/oracle/app/oracle/oradata/orcl/system01.dbf
2    1105     SYSAUX               ***     /home/oracle/app/oracle/oradata/orcl/sysaux01.dbf
3    40       UNDOTBS1             ***     /home/oracle/app/oracle/oradata/orcl/undotbs01.dbf
4    225      USERS                ***     /home/oracle/app/oracle/oradata/orcl/users01.dbf
5    82       EXAMPLE              ***     /home/oracle/app/oracle/oradata/orcl/example01.dbf
6    7        APEX_1930613455248703 ***     /home/oracle/app/oracle/oradata/orcl/APEX_1930613455248703.dbf
7    1        READ_ONLY            ***     /home/oracle/app/oracle/oradata/orcl/read_only01.dbf

List of Temporary Files
=======================
File Size(MB) Tablespace           Maxsize(MB) Tempfile Name
---- -------- -------------------- ----------- --------------------
1    20       TEMP                 32767       /home/oracle/app/oracle/oradata/orcl/temp01.dbf

RMAN> 
Connecting to the instance I can verify my tablespace is there and available.
[oracle@localhost orcl]$ sqlplus / as sysdba

SQL*Plus: Release 11.2.0.2.0 Production on Mon Sep 3 07:57:44 2012

Copyright (c) 1982, 2010, Oracle.  All rights reserved.


Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL> select * from hr.TEST_RO_TABLE;    

         A
----------
         1
         2
         3
         4
         5
As you can see there's no more any difference.
Until 11gr1 by default, the restore command skipped datafiles associated with read-only tablespaces. If you needed read-only tablespaces restored, then you had to use the "check readonly" command or restore each read-only tablespace individually.
Have a look at the restore syntax on "Oracle Database Backup and Recovery Reference 10g Release 2 (10.2)" Part Number B14194-03  and compare it with the syntax used on "Oracle Database Backup and Recovery Reference 11g Release 1 (11.1) Part Number B28273-03" .

In the latter syntax Oracle introduced the SKIP READONLY option, inverting the previous logic: the SKIP READONLY does not restore read-only files.

That's all