alter system dump datafile ' +DATAC1/LNRFK4PC/DEDCC0CD76F00641E0531738E80A8BF1/DATAFILE/system.1365.1104551497' block min 2760 block max 2765;
#############################################
How to detect and Fix Block Corruption
#############################################
- DBVERIFY always checks the whole data file
- RMAN checks the datafile until the high water mark,
Most Common Way used to remediate Corruption :
1) Point in time Restore database
2) Re-Creating Index and Ctask of table
3) Recover from service from prod or Dr
1) Rman Validate and Block Recover + Data Recovery Advisor .
Oracle Recovery Manager (RMAN) can validate the database using the BACKUP VALIDATE command.
By default the command only checks for physical corruption. Add the CHECK LOGICAL clause to include checks for logical corruption.
The VALIDATE command initiates data integrity checks, logging physical, and optionally logical, block corruptions of database files and backups in the V$DATABASE_BLOCK_CORRUPTION view and the Automatic Diagnostic Repository as one or more failures.
RMAN> BACKUP VALIDATE DATABASE ARCHIVELOG ALL;
The process outputs the same information you would see during a backup, but no backup is created. Any block corruptions are visible in the V$DATABASE_BLOCK_CORRUPTION view, as well as in the RMAN output.
By default the command only checks for physical corruption. Add the CHECK LOGICAL clause to include checks for logical corruption.
RMAN> BACKUP VALIDATE CHECK LOGICAL DATABASE ARCHIVELOG ALL;
RMAN can validate the contents of backup files using the RESTORE VALIDATE command.
RMAN> RESTORE DATABASE VALIDATE;
RMAN> RESTORE ARCHIVELOG ALL VALIDATE;
In a similar way to the BACKUP VALIDATE command, the RESTORE VALIDATE command mimics the process of a restore, without actually performing the restore.
Prior to 11g, the straight VALIDATE command could only be used to validate backup related files. In Oracle 11g onward, the VALIDATE command can also validate datafiles, tablespaces or the whole database, so you can use it in place of the BACKUP VALIDATE command.
RMAN> VALIDATE DATAFILE 1;
RMAN> VALIDATE DATAFILE '/u01/app/oracle/oradata/ORCL/system01.dbf';
RMAN> VALIDATE CHECK LOGICAL DATAFILE 1;
RMAN> VALIDATE CHECK LOGICAL DATAFILE '/u01/app/oracle/oradata/ORCL/system01.dbf';
RMAN> VALIDATE TABLESPACE users;
RMAN> VALIDATE CHECK LOGICAL TABLESPACE users;
RMAN> VALIDATE DATABASE;
RMAN> VALIDATE CHECK LOGICAL DATABASE;
Any block corruptions are visible in the V$DATABASE_BLOCK_CORRUPTION view. You can identify the objects containing a corrupt block using a query like this.
COLUMN owner FORMAT A20
COLUMN segment_name FORMAT A30
SELECT DISTINCT owner, segment_name
FROM v$database_block_corruption dbc
JOIN dba_extents e ON dbc.file# = e.file_id AND dbc.block# BETWEEN e.block_id and e.block_id+e.blocks-1
ORDER BY 1,2;
SET MARKUP HTML ON
Spool /tmp/newdata.html
set lines 200 pages 10000
col segment_name format a30
SELECT e.owner, e.segment_type, e.segment_name, e.partition_name, c.file#
, greatest(e.block_id, c.block#) corr_start_block#
, least(e.block_id+e.blocks-1, c.block#+c.blocks-1) corr_end_block#
, least(e.block_id+e.blocks-1, c.block#+c.blocks-1)
- greatest(e.block_id, c.block#) + 1 blocks_corrupted
, null description
FROM dba_extents e, v$database_block_corruption c
WHERE e.file_id = c.file#
AND e.block_id <= c.block# + c.blocks - 1
AND e.block_id + e.blocks - 1 >= c.block#
UNION
SELECT s.owner, s.segment_type, s.segment_name, s.partition_name, c.file#
, header_block corr_start_block#
, header_block corr_end_block#
, 1 blocks_corrupted
, 'Segment Header' description
FROM dba_segments s, v$database_block_corruption c
WHERE s.header_file = c.file#
AND s.header_block between c.block# and c.block# + c.blocks - 1
UNION
SELECT null owner, null segment_type, null segment_name, null partition_name, c.file#
, greatest(f.block_id, c.block#) corr_start_block#
, least(f.block_id+f.blocks-1, c.block#+c.blocks-1) corr_end_block#
, least(f.block_id+f.blocks-1, c.block#+c.blocks-1)
- greatest(f.block_id, c.block#) + 1 blocks_corrupted
, 'Free Block' description
FROM dba_free_space f, v$database_block_corruption c
WHERE f.file_id = c.file#
AND f.block_id <= c.block# + c.blocks - 1
AND f.block_id + f.blocks - 1 >= c.block#
ORDER BY file#, corr_start_block#;
SET MARKUP HTML off
V$COPY_CORRUPTION
This view displays information about datafile copy corruptions from the control file.
Read here about the column definition of this table.
V$BACKUP_CORRUPTION
This view displays information about corrupt block ranges in datafile backups from the control file.
Read here about the column definition of this table.
After Validate has been run we can repair using either REPAIR FAILURE or block recover command
RMAN> LIST FAILURE;
RMAN> ADVISE FAILURE; / RMAN> advise failure all;
RMAN> REPAIR FAILURE PREVIEW;
RMAN> REPAIR FAILURE NOPROMPT; / RMAN> repair failure;
RMAN> CHANGE FAILURE 202 PRIORITY LOW;
To Fix corruption we can Run “blockrecover corruption list”
Need to run after backup check logical validate database .
Execute the BLOCKRECOVER command at the RMAN prompt, specifying the file and block numbers for the corrupted blocks and limiting the backup candidates by means of the available options. For example, you can specify what type of backup should be used to restore the blocks:
# restore from backupset
RMAN> BLOCKRECOVER DATAFILE 8 BLOCK 13 DATAFILE 2 BLOCK 19 FROM BACKUPSET;
# restore from datafile image copy
RMAN> BLOCKRECOVER DATAFILE 8 BLOCK 13 DATAFILE 2 BLOCK 19 FROM DATAFILECOPY;
You can indicate the backup by specifying a tag:
# restore from backupset with tag "mondayam"
RMAN> BLOCKRECOVER DATAFILE 8 BLOCK 13 DATAFILE 2 BLOCK 199 FROM TAG = mondayam;
You can limit the backup candidates to those made before a certain point:
# restore using backups made before one week ago
RMAN> BLOCKRECOVER DATAFILE 8 BLOCK 13 DATAFILE 2 BLOCK 19
RESTORE UNTIL 'SYSDATE-7';
# restore using backups made before SCN 100
RMAN> BLOCKRECOVER DATAFILE 8 BLOCK 13 DATAFILE 2 BLOCK 19
RESTORE UNTIL SCN 100;
# restore using backups made before log sequence 7024
RMAN> BLOCKRECOVER DATAFILE 8 BLOCK 13 DATAFILE 2 BLOCK 19
RESTORE UNTIL SEQUENCE 7024;
Note that if you limit the restore of datablocks with the UNTIL clause, then RMAN must perform more recovery on the blocks, and the recovery phase must scan all logs for changes to the specified blocks.
Examples
Recovering a Group of Corrupt Blocks: Example
This example recovers corrupt blocks in three datafiles:
BLOCKRECOVER DATAFILE 2 BLOCK 12, 13 DATAFILE 3 BLOCK 5, 98, 99 DATAFILE 4 BLOCK 19;
Limiting Block Media Recovery by Type of Restore: Example
The following example recovers a series of blocks and restores only from datafile copies:
RUN
{
BLOCKRECOVER DATAFILE 3 BLOCK 2,3,4,5 TABLESPACE sales DBA 4194405, 4194409, 4194412
FROM DATAFILECOPY;
}
Limiting Block Media Recovery by Backup Tag: Example
This example recovers blocks and restores only from the backup with the tag weekly_backup:
BLOCKRECOVER TABLESPACE SYSTEM DBA 4194404, 4194405 FROM TAG "weekly_backup";
Limiting Block Media Recovery by Time: Example
The following example recovers two blocks in the SYSTEM tablespace. It restores only from backups that could be used to recover the database to a point two days ago:
BLOCKRECOVER TABLESPACE SYSTEM DBA 4194404, 4194405 RESTORE UNTIL TIME 'SYSDATE-2';
Repairing All Block Corruption in the Database: Example
The following example runs a backup validation to populate V$DATABASE_BLOCK_CORRUPTION, then repairs any corrupt blocks recorded in the view:
BACKUP VALIDATE DATABASE;
BLOCKRECOVER CORRUPTION LIST;
Commands that can be used:
RMAN> backup check logical validate datafile 1672;
RMAN> backup validate check logical database;
RMAN> blockrecover corruption list;
RMAN> blockrecover datafile 1281 block 8759;
RMAN> blockrecover datafile 1281 block 8759 from tag 'TAG20100101T200011';
RMAN> list backup of datafile 1281;
RMAN> BLOCKRECOVER DATAFILE 172 block 59903 DATAFILE 1607 block 368273 DATAFILE 1630 block 406686 DATAFILE 1574 block 197819 DATAFILE 1753 block 304906 DATAFILE 1607 block 443063 DATAFILE 1729 block 952410;
RMAN> BLOCKRECOVER DATAFILE 172 block 59903 DATAFILE 1607 block 368273 DATAFILE 1630 block 406686 DATAFILE 1574 block 197819 DATAFILE 1753 block 304906 DATAFILE 1607 block 443063 DATAFILE 1729 block 952410 from tag 'TAG20100101T200011';
2) dbverify utility
https://docs.oracle.com/cd/E11882_01/server.112/e22490/dbverify.htm#SUTIL1536
DBVerify is an external utility that allows validation of offline and online datafiles. In addition to offline datafiles it can be used to check the validity of backup datafiles.
C:\>dbv file=C:\Oracle\oradata\TSH1\system01.dbf feedback=10000 blocksize=8192
This utility is not usually used for controlfiles or redo logs, but in MOS Doc ID 1949795.1 there is an example of using it with controlfiles.
DBVerify to validate the Segment
Note: User must have sysdba privilieges
col segment_name for a12
col tablespace_name for a15
select tablespace_name, segment_name, TABLESPACE_ID, HEADER_FILE, HEADER_BLOCK
from sys.sys_user_segs where SEGMENT_NAME like 'TEST%';
TABLESPACE_NAME SEGMENT_NAME TABLESPACE_ID HEADER_FILE HEADER_BLOCK
--------------- ------------ ------------- ----------- ------------
SYSTEM TEST10 0 1 32776
SYSTEM TEST20 0 1 32784
Advertisements
REPORT THIS AD
-- User has the sysdba priviliges
dbv SEGMENT_ID=0.1.32784
Script to get list of DBV commands of all datafiles
set echo off
set feedback off
set verify off
set pages 0
set termout off
set linesize 150
spool dbv.cmd
select 'dbv file=' || name || ' blocksize=' || block_size || ' feedback=' || round(blocks*.10,0) from v$datafile;
spool off
3) Full database export -- exp/expdp or Perform Count(*) on Table
4) Analyze validate structure Command :
Run UTLVALID.SQL to create INVALID_ROWS table.
SQL> alter session set tracefile_identifier=’ANALYZE’;
SQL> analyze table SALES.PURCHASEITEMS validate structure online;
The following statement analyses the EMPLOYEES table:
ANALYZE TABLE EMPLOYEES VALIDATE STRUCTURE;
You can validate an object and all dependent objects (for example, indexes) by including the CASCADE option:
ANALYZE TABLE EMPLOYEES VALIDATE STRUCTURE CASCADE;
By default the CASCADE option performs a complete validation. Because this operation can be resource intensive, you can perform a faster version of the validation by using the FAST clause. This version checks for the existence of corruptions using an optimized check algorithm, but does not report details about the corruption. If the FAST check finds a corruption, you can then use the CASCADE option without the FAST clause to locate it.
ANALYZE TABLE EMPLOYEES VALIDATE STRUCTURE CASCADE FAST;
You can specify that you want to perform structure validation online while DML is occurring against the object being validated. There can be a slight performance impact when validating with ongoing DML affecting the object, but this is offset by the flexibility of being able to perform ANALYZE online. The following statement validates the emp table and all associated indexes online:
ANALYZE TABLE EMPLOYEES VALIDATE STRUCTURE CASCADE ONLINE;
5) DBMS_REPAIR : (Doc ID 556733.1)
REM Create the repair table in a given tablespace:
BEGIN
DBMS_REPAIR.ADMIN_TABLES (
TABLE_NAME => 'REPAIR_TABLE',
TABLE_TYPE => dbms_repair.repair_table,
ACTION => dbms_repair.create_action,
TABLESPACE => '&tablespace_name');
END;
/
Creating an Orphan Key Table
BEGIN
DBMS_REPAIR.ADMIN_TABLES (
TABLE_NAME => 'ORPHAN_KEY_TABLE',
TABLE_TYPE => dbms_repair.orphan_table,
ACTION => dbms_repair.create_action,
TABLESPACE => 'USERS');
END;
/
REM Identify corrupted blocks for schema.object (it also can be done at partition level with parameter PARTITION_NAME):
set serveroutput on
DECLARE num_corrupt INT;
BEGIN
num_corrupt := 0;
DBMS_REPAIR.CHECK_OBJECT (
SCHEMA_NAME => '&schema_name',
OBJECT_NAME => '&object_name',
REPAIR_TABLE_NAME => 'REPAIR_TABLE',
corrupt_count => num_corrupt);
DBMS_OUTPUT.PUT_LINE('number corrupt: ' || TO_CHAR (num_corrupt));
END;
/
REM Optionally display any corrupted block identified by check_object:
select BLOCK_ID, CORRUPT_TYPE, CORRUPT_DESCRIPTION
from REPAIR_TABLE;
REM Mark the identified blocks as corrupted ( Soft Corrupt - reference Note 1496934.1 )
DECLARE num_fix INT;
BEGIN
num_fix := 0;
DBMS_REPAIR.FIX_CORRUPT_BLOCKS (
SCHEMA_NAME => '&schema_name',
OBJECT_NAME=> '&object_name',
OBJECT_TYPE => dbms_repair.table_object,
REPAIR_TABLE_NAME => 'REPAIR_TABLE',
FIX_COUNT=> num_fix);
DBMS_OUTPUT.PUT_LINE('num fix: ' || to_char(num_fix));
END;
/
Finding Index Entries Pointing to Corrupt Data Blocks.
This procedure is useful in identifying orphan keys in indexes that are pointing to corrupt rows of the table:
SET SERVEROUTPUT ON
DECLARE num_orphans INT;
BEGIN
num_orphans := 0;
DBMS_REPAIR.DUMP_ORPHAN_KEYS (
SCHEMA_NAME => 'SCOTT',
OBJECT_NAME => 'PK_DEPT',
OBJECT_TYPE => dbms_repair.index_object,
REPAIR_TABLE_NAME => 'REPAIR_TABLE',
ORPHAN_TABLE_NAME=> 'ORPHAN_KEY_TABLE',
KEY_COUNT => num_orphans);
DBMS_OUTPUT.PUT_LINE('orphan key count: ' || TO_CHAR(num_orphans));
END;
/
REM Allow future DML statements to skip the corrupted blocks:
BEGIN
DBMS_REPAIR.SKIP_CORRUPT_BLOCKS (
SCHEMA_NAME => '&schema_name',
OBJECT_NAME => '&object_name',
OBJECT_TYPE => dbms_repair.table_object,
FLAGS => dbms_repair.SKIP_FLAG);
END;
/
6) DBMS_HM.RUN_CHECK
Check DBMS HM performed which health Checkup
col name for a30
SELECT name FROM v$hm_check WHERE internal_check='N';
NAME
------------------------------------
DB Structure Integrity Check
Data Block Integrity Check
Redo Integrity Check
Transaction Integrity Check
Undo Segment Integrity Check
Dictionary Integrity Check
Check the parameter name present in the Health checkup and used while running the health check with DBMS_HM Package
set line 200 pages 200
col check_name for a30
col parameter_name for a20
SELECT c.name check_name, p.name parameter_name
--, p.type,p.default_value, p.description
FROM v$hm_check_param p, v$hm_check c
WHERE p.check_id = c.id and c.internal_check = 'N'
ORDER BY c.name;
CHECK_NAME PARAMETER_NAME
------------------------------ --------------------
ASM Allocation Check ASM_DISK_GRP_NAME
CF Block Integrity Check CF_BL_NUM
Data Block Integrity Check BLC_DF_NUM
Data Block Integrity Check BLC_BL_NUM
Dictionary Integrity Check CHECK_MASK
Dictionary Integrity Check TABLE_NAME
Redo Integrity Check SCN_TEXT
Transaction Integrity Check TXN_ID
Undo Segment Integrity Check USN_NUMBER
Parameters for Data Block Integrity Check
Parameter Name Type Default Value Description
BLC_DF_NUM Number (none) Block data file number
BLC_BL_NUM Number (none) Data block number
Example to run
BEGIN
DBMS_HM.RUN_CHECK (
check_name => ‘Data Block Integrity Check’,
run_name => ‘datablockint’,
input_params => ‘BLC_DF_NUM=4;BLC_BL_NUM=191’);
END;
Execute DBMS_HM.RUN_CHECK('Dictionary Integrity Check', 'report1');
exec DBMS_HM.RUN_CHECK(check_name => ‘Transaction Integrity Check’, run_name => ‘report2’, input_params => ‘TXN_ID=7.33.2’);
Check the health checkup report
SET LONG 100000
SET LONGCHUNKSIZE 1000
SET PAGESIZE 1000
SET LINESIZE 512
SELECT DBMS_HM.GET_RUN_REPORT('REPORT2') FROM DUAL;
Views for DBMS HM for view status, errors and results
SELECT run_id, name, check_name, run_mode, src_incident FROM v$hm_run;
SELECT type, description FROM v$hm_finding ;
Clear HM report
exec dbms_hm.drop_schema(FALSE);
7) Oracle 12c diskgroup scrub repair
SQL> alter diskgroup DG1 scrub repair;
Diskgroup altered.
SQL> alter diskgroup DG1 scrub file '+DATA_DISK/DATAFILE/system.254.939393617' repair wait;
Diskgroup altered.
SQL> alter diskgroup DG1 scrub disk DATA_DISK1 repair power max force;
Diskgroup altered
REPAIR: If the repair option is not specified, ASM only check and report logical corruption
POWER: LOW, HIGH, or MAX. If power is not specified, the scrubbing power is controlled based on the system I/O load
FORCE: Command is processed immediately regarless of system load
Two ways of scrubbing: On-demand by administrator on specific area as like above, Occur as part of rebalance operation if disk attribute content.check=TRUE mentioned at disk level.
SQL> alter diskgroup DG1 attribute 'content.check' = 'TRUE';
Diskgroup altered.
8) Handling Redo log corruption
Errors in file C:\APP\PC\diag\rdbms\admin\admin\trace\admin_lgwr_8104.trc:
ORA-00313: open failed for members of log group 5 of thread 1
ORA-00312: online log 5 thread 1: 'u01/redol/REDO07.LOG'
ORA-27046: file size is not a multiple of logical block size
OSD-04012: file size mismatch (OS 10484100)
SELECT GROUP#, ARCHIVED,STATUS FROM V$LOG;
SELECT GROUP#,L.STATUS,V.MEMBER,L.SEQUENCE# FROM V$LOG L JOIN V$LOGFILE V USING (GROUP#) ORDER BY GROUP#;
STARTUP MOUNT
ALTER DATABASE CLEAR UNARCHIVED LOGFILE;
ALTER DATABASE CLEAR LOGFILE;
Shu immediate
Startup mount
ALTER DATABASE CLEAR UNARCHIVED LOGFILE GROUP 6;
Alter Database open ;
ALTER SYSTEM SWITCH LOGFILE;
9) Checking Archivelog Corruption
SQL> exec dbms_logmnr.add_logfile('<path>/<arch file name>.arc');
SQL> exec dbms_logmnr.start_logmnr;
SQL> select count(1) from v$logmnr_contents;
When the archive file is good, you will be able to execute logmnr and select from the view:
SQL> exec dbms_logmnr.add_logfile('/rdbms/oracle/ora1022i/64/admin/ora1022a/arch/1_mf_1_879_56dggmtf_.arc');
SQL> exec dbms_logmnr.start_logmnr;
SQL> select count(1) from v$logmnr_contents;
COUNT(1)
----------
18466
If the archive is bad, logmnr will not be able to access it:
SQL> exec dbms_logmnr.add_logfile('/rdbms/oracle/ora1022i/64/admin/ora1022a/arch/
wqbsqa01_652800616_1_4265.arc');
BEGIN dbms_logmnr.add_logfile('/rdbms/oracle/ora1022i/64/admin/ora1022a/arch/wqbsqa01_652800616_1_4265.arc'); END;
*
ERROR at line 1:
ORA-01284: file
/rdbms/oracle/ora1022i/64/admin/ora1022a/arch/wqbsqa01_652800616_1_4265.arc cannot be opened
ORA-00308: cannot open archived log
'/rdbms/oracle/ora1022i/64/admin/ora1022a/arch/wqbsqa01_652800616_1_4265.arc'
ORA-27047: unable to read the header block of file
OSD-04001: invalid logical block size (OS 3899694081)
ORA-06512: at "SYS.DBMS_LOGMNR", line 68
ORA-06512: at line 1
We can also use dump logfile method prescribed below
SQL> oradebug setmypid
SQL> alter system dump logfile 'Archive_log_path.arc' validate;
SQL> oradebug tracefile_name