In order to test the RMAN’s
BLOCKRECOVER command, we need to corrupt the specific data block and
recover it for testing purpose. To do it in Linux, use dd command. In the
following example, let’s create a table and corrupt it manually
1. For the
purpose of this practice, will create a separate tablespace and a new schema
user.
a. Create
a Tablespace say “test_corrupt”
[oracle@NVMBD1BZY150D00 ~]$ sqlplus / as
sysdba
SQL*Plus: Release 11.2.0.3.0 Production
on Fri Dec 19 18:09:36 2014
Copyright (c) 1982, 2011, Oracle. All rights reserved.
Connected to:
Oracle Database 11g Enterprise Edition
Release 11.2.0.3.0 - 64bit Production
With the Partitioning, OLAP, Data Mining
and Real Application Testing options
SQL> create tablespace test_corrupt
datafile '/data/oracle/app/oracle/oradata/TESTDB/test_corrupt.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 default tablespace test_corrupt
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)) tablespace test_corrupt;
Table created.
3. Insert some
dummy records into the table by writing a simple ‘for loop’ block as shown:
SQL> begin
for i in 1..10000loop
insert into emp values(i);
end loop;
end;
/
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
[oracle@NVMBD1BZY150D00 ~]$ rman target
/
Recovery Manager: Release 11.2.0.3.0 -
Production on Fri Dec 19 18:14:36 2014
Copyright (c) 1982, 2011, Oracle and/or
its affiliates. All rights reserved.
connected to target database: TESTDB
(DBID=2649358339)
Report the
schema to know about the target database
RMAN> report schema;
using target database control file
instead of recovery catalog
Report of database schema for database
with db_unique_name TESTDB
List of Permanent Datafiles
===========================
File Size(MB) Tablespace RB segs Datafile Name
---- -------- --------------------
------- ------------------------
1
100 SYSTEM *** /data/oracle/app/oracle/oradata/TESTDB/system.dbf
2
100 SYSTEM *** /data/oracle/app/oracle/oradata/TESTDB/user04.dbf
3
100 SYSAUX *** /data/oracle/app/oracle/oradata/TESTDB/sysaux.dbf
4
500 UNDOTBS *** /data/oracle/app/oracle/oradata/TESTDB/undo.dbf
5
1024 TEST *** /data/oracle/app/oracle/oradata/TESTDB/test1_tmp.dbf
6
10 TEST_CORRUPT ***
/data/oracle/app/oracle/oradata/TESTDB/test_corrupt.dbf
List of Temporary Files
=======================
File Size(MB) Tablespace Maxsize(MB) Tempfile Name
---- -------- --------------------
----------- --------------------
1
1000 TEMP 1000 /data/oracle/app/oracle/oradata/TESTDB/temp1.dbf
Take the
backup of the tablespace
RMAN> backup tablespace test_corrupt;
Starting backup at 19-DEC-14
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=190 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=00006
name=/data/oracle/app/oracle/oradata/TESTDB/tes
channel ORA_DISK_1: starting piece 1 at
19-DEC-14
channel ORA_DISK_1: finished piece 1 at
19-DEC-14
piece
handle=/data/oracle/app/oracle/product/11.2.0/dbhome_1/dbs/0cpqitp8_1_1 ta
channel ORA_DISK_1: backup set complete,
elapsed time: 00:00:01
Finished backup at 19-DEC-14
RMAN>
Recovery Manager complete.
5. Manually corrupting
datablock.
[oracle@NVMBD1BZY150D00
~]$ ssqlplus / as sysdba
SQL*Plus: Release 11.2.0.3.0 Production
on Fri Dec 19 18:16:14 2014
Copyright (c) 1982, 2011, Oracle. All rights reserved.
Connected to:
Oracle Database 11g Enterprise Edition
Release 11.2.0.3.0 - 64bit Production
With the Partitioning, OLAP, Data Mining
and Real Application Testing options
SQL> SELECT header_block FROM
dba_segments WHERE segment_name='EMP';
HEADER_BLOCK
------------
130
So the header of segment (table) is block 130, so if the
block 131,132,133,… get some noise it will eventually end up as a datafile with
corrupted blocks
[oracle@NVMBD1BZY150D00 ~]$ dd
of=/data/oracle/app/oracle/oradata/TESTDB/test_corrupt.dbf bs=8192 conv=notrunc
seek=131 << EOF
>
> testing corruption
> > EOF
>
> -bash: warning: here-document at
line 18 delimited by end-of-file (wanted `EOF')
0+1 records in
0+1 records out
29 bytes (29 B) copied, 3.1915e-05 s,
909 kB/s
6. To query the
data, connect to the “test” user and query the table “emp”
SQL> ALTER SYSTEM FLUSH BUFFER_CACHE;
System altered.
Connected.
SQL> select * from emp;
select * from emp
*
ERROR at line 1:
ORA-01578: ORACLE data block corrupted
(file # 6, block # 131)
ORA-01110: data file 6:
'/data/oracle/app/oracle/oradata/TESTDB/test_corrupt.dbf'
The query
returns complains of block corruption in file 6, and the block numbered 131 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.
7. Let us see
what are the blocks are corrupted in “test_corrupt01.dbf” datafile by running
dbv (DBVERIFY) utility.
[oracle@NVMBD1BZY150D00
~]$ dbv file=/data/oracle/app/oracle/oradata/TESTDB/test_corrupt.dbf
blocksize=8192
DBVERIFY: Release 11.2.0.3.0 -
Production on Fri Dec 19 18:19:10 2014
Copyright (c) 1982, 2011, Oracle and/or
its affiliates. All rights reserved.
DBVERIFY - Verification starting : FILE
= /data/oracle/app/oracle/oradata/TESTDB/test_corrupt.dbf
Page 131 is marked corrupt
Corrupt block relative dba: 0x01800083
(file 6, block 131)
Bad header found during dbv:
Data in bad block:
type: 32 format: 6 rdba: 0x69747365
last change scn: 0x726f.6320676e seq: 0x72
flg: 0x75
spare1: 0x20 spare2: 0x74 spare3: 0x6f69
consistency value in tail: 0x5b5c0601
check value in block header: 0x7470
computed block checksum: 0xeb9b
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 : 678748 (0.678748)
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.
8. 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.
[oracle@NVMBD1BZY150D00 ~]$ rman target
/
Recovery Manager: Release 11.2.0.3.0 -
Production on Fri Dec 19 18:22:41 2014
Copyright (c) 1982, 2011, Oracle and/or
its affiliates. All rights reserved.
connected to target database: TESTDB
(DBID=2649358339)
Report the Schema to know the status of target database, gathers the information from control file
RMAN> report schema;
using target database control file
instead of recovery catalog
Report of database schema for database
with db_unique_name TESTDB
List of Permanent Datafiles
===========================
File Size(MB) Tablespace RB segs Datafile Name
---- -------- --------------------
------- ------------------------
1
100 SYSTEM *** /data/oracle/app/oracle/oradata/TESTDB/system.dbf
2
100 SYSTEM *** /data/oracle/app/oracle/oradata/TESTDB/user04.dbf
3
100 SYSAUX *** /data/oracle/app/oracle/oradata/TESTDB/sysaux.dbf
4
500 UNDOTBS *** /data/oracle/app/oracle/oradata/TESTDB/undo.dbf
5
1024 TEST *** /data/oracle/app/oracle/oradata/TESTDB/test1_tmp.dbf
6
10 TEST_CORRUPT ***
/data/oracle/app/oracle/oradata/TESTDB/test_corrupt.dbf
List of Temporary Files
=======================
File Size(MB) Tablespace Maxsize(MB) Tempfile Name
---- -------- --------------------
----------- --------------------
1
1000 TEMP 1000 /data/oracle/app/oracle/oradata/TESTDB/temp1.dbf
9. Recover the
corrupted blocks using recover command
RMAN>
BLOCKRECOVER DATAFILE 6 BLOCK 131;
Starting recover at 19-DEC-14
using target database control file
instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=197 device
type=DISK
channel ORA_DISK_1: restoring block(s)
channel ORA_DISK_1: specifying block(s)
to restore from backup set
restoring blocks of datafile 00006
channel ORA_DISK_1: reading from backup
piece /data/oracle/app/oracle/product/11.2.0/dbhome_1/dbs/0cpqitp8_1_1
channel ORA_DISK_1: piece
handle=/data/oracle/app/oracle/product/11.2.0/dbhome_1/dbs/0cpqitp8_1_1
tag=TAG20141219T181504
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 19-DEC-14
RMAN>
Recovery Manager complete.
10. 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.
I hope this article helped you.
Your suggestions/feedback are most
welcome.
Keep learning... Have a great day!!!
Keep learning... Have a great day!!!
how can we corrupt a data block in windows operation system ?
ReplyDeletethanks
Its really very helpful article.
ReplyDeleteWe recommend the stellar jpeg repair software to repair corrupted or deleted JPEG files from your device quickly.