11. Dec. 2008

Doing a repeated rman database time based recovery

RMAN>
run{

alter database mount;

set until time “to_date(‘27.10.2008 23:30:00′,’DD.MM.YYYY HH24:MI:SS’)”;

restore database;
recover database delete archivelog;
alter database open resetlogs;
}

without rman catalog repository can fail with error:

RMAN-20207: UNTIL TIME or RECOVERY WINDOW is before RESETLOGS time

To solve the issue

  • list the incarnation id of the database

RMAN> list incarnation;

using target database control file instead of recovery catalog

List of Database Incarnations

DB  Inc DB Name DB ID    STATUS  Reset SCN Reset Time
Key Key

1   1   ORAV10  76765624 PARENT  1         22.11.2007 16:44:40
2   2   ORAV10  76765624 PARENT  4921103   09.04.2008 11:38:07
3   3   ORAV10  76765624 ORPHAN  15854298  27.11.2008 11:43:33
4   4   ORAV10  76765624 CURRENT 15854298  27.11.2008 17:38:11

  • set the database in mount status to incarnation id that is fitting to the selected restore time

 
RMAN> shutdown immediate;
RMAN> startup mount;
RMAN> reset database to incarnation 2;

  • repeat the database time based recovery

Be careful: Do not restore controlfile. If you do so, incarnation is set the latest id and you run into same error.

RMAN> list incarnation;

List of Database Incarnations

DB  Inc DB Name DB ID    STATUS  Reset SCN Reset Time
Key Key

1   1   ORAV10  76765624 PARENT  1         22.11.2007 16:44:40
2   2   ORAV10  76765624 PARENT  4921103   09.04.2008 11:38:07
5   5   ORAV10  76765624 CURRENT 15783824  10.12.2008 16:03:56
4   4   ORAV10  76765624 ORPHAN  15854298  27.11.2008 17:38:11
3   3   ORAV10  76765624 ORPHAN  15854298  27.11.2008 11:43:33

In some cases you get errors during recovery
ORA-00283: recovery session canceled due to errors
ORA-00081: address range [0x60000000000A7D70, 0x60000000000A7D74) is not readable
ORA-00600: internal error code, arguments: [kcvsor_current_inc_rdfail], [0], [], [], [], [], [], []

In this case you have to restore an adequate controlfile created in selected recovery time frame and that has the same incarnation as the datafiles (see also oracle support Note:378273.1)

10. Dec. 2008

Since Oracle Version 10G ist is possible to transfer tablespaces no longer only between platforms of the same architecture. Now in 10G it also possible to transport from any platform to any platform, provided the platforms belong to the list below:

SQL>  select * from v$transportable_platform;

   PLATFORM_ID PLATFORM_NAME                    ENDIAN_FORMAT
  
             1 Solaris[tm] OE (32-bit)          Big
             2 Solaris[tm] OE (64-bit)          Big
             7 Microsoft Windows NT             Little
            10 Linux IA (32-bit)                Little
             6 AIX-Based Systems (64-bit)       Big
             3 HP-UX (64-bit)                   Big
             5 HP Tru64 UNIX                    Little
             4 HP-UX IA (64-bit)                Big
            11 Linux IA (64-bit)                Little
            15 HP Open VMS                      Little
             8 Microsoft Windows IA (64-bit)    Little
             9 IBM zSeries Based Linux          Big
            13 Linux 64-bit for AMD             Little
            16 Apple Mac OS                     Big
            12 Microsoft Windows 64-bit for AMD Little

But be aware that depending on which plattforms we deal with there might be some converting necessary or not!

To help you with that, I have carried together the little cook book about “How to do” below:

1. Set the tablespace to READ ONLY

SQL> alter tablespace USERS read only;
Tablespace altered.
 

2. Export metadata

exp userid=\’/ as sysdba\’ transport_tablespace=y
tablespaces=users
file=users_tts.dmp log=exp_users_tts.log
statistics=none

3. Converting tablespace if necessary

Depending on we have to convert the file between endianness Little and endianness Big (forward or backward) we can do that with RMAN:

rman target=/

Recovery Manager: Release 10.2.0.3.0 – Production on Wed Dec 10 13:10:57 2008
connected to target database: orav10 (DBID=1953618181)

RMAN> convert tablespace ‘USERS’
2>  to platform=”Linux IA (32-bit)”
3>  db_file_name_convert=’/database/orav10/datafiles/users.dbf’,
4>  ‘/tmp/users.dbf’;

4. Move datafiles and export dump file

$ftp users_tts.dmp

and /database/orav10/datafiles/users.dbf (no conversion)
or /tmp/users.dbf (converted file if conversion had been required)

5. Import metadata

imp userid=\’/ as sysdba\’ TRANSPORT_TABLESPACE=Y
datafiles=
/database/orav10/datafiles/users.dbf
(or
/tmp/users.dbf )
file=users_tts.dmp log=imp_users_tts.log

6. Set the tablespace to READ WRITE

SQL> alter tablespace USERS read write;
Tablespace altered.

9. Dec. 2008

Working with the Oracle Flashback option we can restore the old data using flashback queries. Introduced in Oracle Version 9.2 the “AS OF” clause can be used to:

  • find the old data
  • restore the old data

Mistakenly set the salary of Manager King to a wrong value:

SQL> update emp set sal=4500 where ename=’KING’;
1 row updated.
SQL> commit;
Commit complete.

SQL> select ename, sal from emp where ename=’KING’;
ENAME             SAL
———- ———-
KING             4500

We can query the old value again using the “AS OF” clause and specifying a time interval:

Issuing this query will tell us the correct value as it was existing 15 minutes before.

SELECT ename, sal FROM emp
AS OF TIMESTAMP (SYSTIMESTAMP – INTERVAL ’15’ MINUTE)
WHERE ename = ‘KING’;

ENAME             SAL
———- ———-
KING             5000

Now we can use flashback query as a sub query in an update statement to restore back to the old value. The command is as follows:

update emp
set sal = (
SELECT sal FROM emp
AS OF TIMESTAMP (SYSTIMESTAMP – INTERVAL ’15’ MINUTE) where ename=’KING’)
where ename=’KING’;

In case you are going to use this for testing purposes, you might find it usefully to record the referencing SCN and use flashback query in combination with the recorded SCN.

SQL> select dbms_flashback.get_system_change_number from dual;
GET_SYSTEM_CHANGE_NUMBER
————————
                 4312233

Now changing a value on purpose:

SQL> update emp set sal=4300 where ename=’KING’;
1 row updated.

SQL> commit;
Commit complete.

SQL> select ename, sal from emp where ename=’KING’;
ENAME             SAL
———- ———-
KING             4300

Then you might not know the previous salary of MILLER but you do know the SCN when it refered to the old value and the original value can be updated and restored with flashback query by using the SCN noted prior to the update statement.

Here is the required query:

SELECT ename, sal FROM emp
AS OF SCN 4312233
where ename=’KING’;

ENAME             SAL
———- ———-
KING             4300

And you can restore the old value by updating the row or better you directly restore the old value using the following update with flashback sub query:

update emp
set sal = (
SELECT sal FROM emp
AS OF SCN 4312233 where ename=’KING’)
where ename=’KING’;

« previousnext »