Description:-
Description:-
- This feature is available form Oracle 11g called the Data Recovery Advisor.
- Data Recovery Advisor tool will automatically diagnose data failures, such as corruption or loss of persistent datafile on disk.
- Prior to Oracle Database 11g,only block corruptions that were detected by RMAN were recorded in V$DATABASE_BLOCK_CORRUPTION.
- Starting with Oracle Database 11g,several database components and utilities, including RMAN and Automatic Diagnostic
Repository (ADR), can detect a corrupt block and record it in that view. - Oracle Database automatically updates this view when block corruptions are detected or repaired.
- Data Recovery Advisor tool is used for recovery process to complete the Mean Time To Recover (MTTR).
Detection and Diagnosis Using Data Recovery Advisor.
Data Recovery Advisor commands are
- List Failure
- Advise Failure
- Repair Failure
- Change Failure
- Validate
- The Data Recovery Advisor automatically diagnoses data failures, determines and presents
appropriate repair options, and performs repair operations at the user’s request. - Data Recovery Advisor improves the manageability and reliability of an Oracle database.
- You can use Data Recovery Advisor to troubleshoot primary databases,logical standby databases, and snapshot
standby databases
Let’s Start the Demo:-
- This article i am going to corrupt the block and recover using ADR Method. The demo is done on 19c database the same way for 12c also.
- I have corrupted blocks on my demo 19c database affecting the oracledba table of the tablespace hari
Step1:-Create tablepsace(Hari) and table(oracledba) for Demo.
SQL> create tablespace hari datafile'/u01/CLONE/datafile/hari.dbf' size 5m;
Tablespace created.
Create table and store in the new tablespace
SQL> create table oracldba as select * from all_objects;
Table created.
SQL> select count(*) from oracldba;
COUNT(*)
----------
54886
Step2:-Check the Block Header of the Table
SQL> select segment_name , header_file , header_block from dba_segments where segment_name like '%ORACL%';
SEGMENT_NAME HEADER_FILE HEADER_BLOCK
----------- ------------ ---------------
ORACLDBA 8 130
Step3:-Before going to corrupt the block take rman backup
[oracle@ram ~]$ rman target /
Recovery Manager: Release 19.0.0.0.0 - Production on Wed May 22 00:20:38 2019
Version 19.2.0.0.0
Copyright (c) 1982, 2019, Oracle and/or its affiliates. All rights reserved.
connected to target database: CLONE (DBID=1337475478)
RMAN> backup tablespace HARI;
Starting backup at 22-MAY-19
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=64 device type=DISK
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00008 name=/u01/CLONE/datafile/hari.dbf
channel ORA_DISK_1: starting piece 1 at 22-MAY-19
channel ORA_DISK_1: finished piece 1 at 22-MAY-19
piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/04u2503u_1_1 tag=TAG20190522T002117 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 22-MAY-19
Starting Control File Autobackup at 22-MAY-19
piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/c-1337475478-20190522-00 comment=NONE
Finished Control File Autobackup at 22-MAY-19
Step4:-Corrupt the block using OS command (DD). (Do Not Try This in Client Database)
cd /u01/CLONE/datafile/
[oracle@ram ~]$ cd /u01/CLONE/datafile/
[oracle@ram datafile]$ dd of=hari.dbf bs=8192 conv=notrunc seek=130 <<EOF
> EOF
0+1 records in
0+1 records out
1 byte (1 B) copied, 0.0189029 s, 0.1 kB/s
Step5:-After the Block Corruption to check using DBV Utility
dbv file=hari.dbf
[oracle@ram datafile]$ dbv file=hari.dbf
DBVERIFY: Release 19.0.0.0.0 - Production on Wed May 22 00:31:14 2019
Copyright (c) 1982, 2019, Oracle and/or its affiliates. All rights reserved.
DBVERIFY - Verification starting : FILE = /u01/CLONE/datafile/hari.dbf
Page 130 is influx - most likely media corrupt
Corrupt block relative dba: 0x02000082 (file 8, block 130)
Fractured block found during dbv:
Data in bad block:
type: 10 format: 2 rdba: 0x02000082
last change scn: 0x0000.0000.0028672d seq: 0x1 flg: 0x04
spare3: 0x0
consistency value in tail: 0x672d2301
check value in block header: 0xb7cf
computed block checksum: 0x29
DBVERIFY - Verification complete
Total Pages Examined : 12800
Total Pages Processed (Data) : 1096
Total Pages Failing (Data) : 0
Total Pages Processed (Index): 0
Total Pages Failing (Index): 0
Total Pages Processed (Other): 152
Total Pages Processed (Seg) : 0
Total Pages Failing (Seg) : 0
Total Pages Empty : 11551
Total Pages Marked Corrupt : 1
Total Pages Influx : 1
Total Pages Encrypted : 0
Highest block SCN : 2647849 (0.2647849)
Here we are unable to get the count of the table (oracldba)
[oracle@ram datafile]$ export ORACLE_SID=clone
[oracle@ram datafile]$ sqlplus / as sysdba
SQL*Plus: Release 19.0.0.0.0 - Production on Wed May 22 00:33:06 2019
Version 19.2.0.0.0
Copyright (c) 1982, 2018, Oracle. All rights reserved.
Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.2.0.0.0
SQL> conn ram/ram
Connected.
SQL> select count(*) from oracldba;
*
ERROR at line 1:
ORA-28304: Oracle encrypted block is corrupt (file # 8, block # 130)
ORA-01110: data file 8: ‘/u01/CLONE/datafile/hari.dbf’
Step6:-Recover the Corrupt block Using Data Recovery Advisor Concept
VALIDATE CHECK LOGICAL TABLESPACE hari;
RMAN> VALIDATE CHECK LOGICAL TABLESPACE hari;
Starting validate at 22-MAY-19
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=1 device type=DISK
channel ORA_DISK_1: starting validation of datafile
channel ORA_DISK_1: specifying datafile(s) for validation
input datafile file number=00008 name=/u01/CLONE/datafile/hari.dbf
channel ORA_DISK_1: validation complete, elapsed time: 00:00:03
List of Datafiles
=================
File Status Marked Corrupt Empty Blocks Blocks Examined High SCN
---- ------ -------------- ------------ --------------- ----------
8 FAILED 0 11551 12800 2647849
File Name: /u01/CLONE/datafile/hari.dbf
Block Type Blocks Failing Blocks Processed
---------- -------------- ----------------
Data 0 1096
Index 0 0
Other 1 153
validate found one or more corrupt blocks
See trace file /u01/app/oracle/diag/rdbms/clone/clone/trace/clone_ora_48768.trc for details
Finished validate at 22-MAY-19
List Failure:-
RMAN> list failure;
Database Role: PRIMARY
List of Database Failures
=========================
Failure ID Priority Status Time Detected Summary
---------- -------- --------- ------------- -------
321 HIGH OPEN 22-MAY-19 Datafile 8: '/u01/CLONE/datafile/hari.dbf' contains one or more corrupt blocks
105 HIGH OPEN 21-MAY-19 Name for datafile 5 is unknown in the control file
102 HIGH OPEN 21-MAY-19 Name for datafile 2 is unknown in the control file
Advise failure all:-
RMAN> list failure;
Database Role: PRIMARY
List of Database Failures
=========================
Failure ID Priority Status Time Detected Summary
---------- -------- --------- ------------- -------
321 HIGH OPEN 22-MAY-19 Datafile 8: '/u01/CLONE/datafile/hari.dbf' contains one or more corrupt blocks
105 HIGH OPEN 21-MAY-19 Name for datafile 5 is unknown in the control file
102 HIGH OPEN 21-MAY-19 Name for datafile 2 is unknown in the control file
Advise failure all:-
RMAN> advise failure all;
Database Role: PRIMARY
List of Database Failures
=========================
Failure ID Priority Status Time Detected Summary
---------- -------- --------- ------------- -------
321 HIGH OPEN 22-MAY-19 Datafile 8: '/u01/CLONE/datafile/hari.dbf' contains one or more corrupt blocks
105 HIGH OPEN 21-MAY-19 Name for datafile 5 is unknown in the control file
102 HIGH OPEN 21-MAY-19 Name for datafile 2 is unknown in the control file
analyzing automatic repair options; this may take some time
using channel ORA_DISK_1
analyzing automatic repair options complete
Mandatory Manual Actions
========================
1. If the file exists, rename data file 5 to the name of the real file using ALTER DATABASE RENAME FILE command. If the file does not exist, create a new data file using ALTER DATABASE CREATE DATAFILE command.
2. If the file exists, rename data file 2 to the name of the real file using ALTER DATABASE RENAME FILE command. If the file does not exist, create a new data file using ALTER DATABASE CREATE DATAFILE command.
3. Contact Oracle Support Services if the preceding recommendations cannot be used, or if they do not fix the failures selected for repair
Optional Manual Actions
=======================
no manual actions available
Automated Repair Options
========================
Option Repair Description
------ ------------------
1 Perform block media recovery of block 130 in file 8
Strategy: The repair includes complete media recovery with no data loss
Repair script: /u01/app/oracle/diag/rdbms/clone/clone/hm/reco_136834731.hm
Repair failure:-
RMAN> repair failure;
Strategy: The repair includes complete media recovery with no data loss
Repair script: /u01/app/oracle/diag/rdbms/clone/clone/hm/reco_136834731.hm
contents of repair script:
# block media recovery
recover datafile 8 block 130;
Do you really want to execute the above repair (enter YES or NO)? YES
executing repair script
Starting recover at 22-MAY-19
using channel ORA_DISK_1
channel ORA_DISK_1: restoring block(s)
channel ORA_DISK_1: specifying block(s) to restore from backup set
restoring blocks of datafile 00008
channel ORA_DISK_1: reading from backup piece /u01/app/oracle/product/19.0.0/dbhome_1/dbs/04u2503u_1_1
channel ORA_DISK_1: piece handle=/u01/app/oracle/product/19.0.0/dbhome_1/dbs/04u2503u_1_1 tag=TAG20190522T002117
channel ORA_DISK_1: restored block(s) from backup piece 1
channel ORA_DISK_1: block restore complete, elapsed time: 00:00:01
starting media recovery
media recovery complete, elapsed time: 00:00:03
Finished recover at 22-MAY-19
repair failure complete
[oracle@ram datafile]$ !sq
sqlplus / as sysdba
SQL*Plus: Release 19.0.0.0.0 - Production on Wed May 22 00:42:35 2019
Version 19.2.0.0.0
Copyright (c) 1982, 2018, Oracle. All rights reserved.
Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.2.0.0.0
SQL> conn ram/ram
Connected.
SQL> select count(*) from oracldba;
COUNT(*)
----------
54886
Catch Me On:- Hariprasath Rajaram
LinkedIn: https://www.linkedin.com/in/hari-prasath-aa65bb19/
Facebook: https://www.facebook.com/HariPrasathdba
FB Group: https://www.facebook.com/groups/894402327369506/
FB Page: https://www.facebook.com/dbahariprasath/?
Twitter: https://twitter.com/hariprasathdba