How to resolve media failures with the Recovery Advisor in #Oracle

rescue

Error messages are showing up because files have been damaged? Database Recovery Advisor to the rescue!

[oracle@uhesse ~]$ sqlplus / as sysdba

SQL*Plus: Release 12.1.0.2.0 Production on Wed Sep 7 11:52:24 2016

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


Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options

SQL> select name from v$datafile;

NAME
--------------------------------------------------------------------------------
/u01/app/oracle/oradata/prima/system01.dbf
/u01/app/oracle/oradata/prima/sysaux01.dbf
/u01/app/oracle/oradata/prima/undotbs01.dbf
/u01/app/oracle/oradata/prima/users01.dbf

SQL> host echo kaputt > /u01/app/oracle/oradata/prima/users01.dbf

SQL> select count(*) from adam.sales;
select count(*) from adam.sales
                          *
ERROR at line 1:
ORA-01115: IO error reading block from file  (block # )
ORA-01115: IO error reading block from file 4 (block # 147)
ORA-27072: File I/O error
Additional information: 4
Additional information: 147

Don’t do that at home, but the above prepared the playground to show how to resolve media errors easily. I’m using 12.1.0.2 here, but the shown functionality is available since 11.1 already.

SQL> exit
Disconnected from Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
[oracle@uhesse ~]$ rman target /

Recovery Manager: Release 12.1.0.2.0 - Production on Wed Sep 7 12:02:47 2016

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

connected to target database: PRIMA (DBID=2131944058)

RMAN> list failure;

using target database control file instead of recovery catalog
Database Role: PRIMARY

no failures found that match specification

If the failure is not already listed, you should run the following check (works in 12c from the RMAN shell as shown, in 11g you need to run it from SQL*Plus):

RMAN> begin
 dbms_hm.run_check ('DB Structure Integrity Check','mycheck');
end;
/

Statement processed

RMAN> list failure;

Database Role: PRIMARY

List of Database Failures
=========================

Failure ID Priority Status    Time Detected       Summary
---------- -------- --------- ------------------- -------
42         HIGH     OPEN      2016-09-07 12:05:04 One or more non-system datafiles are corrupt

The failure is now listed. Next steps:

RMAN> advise failure;

Database Role: PRIMARY

List of Database Failures
=========================

Failure ID Priority Status    Time Detected       Summary
---------- -------- --------- ------------------- -------
42         HIGH     OPEN      2016-09-07 12:05:04 One or more non-system datafiles are corrupt

analyzing automatic repair options; this may take some time
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=20 device type=DISK
analyzing automatic repair options complete

Mandatory Manual Actions
========================
no manual actions available

Optional Manual Actions
=======================
no manual actions available

Automated Repair Options
========================
Option Repair Description
------ ------------------
1      Restore and recover datafile 4  
  Strategy: The repair includes complete media recovery with no data loss
  Repair script: /u01/app/oracle/diag/rdbms/prima/prima/hm/reco_1884775430.hm

RMAN> repair failure preview;

Strategy: The repair includes complete media recovery with no data loss
Repair script: /u01/app/oracle/diag/rdbms/prima/prima/hm/reco_1884775430.hm

contents of repair script:
   # restore and recover datafile
   sql 'alter database datafile 4 offline';
   restore ( datafile 4 );
   recover datafile 4;
   sql 'alter database datafile 4 online';

So that’s good to know: ‚The repair includes complete media recovery with no data loss‘ 🙂 Let’s do that:

RMAN> repair failure;

Strategy: The repair includes complete media recovery with no data loss
Repair script: /u01/app/oracle/diag/rdbms/prima/prima/hm/reco_1884775430.hm

contents of repair script:
   # restore and recover datafile
   sql 'alter database datafile 4 offline';
   restore ( datafile 4 );
   recover datafile 4;
   sql 'alter database datafile 4 online';

Do you really want to execute the above repair (enter YES or NO)? yes
executing repair script

sql statement: alter database datafile 4 offline

Starting restore at 2016-09-07 12:08:43
using channel ORA_DISK_1

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 00004 to /u01/app/oracle/oradata/prima/users01.dbf
channel ORA_DISK_1: reading from backup piece /u02/reco/PRIMA/backupset/2016_04_26/o1_mf_nnndf_TAG20160426T105118_ckyc07n5_.bkp
channel ORA_DISK_1: piece handle=/u02/reco/PRIMA/backupset/2016_04_26/o1_mf_nnndf_TAG20160426T105118_ckyc07n5_.bkp tag=TAG20160426T105118
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:01:15
Finished restore at 2016-09-07 12:09:58

Starting recover at 2016-09-07 12:09:58
using channel ORA_DISK_1

starting media recovery

archived log for thread 1 with sequence 37 is already on disk as file /u02/reco/PRIMA/archivelog/2016_04_26/o1_mf_1_37_ckyc311q_.arc
archived log for thread 1 with sequence 38 is already on disk as file /u02/reco/PRIMA/archivelog/2016_04_26/o1_mf_1_38_ckyc373o_.arc
archived log for thread 1 with sequence 39 is already on disk as file /u02/reco/PRIMA/archivelog/2016_04_26/o1_mf_1_39_ckyc3co9_.arc
archived log file name=/u02/reco/PRIMA/archivelog/2016_04_26/o1_mf_1_37_ckyc311q_.arc thread=1 sequence=37
archived log file name=/u02/reco/PRIMA/archivelog/2016_04_26/o1_mf_1_38_ckyc373o_.arc thread=1 sequence=38
media recovery complete, elapsed time: 00:00:01
Finished recover at 2016-09-07 12:10:01

sql statement: alter database datafile 4 online
repair failure complete

The Recovery Advisor did not only resolve the problem but it did also choose the solution with the least impact on availability: Restore and recovery has been done with the instance in status OPEN. Is the error now gone?

RMAN> select count(*) from adam.sales;

  COUNT(*)
----------
  10000000

Problem solved! Think of the Recovery Advisor as your personal first level support: There are problems that are too difficult for this tool to resolve, but it may be able to do a pretty good job as in this example. It doesn’t support RAC and cannot resolve issues at a standby database in a Data Guard  environment. Many more details are here, but essentially, you just need to memorize these three commands: LIST FAILURE, ADVISE FAILURE, REPAIR FAILURE. I think that’s not too much to ask, even with a very high stress level 🙂

  1. #1 von Herlindo am September 14, 2016 - 07:19

    Hi Uheese,

    „and cannot resolve issues at a standby database in a Data Guard environment“
    Good news At least in 12c it seems to be data guard aware as it was able to solve corruption of sysaux datafile in standby, got it fixed by restoring file again pulling it over the network ( from service clause in 12c) 🙂

  2. #2 von jignesh jethwa am September 14, 2016 - 13:27

    Hello Uhesse,
    I appreciate your efforts for this post, I used to follow your post and get inspired to write something for my team and my online followers. Thank you for knowledge and inspiration.
    One off bit question please, How do you prepared playground for this post? I mean to demonstrate oracle error (ORA-01115: IO error reading)

    Thanks in Advance.

  3. #3 von Uwe Hesse am September 27, 2016 - 16:55

    This line destroys the datafile:
    SQL> host echo kaputt > /u01/app/oracle/oradata/prima/users01.dbf

    Don’t do that with your production database 😉

Kommentar verfassen

Trage deine Daten unten ein oder klicke ein Icon um dich einzuloggen:

WordPress.com-Logo

Du kommentierst mit Deinem WordPress.com-Konto. Abmelden /  Ändern )

Twitter-Bild

Du kommentierst mit Deinem Twitter-Konto. Abmelden /  Ändern )

Facebook-Foto

Du kommentierst mit Deinem Facebook-Konto. Abmelden /  Ändern )

Verbinde mit %s

Diese Seite verwendet Akismet, um Spam zu reduzieren. Erfahre, wie deine Kommentardaten verarbeitet werden..