Thursday 20 February 2014

Manually Corrupting Oracle Data Block

Manually Corrupting Oracle Data Block

When we’re practicing the backup and recovery scenarios, we come-up with the block corruption recovery cases. So how to make the blocks to get corrupt? And how the recoveries can be done? And here is the solution for how to make the Oracle data blocks to get corrupted.
At the same time, this will also help us to recover the corrupted blocks from the production databases.

Before we begin:

This is only for the learning, practicing, and educational purpose, please do not try these methods on the production, testing, and/or development databases.
The way we corrupt the Oracle data blocks that allows the learners’ to practice the scenarios on backup and recoveries. That makes when the actual database block level corruption has occurred, we will be in a position to recover in the block level.
1. For the purpose of this practice, will create a separate tablespace and a new schema user.
a. Create a Tablespace say “test_corrupt”
SQL> create tablespace test_corrupt
2 datafile ‘/u01/app/oracle/oradata/orcl/test_corrupt01.dbf’ size 10m;
Tablespace created.
b. Create an user say “test” and assign quota to the “test_corrupt” tablespace
SQL> create user test identified by test123
2 default tablespace test_corrupt
3 quota unlimited on test_corrupt;
User created.
c. Grant the necessary privileges
SQL> grant create session, resource to test;
Grant succeeded.
2. Create a table as test user
SQL> conn test/test123
Connected.
SQL> create table emp(eno number(7))
2 tablespace test_corrupt;
Table created.
3. Insert some dummy records into the table by writing a simple ‘for loop’ block as shown:
SQL> begin
2 for i in 1..10000
3 loop
4 insert into emp values(i);
5 end loop;
6 end;
8 /
PL/SQL procedure successfully completed.
SQL> select count(*) from emp;
COUNT(*)
———-
10000
4. Take the RMAN backup, either full database or tablespace level backup before corrupting the block.
Connect to the RMAN
$ rman target / catalog scott/tiger@rc
Recovery Manager: Release 11.2.0.1.0 – Production on Mon Mar 28 16:00:39 2011
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
connected to target database: ORCL (DBID=1272957858)
connected to recovery catalog database
Report the schema to know about the target database
RMAN> report schema;
Report of database schema for database with db_unique_name ORCL
List of Permanent Datafiles
===========================
File Size(MB) Tablespace RB segs Datafile Name
—- ——– ——————– ——- ————————
1 690 SYSTEM YES /u01/app/oracle/oradata/orcl/system01.dbf
2 540 SYSAUX NO /u01/app/oracle/oradata/orcl/sysaux01.dbf
3 80 UNDOTBS1 YES /u01/app/oracle/oradata/orcl/undotbs01.dbf
4 10 TEST_CORRUPT NO /u01/app/oracle/oradata/orcl/test_corrupt01.dbf
6 20 DEF_PERM NO /u01/app/oracle/oradata/orcl/def_perm01.dbf
List of Temporary Files
=======================
File Size(MB) Tablespace Maxsize(MB) Tempfile Name
—- ——– ——————– ———– ——————–
1 33 TEMP 32767 /u01/app/oracle/oradata/orcl/temp01.dbf
Take the backup of the tablespace
RMAN> backup tablespace test_corrupt;
Starting backup at 28-MAR-11
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00004 name=/u01/app/oracle/oradata/orcl/test_corrupt01.dbf
channel ORA_DISK_1: starting piece 1 at 28-MAR-11
channel ORA_DISK_1: finished piece 1 at 28-MAR-11
piece handle=/backup/rman_backups/rman_ORCL_0um8c6ve tag=TAG20110328T161437 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 28-MAR-11
5. Take the tablespace offline so that we can make changes to the datafile.
SQL> conn / as sysdba
connected
SQL> alter tablespace test1 offline;
Tablespace altered.
6. To corrupt a datafile, there are many freeware editors available. Here we are using UltraEdit GUI editor (Available for both Windows and Linux Versions) to make changes in the datafile.
Download from the websites and install it. Once the installation has been completed, the files can be edited by using UltraEdit with the help of executable called uex
Open the datafile “/u01/app/oracle/oradata/orcl/test_corrupt01.dbf” using UltraEdit
$ uex /u01/app/oracle/oradata/orcl/test_corrupt01.dbf
The screen will look as like below:
Do not try to edit the file in the beginning, because those portion of the file will contain the datafile header information. Modifying the header file will corrupt the whole file itself.
So, scroll down to find out the blocks where the data is present, try to type some blunders in the space wherever the mouse pointer is blinking. Once the change has been completed, save the file.
7. After corrupting the blocks, bring back the tablespace to online
SQL> alter tablespace test online;
Tablespace altered.
You can notice that Oracle doesn’t through any errors when we brought tablespace online, because we had not modified the datafile header. If in case we had done, then that will through an errors while bringing back the tablespace to online. Oracle will through an error only when it tries to access the data from corrupted blocks.
8. To query the data, connect to the “test” user and query the table “emp”
SQL> conn test/test123
Connected
SQL> select * from emp;
ENO
———-
661
662
663
664
7903
7904
7905
ERROR:
ORA-01578: ORACLE data block corrupted (file # 4, block # 142)
ORA-01110: data file 4: ‘/u01/app/oracle/oradata/orcl/test_corrupt01.dbf’
4605 rows selected.
The query returns 4605 records and then complains of block corruption in file 4, and the block numbered 142 is being reported as corrupt.
This is the methods to be followed in order to corrupt the Oracle data blocks.
Lets us see, how to identify the corrupted blocks and recover them.
9. Let us see what are the blocks are corrupted in “test_corrupt01.dbf” datafile by running dbv utility.
$ which dbv
/u01/app/oracle/product/11.2.0/dbhome_1/bin/dbv
$ dbv file=/u01/app/oracle/oradata/orcl/test_corrupt01.dbf
DBVERIFY: Release 11.2.0.1.0 – Production on Mon Mar 28 15:51:01 2011
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
DBVERIFY – Verification starting : FILE = /u01/app/oracle/oradata/orcl/test_corrupt01.dbf
Page 142 is marked corrupt
Corrupt block relative dba: 0x0100008e (file 4, block 142)
Bad check value found during dbv:
Data in bad block:
type: 6 format: 2 rdba: 0x0100008e
last change scn: 0×0000.00134653 seq: 0×1 flg: 0×06
spare1: 0×0 spare2: 0×0 spare3: 0×0
consistency value in tail: 0×46530601
check value in block header: 0xe6bd
computed block checksum: 0xcc0a
DBVERIFY – Verification complete
Total Pages Examined : 1280
Total Pages Processed (Data) : 19
Total Pages Failing (Data) : 0
Total Pages Processed (Index): 0
Total Pages Failing (Index): 0
Total Pages Processed (Other): 131
Total Pages Processed (Seg) : 0
Total Pages Failing (Seg) : 0
Total Pages Empty : 1129
Total Pages Marked Corrupt : 1
Total Pages Influx : 0
Total Pages Encrypted : 0
Highest block SCN : 1263187 (0.1263187)
This utility scans all the blocks in a given datafile and outputs the corrupt blocks. In this case, there was only one block marked as corrupt. Make a note of all the corrupted blocks as we need to recover them to previous state.
10. Start RMAN session and recover all the corrupted blocks.
The beauty of RMAN is that it recovers only corrupted blocks and we need to recover only those corrupt blocks instead of entire datafile.
$ rman target / catalog scott/tiger@rc
Recovery Manager: Release 11.2.0.1.0 – Production on Mon Mar 28 16:00:39 2011
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
connected to target database: ORCL (DBID=1272957858)
connected to recovery catalog database
Report the Schema to know the status of target database, gathers the information from control file
RMAN> report schema;
Report of database schema for database with db_unique_name ORCL
List of Permanent Datafiles
===========================
File Size(MB) Tablespace RB segs Datafile Name
—- ——– ——————– ——- ————————
1 690 SYSTEM YES /u01/app/oracle/oradata/orcl/system01.dbf
2 540 SYSAUX NO /u01/app/oracle/oradata/orcl/sysaux01.dbf
3 80 UNDOTBS1 YES /u01/app/oracle/oradata/orcl/undotbs01.dbf
4 10 TEST_CORRUPT NO /u01/app/oracle/oradata/orcl/test_corrupt01.dbf
6 20 DEF_PERM NO /u01/app/oracle/oradata/orcl/def_perm01.dbf
List of Temporary Files
=======================
File Size(MB) Tablespace Maxsize(MB) Tempfile Name
—- ——– ——————– ———– ——————–
1 33 TEMP 32767 /u01/app/oracle/oradata/orcl/temp01.dbf
11. Recover the corrupted blocks using recover command
RMAN> recover datafile 4 block 142;
Starting recover at 28-MAR-11
starting full resync of recovery catalog
full resync complete
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 00004
channel ORA_DISK_1: reading from backup piece /backup/rman_backups/rman_ORCL_0vm8c862
channel ORA_DISK_1: piece handle=/backup/rman_backups/rman_ORCL_0vm8c862 tag=TAG20110328T163513
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:01
Finished recover at 28-MAR-11
RMAN reports success of block recovery command.
12. Will query the table again by logging in to the SQL*Plus:
SQL> conn test/test123
Connected.
SQL> select * from emp order by eno;
ENO
———-
1
2
3
9997
9998
9999
10000
10000 rows selected.
SQL> select count(*) from emp;
COUNT(*)
———-
10000
This will executes successfully and the records will be restored back to the table.

1 comment:

  1. You got a really useful blog I have been here reading for about an hour. I am a newbie and your success is very much an inspiration for me. Wireshark Training | Block Chain | F5 LTM Training

    ReplyDelete