Step 1 – Identify corrupt datafile
The corruption may be reported at the application level, such as DBV and RMAN, or the alert.log.
Step 2 Run DBV/Rman validate on affected datafile and check for corrupt block
Run dbverify on the datafile which reports corrupt block.
# dbv userid=asrinivasan/****** file=/u01/oradata/****/atlas_datafile.dbf
Check the {output filename} for the result
Sample Output:
DBVERIFY: Release 9.2.0.3.0 – Production on Thu Aug 25 11:15:54 2005
Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.
DBVERIFY – Verification starting : FILE = /u01/oradata/****/atlas_datafile.dbf
Page 48740 is marked corrupt ***
Corrupt block relative dba: 0x01c0be64 (file 7, block 48740)
Bad check value found during dbv:
Data in bad block –
type: 0 format: 2 rdba: 0x0000be64
last change scn: 0x0000.00000000 seq: 0x1 flg: 0x05
consistency value in tail: 0x00000001
check value in block header: 0xb964, computed block checksum: 0x2a5a
spare1: 0x0, spare2: 0x0, spare3: 0x0
***
DBVERIFY – Verification complete
Total Pages Examined : 64000
Total Pages Processed (Data) : 0
Total Pages Failing (Data) : 0
Total Pages Processed (Index): 1751
Total Pages Failing (Index): 0
Total Pages Processed (Other): 45
Total Pages Processed (Seg) : 0
Total Pages Failing (Seg) : 0
Total Pages Empty : 62203
Total Pages Marked Corrupt : 1
Note that Block 48740 is reported as corrupt in datafile 7.
Or in RMAN:
For Entire database
Rman> backup validate check logical database ;
For specific datafile
Rman> backup validate check logical datafile <fileno> ;
Once done query
SQL>Select * from v$database_block_corruption ;
**If large number of blocks are reported, proceed to step 4 instead of step 3.
Step 3 – Check whether block is part of any object – For Small Number of Corrupted Blocks
Query dba_extents and cross check the block does not belong to any object :
SQL> select segment_name, segment_type, owner
from dba_extents
where file_id = <Absolute file number>
and <corrupted block number> between block_id
and block_id + blocks -1;
If it doesn’t belong to an object, double check if it does exists in dba_free_space :
SQL> Select * from dba_free_space where file_id= <Absolute file number>
and <corrupted block number> between block_id and block_id + blocks -1;
If the block cannot be found on DBA_FREE_SPACE nor DBA_EXTENTS, the block might be a file space usage bitmap and cannot be reformatted.
Step 4 – Check whether block is part of any object – For Large Number of Corrupted Blocks
If you have already ran rman validate in step 2 go to directly sqlplus script given below to identify the object
$ rman target / nocatalog
or
$ rman target sys/ nocatalog
run {
allocate channel d1 type disk;
allocate channel d2 type disk;
————————————————————————
— multiple channels may be allocated for parallelizing purposes
— depends: RMAN – Min ( MAXOPENFILES , FILESPERSET )
— Defaults: MAXOPENFILES =8, FILESPERSET =64
————————————————————————
allocate channel dn type disk;
backup check logical validate database;
}
Note: if RDBMS is < 11g and NOARCHIVELOG mode, then db must be in MOUNTED mode
*** The RMAN check logical validate database command MUST be executed and completed before going any further.
*** The ‘v$database_block_corruption’ view gets populated upon this command completion.
*** If not complete, you risk to get invalid/incomplete information from the below step.
Run the following sql query to find if the block is in free space or occupied
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#;
Step 5 – Create a dummy table as user other than SYS and SYSTEM
SQL> connect <username>/<password>
Create a dummy table in the tablespace containing datafile which has the corrupt block – and use nologging option to prevent redo records from being generated:
SQL> create table s (
n number,
c varchar2(4000)
) nologging tablespace <tablespace name having the corrupt block> pctfree 99;
Different storage parameters can be used to suit the specific environment.
We use the PCTFREE 99 to speed up the reformat of the block
Verify that the table is created in the correct tablespace by querying user_segments:
SQL> select segment_name,tablespace_name from user_segments
where segment_name=’S’ ;
Please note in 11gr2 due to deferred segment creation concept query from above user_segments may not report any rows in such cases query user_tables
SQL>Select table_name,tablespace_name from user_tables where table_name=’S’ ;
Step 6 – Create trigger on dummy table which throws exception once the corrupted block is reused
Login as SYSDBA
Please note when prompted for file number enter the relative file no(rfile# value from v$datafile)
CREATE OR REPLACE TRIGGER corrupt_trigger
AFTER INSERT ON <username>.s
REFERENCING OLD AS p_old NEW AS new_p
FOR EACH ROW
DECLARE
corrupt EXCEPTION;
BEGIN
IF (dbms_rowid.rowid_block_number(:new_p.rowid)=&blocknumber)
and (dbms_rowid.rowid_relative_fno(:new_p.rowid)=&filenumber) THEN
RAISE corrupt;
END IF;
EXCEPTION
WHEN corrupt THEN
RAISE_APPLICATION_ERROR(-20000, ‘Corrupt block has been formatted’);
END;
/
When prompted for the block number, provide the block reported corrupt as input.
When prompted for the file number enter the relative fileno (rfile# value from v$datafile) for corrupt datafile.
Step 7- Allocate space to the table from the affected datafile
Notes
1) If this is an ASSM tablespace, you may need to repeat this step a few times. That is, create multiple tables and allocate multiple extents.
And periodically look at dba_extents to ensure that the free space is now allocated to a dummy table.
This is because ASSM will automatically determine the size of the next extent
2) It is advisable to ensure that AUTOEXTEND is OFF for the datafile, to prevent it from growing
Please note :- If your database is on 10.2.0.4/11.1.0.7 and tablespace in which dummy table is created is ASSM then you might hit the below bug while manually Allocating extent to the dummy table. Ensure for 10.2.0.4/11.1.0.7 database you have the below fix installed before Manually allocating extents.Ensure you have One off patch 6647480 applied for 10.2.0.4/11.1.0.7 database version.
Bug 6647480 – Corruption / OERI [kddummy_blkchk] .. [18021] with ASSM (Doc ID 6647480.8)
Firstly, find the extent size by querying dba_free_space
SQL> Select BYTES from dba_free_space where file_id=<file no> and <corrupt block no> between block_id and block_id + blocks -1;
BYTES
—————- ———- ———- ———- ———- ————
65536
In this case it’s 64K, so allocate the extent as follows:
SQL> alter table <username>.s
allocate extent (DATAFILE ‘E:\xxxx\<datafilename>.ORA’ SIZE 64K);
If there are multiple extents of 64K free in this datafile, you may need use this loop:
BEGIN
for i in 1..1000000 loop
EXECUTE IMMEDIATE ‘alter table <username>.s allocate extent (DATAFILE ‘||”’E:\xxxx\<datafilename>.ORA”’ ||’SIZE 64K) ‘;
end loop;
end ;
/
Keep allocating until the corrupted block is part of <username>.s. Use this query to confirm thus:
SQL> select segment_name, segment_type, owner
from dba_extents
where file_id = <Absolute file number>
and <corrupt block number> between block_id
and block_id + blocks -1 ;
Step 8 – Insert data into dummy table to format the block
Sample code (depending on the size of the tablespace it may vary):
BEGIN
FOR i IN 1..1000000000 LOOP
INSERT /*+ APPEND */ INTO <username>.s select i, lpad(‘REFORMAT’,3092, ‘R’) from dual;
commit ;
END LOOP;
END;
Or
BEGIN
FOR i IN 1..1000000000 LOOP
INSERT INTO <username>.s VALUES(i,’x’);
END LOOP;
END;
/
Or use the below code which includes 2 loops:
Begin
FOR i IN 1..1000000000 loop
for j IN 1..1000 loop
Insert into <username>.s VALUES(i,’x’);
end loop;
commit;
END LOOP;
END;
The trigger will be fired for every row inserted into the table and an exception with ORA-20000 will be produced as soon as it inserts the first row into the corrupt block.
Step 9 – Confirm that the block is now corruption free
Run dbverify or RMAN validate on the corrupt datafile (or entire database) again. It will not show the block as corrupted.
Ensure you do couple of manual logswitch or checkpoint for information in memory to be written to disk.
RMAN backup will not report any error on this block.
Before running the actual backup you can re-run Rman validate command on the datafile and check v$database_block_corruption doesnot show the block formatted as corrupted.
For Db version <=10gr2
Rman> Backup validate check logical datafile <fileno>,<fileno> ;
For Db version >= 11gr1
Rman> Backup validate check logical datafile <fileno> ;
Or
Rman> validate datafile <fileno> block <blockno reported corrupt>, <blockno reported corrupt> ;
Once done
SQL>Select * from v$database_block_corruption ;
Step 10 – Drop the dummy table created in step 4
SQL> DROP TABLE <username>.s ;
If 10gr1 and above drop table with purge option.
Step 11:- Do a Manual logswitch and checkpoint
Do couple of logswitch and checkpoint so that The block formatted in-memory are written into disk and dbverify no longer reports errors
SQL>Alter system switch logfile ; –> Do this couple of time
SQL>Alter system checkpoint ;
Step 12:- Drop trigger created in step 6
SQL> DROP trigger corrupt_trigger ;