模拟数据块坏块:
对于发生数据块不一致的数据块,如果当前数据库有备份且处于归档模式,那么就可以利用rman工具数据块恢复功能 对数据块进行恢复,这种方法最简单有效,而且可以在数据文件在线时进行,不会发生数据丢失。对于被有备份的数据库 发生数据块损坏,可能会发生数据的丢失或数据不丢失,这要根据发生坏块的所在的对象决定的,如索引块发生损坏,数据 就不会丢失,重建索引就可以了,发生数据丢失的多发生在表或分区表数据块上。
1.不丢数据的恢复方法
---使用rman工具的 blockrecover blockrecover datafile xx block xx;--修复单个坏块
blockrecover corruption list;--修复全部坏块 SQL> select * from livan.test;
select * from livan.test
*
ERROR at line :
ORA-: ORACLE data block corrupted (file # , block # )
ORA-: data file : '/u02/app/oradata/PSDB/livan_tbs01.dbf'
[oracle@std u02]$ rman target / Recovery Manager: Release 10.2.0.4. - Production on Thu Feb :: Copyright (c) , , Oracle. All rights reserved. connected to target database: PSDB (DBID=) RMAN> blockrecover datafile block ; Starting blockrecover at -FEB-
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid= devtype=DISK channel ORA_DISK_1: restoring block(s)
channel ORA_DISK_1: specifying block(s) to restore from backup set
restoring blocks of datafile
channel ORA_DISK_1: reading from backup piece /u02/PSDB_BACKUP/full_PSDB_870868610
channel ORA_DISK_1: restored block(s) from backup piece
piece handle=/u02/PSDB_BACKUP/full_PSDB_870868610 tag=TAG20150205T115650
channel ORA_DISK_1: block restore complete, elapsed time: :: starting media recovery
media recovery complete, elapsed time: :: Finished blockrecover at -FEB-
[oracle@std u02]$ sqlplus '/as sysdba' SQL*Plus: Release 10.2.0.4. - Production on Thu Feb :: Copyright (c) , , Oracle. All Rights Reserved. Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.4. - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options SQL> select * from livan.test; ID NAME
---------- ------------------------------
beijing
shanghai
shandong
如果坏块上的表最近都没有更新,还可以利用bbed的copy命令来从一个最近的备份中copy过来一个数据块恢复,具体不演示。
2.有可能存在数据丢失的恢复(在没有备份没有归档的情况下)
---用户表数据损坏
<1>正常情况下数据条目数
SQL> select count(*) from test; COUNT(*)
----------
<2>制作一个坏块
select rowid,
dbms_rowid.rowid_relative_fno(rowid) rel_fno,
dbms_rowid.rowid_block_number(rowid) blockno,
dbms_rowid.rowid_row_number(rowid) rowno
from livan.test; BBED> set dba ,
DBA 0x0180004c ( ,) BBED> d /v dba , offset
File: /u02/app/oradata/PSDB/livan_tbs01.dbf ()
Block: Offsets: to Dba:0x0180004c
-------------------------------------------------------
06a20000 4c008001 d3220800 l .?.L...?......
b8510000 ddce0000 b4220800 l 窺......菸..?..
ffff0000 l .......A.......
l ................
b4220800 l ?..............
l ................
l ................
l ................ < bytes per line> BBED> modify /x dba , offset
File: /u02/app/oradata/PSDB/livan_tbs01.dbf ()
Block: Offsets: to Dba:0x0180004c
------------------------------------------------------------------------
4c008001 d3220800 b8510000 ddce0000 b4220800
ffff0000
b4220800 < bytes per line> BBED> sum play
BBED-: invalid parameter (play) BBED> sum apply
Check value for File , Block :
current = 0xd0fa, required = 0xd0fa SQL> alter system flush buffer_cache; System altered. SQL> select count(*) from test;
select count(*) from test
*
ERROR at line :
ORA-: ORACLE data block corrupted (file # , block # )
ORA-: data file : '/u02/app/oradata/PSDB/livan_tbs01.dbf'
发现我们第6个文件第76号数据块损坏,报ORA-0178错误,我们知掉只要数据库报ORA-01578错误,
说明该数据块已经被标识为:"software corrupt"
<3>确认坏块的类型
SQL> select segment_name,partition_name,segment_type,owner,tablespace_name
from sys.dba_extents
where file_id=&AFN
and &bad_block_id between block_id and block_id + blocks-;
Enter value for afn:
old : where file_id=&AFN
new : where file_id=
Enter value for bad_block_id:
old : and &bad_block_id between block_id and block_id + blocks-
new : and between block_id and block_id + blocks- SEGMENT_NAME PARTITION_NAME SEGMENT_TYPE OWNER TABLESPACE_NAME
--------------- -------------------- ------------------ ---------- ------------------------------
TEST TABLE LIVAN LIVAN_TBS
经查我们的数据损坏坏位于我们的用户表上,无备份数据会丢失。
<4>标记坏块为"software corrupt"
在第2步的时候全表扫描时已经报ORA-01578错误,说明该数据块已经被标识为:"software corrupt", 正常情况下可以跳过这步。 我们使用dbms_repair包演示标记坏块为"software corrupt"
使用dbms_repair包可参考:http://blog.itpub.net/8494287/viewspace-1357457/
--利用dbms_repair包必须先创建repair table两个表:
SQL> begin
dbms_repair.admin_tables(
table_name=>'REPAIR_TABLE',
table_type=>dbms_repair.repair_table,
action=>dbms_repair.create_action,
tablespace=>'LIVAN_TBS');
end;
/ PL/SQL procedure successfully completed. SQL> col object_name for a20
SQL> select owner,object_name,object_type
from dba_objects
where object_name like '%REPAIR_TABLE%'; OWNER OBJECT_NAME OBJECT_TYPE
------------------------------ -------------------- -------------------
SYS REPAIR_TABLE TABLE
SYS DBA_REPAIR_TABLE VIEW
--再创建orphan key table
SQL> begin
dbms_repair.admin_tables(
table_type=>dbms_repair.orphan_table,
action=>dbms_repair.create_action,
tablespace=>'LIVAN_TBS');
end;
/ PL/SQL procedure successfully completed. SQL> select owner,object_name,object_type
from dba_objects
where object_name like '%ORPHAN_KEY_TABLE%'; OWNER OBJECT_NAME OBJECT_TYPE
------------------------------ -------------------- -------------------
SYS ORPHAN_KEY_TABLE TABLE
SYS DBA_ORPHAN_KEY_TABLE VIEW
--检查对象,检查结果会放到我们之前创建的repair_table中
SQL> set serveroutput on
SQL> declare
rpr_count int;
begin
rpr_count:=;
dbms_repair.check_object(
schema_name=>'LIVAN',
object_name=>'TEST',
repair_table_name=>'REPAIR_TABLE',
corrupt_count=>rpr_count);
dbms_output.put_line('repair count:'||to_char(rpr_count));
end;
/
repair count: PL/SQL procedure successfully completed.
检查出有1个坏块
--检查校验的坏块结果
SQL> select object_name,block_id,corrupt_type,marked_corrupt,
corrupt_description,repair_description
from repair_table; OBJECT_NAM BLOCK_ID CORRUPT_TYPE MARKED_COR CORRUPT_DESCRIP REPAIR_DESCRIPTION
---------- ---------- ------------ ---------- --------------- ------------------------------
TEST TRUE mark block software corrupt
我们知道当marked_corrupt为TRUE时,标识这个数据块已经被标识过software corrupt
---标识坏块为software corrupt(重新演示一下)
SQL> declare
fix_count int;
begin
fix_count:=;
dbms_repair.fix_corrupt_blocks(
schema_name=>'LIVAN',
object_name=>'TEST',
object_type=>dbms_repair.table_object,
repair_table_name=>'REPAIR_TABLE',
fix_count=>fix_count);
dbms_output.put_line('fix count:'||to_char(fix_count));
end;
/
fix count: PL/SQL procedure successfully completed.
--再次检查,因为已经被标志为software corrupt,所以在此标志也没什么变化
SQL> select object_name,block_id,corrupt_type,marked_corrupt,
corrupt_description,repair_description
from repair_table; OBJECT_NAM BLOCK_ID CORRUPT_TYPE MARKED_COR CORRUPT_DESCRIP REPAIR_DESCRIPTION
---------- ---------- ------------ ---------- --------------- ------------------------------
TEST TRUE mark block software corrupt
未被标志为oftware corrupt ,marked_corrupt列会显示FALSE
<5>检查其他关联对象
检查有多少个索引项指向了坏块的记录
SQL> select index_name from dba_indexes
where table_name in (select distinct object_name from repair_table); INDEX_NAME
------------------------------
INDEX_TEST
查询发现有一个索引指向这个坏块
--检查都有多少索引数据
SQL> set serveroutput on
SQL> declare
key_count int;
begin
key_count:=;
dbms_repair.dump_orphan_keys(
schema_name=>'LIVAN',
object_name=>'INDEX_TEST',
object_type=>dbms_repair.index_object,
repair_table_name=>'REPAIR_TABLE',
orphan_table_name=>'ORPHAN_KEY_TABLE',
key_count=>key_count);
dbms_output.put_line('orphan key count:'||to_char(key_count));
end;
/
orphan key count: PL/SQL procedure successfully completed. SQL> select index_name,count(*) from orphan_key_table
group by index_name; INDEX_NAME COUNT(*)
------------------------------ ----------
INDEX_TEST
可以看到有146条数据指向坏块
<6>使用dbms_repair.skip_corrupt_blocks或10231事件方式跳过坏块
SQL> select count(*) from livan.test;
select count(*) from livan.test
*
ERROR at line :
ORA-: ORACLE data block corrupted (file # , block # )
ORA-: data file : '/u02/app/oradata/PSDB/livan_tbs01.dbf' SQL> begin
dbms_repair.skip_corrupt_blocks(
schema_name=>'LIVAN',
object_name=>'TEST',
object_type=>dbms_repair.table_object,
flags=>dbms_repair.skip_flag);
end;
/ PL/SQL procedure successfully completed. SQL> select count(*) from livan.test; COUNT(*)
----------
可以看到当执行完dbms_repair.skip_corrupt_blocks数据可以正常访问了,只是统计出来的数据比原先
少了146条(50604-50458),也就是我们坏块上的数据没有统计,被跳过了。
---使用10231事件跳过
SQL> select count(*) from livan.test; COUNT(*)
---------- SQL> begin
dbms_repair.skip_corrupt_blocks(
schema_name=>'LIVAN',
object_name=>'TEST',
object_type=>dbms_repair.table_object,
flags=>dbms_repair.noskip_flag);
end;
/ PL/SQL procedure successfully completed. SQL> select count(*) from livan.test;
select count(*) from livan.test
*
ERROR at line :
ORA-: ORACLE data block corrupted (file # , block # )
ORA-: data file : '/u02/app/oradata/PSDB/livan_tbs01.dbf' SQL> alter session set events '10231 trace name context forever,level 10'; Session altered. SQL> select count(*) from livan.test; COUNT(*)
---------- SQL> alter session set events '10231 trace name context off'; Session altered.
<7>使用CTAS方式重建表及索引
SQL> create table test_bak as select * from test; Table created. SQL> create index idx_test_bak on test_bak(object_id); Index created. --重建索引语句
SQL> alter index index_test rebuild online; Index altered.
<8>使用重建对象的freelists方式修复原表
使用这种方式防止坏块以后被加入到freelists中 注意这个方法只适用于段空间手动管理的表空间(SEGMENT SPACE MANAGEMENT MANUAL), 否则会报ORA-10614: Operation not allowed on this segment 错误
SQL> begin
dbms_repair.rebuild_freelists(
schema_name=>'LIVAN',
object_name=>'TEST',
object_type=>dbms_repair.table_object);
end;
/
begin
*
ERROR at line :
ORA-: Operation not allowed on this segment
ORA-: at "SYS.DBMS_REPAIR", line
ORA-: at line
<9>坏块中的数据
如果坏块中的数据不可丢失,只能尝试其他方法从恢复坏块内容,这其中也有一些第三方付费工具可使用, 也可进行以下尝试:
*尝试从索引内容中恢复出索引列的内容
*尝试使用logminer,从日志中挖掘
*联系Oracle Support,会有些工具解释数据块中的内容。