阿里云-云小站(无限量代金券发放中)
【腾讯云】云服务器、云数据库、COS、CDN、短信等热卖云产品特惠抢购

Oracle数据块损坏的恢复实例

99次阅读
没有评论

共计 18615 个字符,预计需要花费 47 分钟才能阅读完成。

测试环境:11.2.0.4

  • 1. 构建数据块损坏的测试环境
  • 2. 有备份:常规恢复坏块
  • 3. 无备份:跳过坏块

1. 构建数据块损坏的测试环境

1.1 创建测试表

--Create Table t_test
conn jingyu/jingyu
drop table t_test purge;
create table t_test (id number, name char(2000));

--Insert data
insert into t_test values(1, 'alfred 1');
insert into t_test values(2, 'alfred 2');
insert into t_test values(3, 'alfred 3');
insert into t_test values(4, 'alfred 4');
insert into t_test values(5, 'alfred 5');
insert into t_test values(6, 'alfred 6');
insert into t_test values(7, 'alfred 7');
insert into t_test values(8, 'alfred 8');
insert into t_test values(9, 'alfred 9');
insert into t_test values(10, 'alfred 10');
commit;

--Create Index
create index idx_t_test_1 on t_test(id);

--Statistics
--analyze table t_test compute statistics;
EXEC DBMS_STATS.gather_table_stats('JINGYU', 'T_TEST', cascade => TRUE);

1.2 查询表中每一行对应的文件号和块号

-- 查询 t_test 表中每一行对应的文件和块号
select blocks from user_tables where table_name = 'T_TEST';

select dbms_rowid.rowid_relative_fno(rowid) R_FNO,
dbms_rowid.rowid_block_number(rowid) b_no, id
from t_test
order by 1,2;

-- 这里对象占用块数的查询前后不匹配, 与书中不符, 但不影响实验, 结果如下: 
SQL> select blocks from user_tables where table_name = 'T_TEST';

    BLOCKS
----------
         5

SQL> select dbms_rowid.rowid_relative_fno(rowid) R_FNO,
  2  dbms_rowid.rowid_block_number(rowid) b_no, id
  3  from t_test
  4  order by 1,2;

     R_FNO       B_NO         ID
---------- ---------- ----------
         6       3892          1
         6       3892          2
         6       3892          3
         6       3893          4
         6       3893          5
         6       3893          6
         6       3894          7
         6       3894          8
         6       3894          9
         6       3895         10

10 rows selected.

1.3 使用 bbed 工具模拟破坏 6 号数据文件的 3893 数据块

关于 bbed 的编译和使用可参考

  • 《Oracle 11g 编译使用 BBED》

1.3.1 准备 bbed 配置文件:
编辑 /tmp/bbed.par 参数配置文件

-- 编辑 /tmp/bbed.par 参数配置文件
blocksize=8192
listfile=/tmp/listfile.txt
mode=edit

-- 编辑 /tmp/listfile.txt 文件 
SQL> select file#||''||name||' '||bytes from v$datafile ;

FILE#||''||NAME||''||BYTES
--------------------------------------------------------------------------------
1 +DATA1/jyzhao/datafile/system.256.919998779 786432000
2 +DATA1/jyzhao/datafile/sysaux.257.919998781 891289600
3 +DATA1/jyzhao/datafile/undotbs1.258.919998783 125829120
4 +DATA1/jyzhao/datafile/users.259.919998789 13107200
5 +DATA1/jyzhao/datafile/undotbs2.264.919999419 78643200
6 +DATA1/jyzhao/datafile/dbs_d_jingyu.268.927427887 104857600
7 +DATA1/jyzhao/datafile/dbs_i_jingyu.270.927427891 31457280
8 +DATA1/jyzhao/datafile/soe.278.939295201 104857600
9 +DATA1/jyzhao/datafile/dbs_d_jingyu.277.939295229 104857600

由于 bbed 不能直接操作 ASM 里面的数据文件,所以需把对应的数据文件转储出来:

RMAN> backup as copy datafile 6 format '/opt/app/Oracle/datafile/dbs_d_jingyu01.dbf';
--mount 
RMAN> switch datafile 6 to copy;
RMAN> recover datafile 6;
RMAN> alter database open;

-- 编辑 /tmp/listfile.txt, 添加6 号文件信息
vi /tmp/listfile.txt
6 /opt/app/oracle/datafile/dbs_d_jingyu01.dbf 104857600

SQL> alter system checkpoint;

测试调用 bbed 正常:

-- 调用 bbed
cd /tmp
bbed parfile=bbed.par

1.3.2 破坏数据文件 6 的 3893 数据块

[oracle@jyrac1 tmp]$ bbed parfile=bbed.par
Password: 

BBED: Release 2.0.0.0.0 - Limited Production on Wed Mar 22 15:28:00 2017

Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.

************* !!! For Oracle Internal Use only !!! ***************

BBED> set dba 6,3893 
        DBA             0x01800f35 (25169717 6,3893)

BBED> find /c alfred
 File: /opt/app/oracle/datafile/dbs_d_jingyu01.dbf (6)
 Block: 3893             Offsets: 2170 to 2681           Dba:0x01800f35
------------------------------------------------------------------------
 616c6672 65642036 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 

 <32 bytes per line>

BBED> f
 File: /opt/app/oracle/datafile/dbs_d_jingyu01.dbf (6)
 Block: 3893             Offsets: 4179 to 4690           Dba:0x01800f35
------------------------------------------------------------------------
 616c6672 65642035 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 

 <32 bytes per line>

BBED> f
 File: /opt/app/oracle/datafile/dbs_d_jingyu01.dbf (6)
 Block: 3893             Offsets: 6188 to 6699           Dba:0x01800f35
------------------------------------------------------------------------
 616c6672 65642034 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 

 <32 bytes per line>

BBED> f
BBED-00212: search string not found


BBED> dump /v dba 6,3893 offset 2170 count 64
 File: /opt/app/oracle/datafile/dbs_d_jingyu01.dbf (6)
 Block: 3893    Offsets: 2170 to 2233  Dba:0x01800f35
-------------------------------------------------------
 616c6672 65642036 20202020 20202020 l alfred 6        
 20202020 20202020 20202020 20202020 l                 
 20202020 20202020 20202020 20202020 l                 
 20202020 20202020 20202020 20202020 l                 

 <16 bytes per line>

BBED> dump /v dba 6,3893 offset 4179 count 64
 File: /opt/app/oracle/datafile/dbs_d_jingyu01.dbf (6)
 Block: 3893    Offsets: 4179 to 4242  Dba:0x01800f35
-------------------------------------------------------
 616c6672 65642035 20202020 20202020 l alfred 5        
 20202020 20202020 20202020 20202020 l                 
 20202020 20202020 20202020 20202020 l                 
 20202020 20202020 20202020 20202020 l                 

 <16 bytes per line>

BBED> dump /v dba 6,3893 offset 6188 count 64
 File: /opt/app/oracle/datafile/dbs_d_jingyu01.dbf (6)
 Block: 3893    Offsets: 6188 to 6251  Dba:0x01800f35
-------------------------------------------------------
 616c6672 65642034 20202020 20202020 l alfred 4        
 20202020 20202020 20202020 20202020 l                 
 20202020 20202020 20202020 20202020 l                 
 20202020 20202020 20202020 20202020 l                 

 <16 bytes per line>

BBED> modify 901010 dba 6,3893
Warning: contents of previous BIFILE will be lost. Proceed? (Y/N) y
 File: /opt/app/oracle/datafile/dbs_d_jingyu01.dbf (6)
 Block: 3893             Offsets: 6188 to 6251           Dba:0x01800f35
------------------------------------------------------------------------
 0dbf9272 65642034 20202020 20202020 20202020 20202020 20202020 20202020 
 20202020 20202020 20202020 20202020 20202020 20202020 20202020 20202020 

 <32 bytes per line>

BBED> exit

1.3.3 使用 dbv 检查文件

[oracle@jyrac1 tmp]$ dbv file=/opt/app/oracle/datafile/dbs_d_jingyu01.dbf

DBVERIFY: Release 11.2.0.4.0 - Production on Wed Mar 22 15:31:50 2017

Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.

DBVERIFY - Verification starting : FILE = /opt/app/oracle/datafile/dbs_d_jingyu01.dbf
Page 3893 is marked corrupt
Corrupt block relative dba: 0x01800f35 (file 6, block 3893)
Bad check value found during dbv: 
Data in bad block:
 type: 6 format: 2 rdba: 0x01800f35
 last change scn: 0x0000.003b68be seq: 0x1 flg: 0x06
 spare1: 0x0 spare2: 0x0 spare3: 0x0
 consistency value in tail: 0x68be0601
 check value in block header: 0x6485
 computed block checksum: 0xd398



DBVERIFY - Verification complete

Total Pages Examined         : 12800
Total Pages Processed (Data) : 2512
Total Pages Failing   (Data) : 0
Total Pages Processed (Index): 989
Total Pages Failing   (Index): 0
Total Pages Processed (Other): 9025
Total Pages Processed (Seg)  : 0
Total Pages Failing   (Seg)  : 0
Total Pages Empty            : 273
Total Pages Marked Corrupt   : 1
Total Pages Influx           : 0
Total Pages Encrypted        : 0
Highest block SCN            : 3893454 (0.3893454)
[oracle@jyrac1 tmp]$ 

2. 有备份:常规恢复

数据库有有效的 RMAN 备份,那么很简单,直接恢复损害数据块即可。
RMAN> blockrecover datafile 6 block 3893;

常规恢复输出类似下面这样:

RMAN> blockrecover datafile 6 block 3893;

Starting recover at 22-MAR-17
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=148 instance=jyzhao1 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 +FRA1/jyzhao/backupset/2017_03_22/nnndf0_tag20170322t123922_0.463.939299963
channel ORA_DISK_1: piece handle=+FRA1/jyzhao/backupset/2017_03_22/nnndf0_tag20170322t123922_0.463.939299963 tag=TAG20170322T123922
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:04

Finished recover at 22-MAR-17

恢复完成后可以正常访问。

3. 无备份:跳过坏块

3.1 查看 AFN 和 RFN

绝对数据文件号:AFN 是数据文件在整个系统范围内的编号。
相对数据文件号:RFN 是数据文件在表空间范围内的编号。
两个文件可能有相同的 RFN,但是不会有相同的 AFN。

获取普通文件的 AFN 和 RFN:
select tablespace_name, file_id “AFN”, relative_fno “RFN” from dba_data_files;

SQL> select tablespace_name, file_id "AFN", relative_fno "RFN" from dba_data_files;

TABLESPACE_NAME                       AFN        RFN
------------------------------ ---------- ----------
USERS                                   4          4
UNDOTBS1                                3          3
SYSAUX                                  2          2
SYSTEM                                  1          1
UNDOTBS2                                5          5
DBS_D_JINGYU                            6          6
DBS_I_JINGYU                            7          7
SOE                                     8       1024
DBS_D_JINGYU                            9          9

9 rows selected.

注意:实验发现,大文件表空间的 RFN 固定为 1024。

获取临时文件的 AFN 和 RFN:
select tablespace_name, file_id + value “AFN”, relative_fno “RFN” from dba_temp_files, v$parameter where name = ‘db_files’;

SQL> select tablespace_name, file_id + value "AFN", relative_fno "RFN" from dba_temp_files, v$parameter where name = 'db_files';

TABLESPACE_NAME                       AFN        RFN
------------------------------ ---------- ----------
TEMP_JINGYU                           202          1
TEMP                                  201          1

3.2 创建 REPAIR_TABLE 和 ORPHAN_KEY_TABLE
REPAIR_TABLE 用来记录错误检查结果,ORPHAN_KEY_TABLE 用来记录表坏块中记录在索引中对应键值。

-- 通过如下存储过程创建 REPAIR_TABLE 和 ORPHAN_KEY_TABLE
--Repair Table
declare
begin
    dbms_repair.admin_tables(table_name => 'REPAIR_TABLE',
        table_type => dbms_repair.repair_table,
        action => dbms_repair.create_action,
        tablespace => 'USERS'
    );
end;
/

select owner, object_name, object_type from dba_objects where object_name like '%REPAIR_TABLE';

--Orphan Key Table
declare
begin
    dbms_repair.admin_tables(table_name => 'ORPHAN_KEY_TABLE',
        table_type => dbms_repair.orphan_table,
        action => dbms_repair.create_action,
        tablespace => 'USERS'
    );
end;
/

select owner, object_name, object_type from dba_objects where object_name like '%ORPHAN_KEY_TABLE';

-- 不再需要时,可以通过下面的存储过程删除 REPAIR_TABLE 和 ORPHAN_KEY_TABLE 这两个表:
--DROP REPAIR_TABLE
BEGIN
    DBMS_REPAIR.ADMIN_TABLES (TABLE_NAME => 'REPAIR_TABLE',
        TABLE_TYPE => dbms_repair.repair_table,
        ACTION => dbms_repair.drop_action);
END;
/

--DROP ORPHAN_KEY_TABLE
BEGIN
    DBMS_REPAIR.ADMIN_TABLES (TABLE_NAME => 'ORPHAN_KEY_TABLE',
        TABLE_TYPE => dbms_repair.orphan_table,
        ACTION => dbms_repair.drop_action);
END;
/

3.3 使用 CHECK_OBJECT 过程检测坏块

set serveroutput on
declare
    rpr_count int;
begin
    rpr_count := 0;
    dbms_repair.check_object(schema_name => 'JINGYU',
        object_name => 'T_TEST',
        repair_table_name => 'REPAIR_TABLE',
        corrupt_count => rpr_count
    );
    dbms_output.put_line('repair count:' || to_char(rpr_count));
end;
/

select object_name, block_id, corrupt_type, marked_corrupt, corrupt_description, repair_description from repair_table;

执行结果:

SQL> set serveroutput on
SQL> declare
  2     rpr_count int;
  3  begin
  4     rpr_count := 0;
  5     dbms_repair.check_object(6             schema_name => 'JINGYU',
  7             object_name => 'T_TEST',
  8             repair_table_name => 'REPAIR_TABLE',
  9             corrupt_count => rpr_count
 10     );
 11     dbms_output.put_line('repair count:' || to_char(rpr_count));
 12  end;
 13  /
repair count: 1

PL/SQL procedure successfully completed.

SQL> select object_name, block_id, corrupt_type, marked_corrupt, corrupt_description, repair_description from repair_table;

OBJECT_NAME                      BLOCK_ID CORRUPT_TYPE MARKED_COR
------------------------------ ---------- ------------ ----------
CORRUPT_DESCRIPTION
--------------------------------------------------------------------------------
REPAIR_DESCRIPTION
--------------------------------------------------------------------------------
T_TEST                               3893         6148 TRUE

mark block software corrupt

如果 marked_corrupt 不是 true,则需要使用 fix_corrupt_blocks 过程修复:

declare
    fix_count int;
begin
    fix_count := 0;
    dbms_repair.fix_corrupt_blocks(schema_name => 'JINGYU',
        object_name => 'T_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;
/

这里实验此步骤执行不执行都可以。

3.4 使用 DUMP_ORPHAN_KEYS 过程来保存坏块中的索引键值

select object_name, block_id, marked_corrupt from repair_table;

select index_name from dba_indexes where table_name in (select distinct object_name from repair_table);

SQL> select object_name, block_id, marked_corrupt from repair_table;

OBJECT_NAME                      BLOCK_ID MARKED_COR
------------------------------ ---------- ----------
T_TEST                               3893 TRUE

SQL> select index_name from dba_indexes where table_name in (select distinct object_name from repair_table);

INDEX_NAME
------------------------------
IDX_T_TEST_1

这时还存在着一个潜在的问题。
就是表有坏块,但索引没有损坏,通过表扫描会出现错误,但是通过索引扫描仍然可以返回结果,这会造成数据的不一致性。
比如,这里我知道 id = 4 的记录:

SQL> select * from jingyu.t_test where id = 4;
select * from jingyu.t_test where id = 4
                     *
ERROR at line 1:
ORA-01578: ORACLE data block corrupted (file # 6, block # 3893)
ORA-01110: data file 6: '/opt/app/oracle/datafile/dbs_d_jingyu01.dbf'


SQL> select id from jingyu.t_test where id = 4;

        ID
----------
         4

使用 DUMP_ORPHAN_KEYS 过程来保存坏块中的索引键值:

set serveroutput on
declare
    key_count int;
begin
    key_count := 0;
    dbms_repair.dump_orphan_keys(schema_name => 'JINGYU',
        object_name => 'IDX_T_TEST_1',
        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;
/

执行结果如下:

SQL> set serveroutput on
SQL> declare
  2     key_count int;
  3  begin
  4     key_count := 0;
  5     dbms_repair.dump_orphan_keys(6             schema_name => 'JINGYU',
  7             object_name => 'IDX_T_TEST_1',
  8             object_type => dbms_repair.index_object,
  9             repair_table_name => 'REPAIR_TABLE',
 10             orphan_table_name => 'ORPHAN_KEY_TABLE',
 11             key_count => key_count
 12     );
 13     dbms_output.put_line('orphan key count:' || to_char(key_count));
 14  end;
 15  /
orphan key count: 3

PL/SQL procedure successfully completed.

这样当之后执行完 SKIP_CORRUPT_BLOCKS 操作后,就可以重新建立索引了(对每个索引都要执行 DUMP_ORPHAN_KEYS 过程)。

3.5 使用 skip_corrupt_blocks 过程来跳过坏块
执行 skip_corrupt_blocks 过程,使后续 DML 操作跳过坏块:

begin
    dbms_repair.skip_corrupt_blocks (schema_name => 'JINGYU',
        object_name => 'T_TEST',
        object_type => dbms_repair.table_object,
        flags => dbms_repair.skip_flag
    );
end;
/

执行结果:

SQL> select count(1) from jingyu.t_test;
select count(1) from jingyu.t_test
                            *
ERROR at line 1:
ORA-01578: ORACLE data block corrupted (file # 6, block # 3893)
ORA-01110: data file 6: '/opt/app/oracle/datafile/dbs_d_Jingyu01.dbf'


SQL> begin
  2     dbms_repair.skip_corrupt_blocks (3             schema_name => 'JINGYU',
  4             object_name => 'T_TEST',
  5             object_type => dbms_repair.table_object,
  6             flags => dbms_repair.skip_flag
  7     );
  8  end;
  9  /

PL/SQL procedure successfully completed.

SQL>  select count(1) from jingyu.t_test;

  COUNT(1)
----------
         7

3.6 重建 freelist
如果不想使用 CTAS 方式重建表而仍是在原表上修复,则需要重建对象的 Freelist,防止这个数据块以后被加到 freelist 中。使用下面的方法:

declare
begin
    dbms_repair.rebuild_freelists (schema_name => 'JINGYU',
        object_name => 'T_TEST',
        object_type => dbms_repair.table_object
    );
end;
/

这里实际已知坏块不在 freelist 中,所以不需要执行,执行会报错如下错误:

SQL> declare
  2  begin
  3     dbms_repair.rebuild_freelists (4             schema_name => 'JINGYU',
  5             object_name => 'T_TEST',
  6             object_type => dbms_repair.table_object
  7     );
  8  end;
  9  /
declare
*
ERROR at line 1:
ORA-10614: Operation not allowed on this segment
ORA-06512: at "SYS.DBMS_REPAIR", line 401
ORA-06512: at line 3

3.7 重建索引
目前索引和数据块仍然存在不一致,必须要重建索引:

-- 以 id=4为例,索引和数据块依然存在不一致:SQL> select * from jingyu.t_test where id = 4;

no rows selected

SQL> select id from jingyu.t_test where id = 4;

        ID
----------
         4

-- 重建索引,不能采用 rebuild,只能 drop 后再 create。因为 rebuild 数据源来自索引:-- 测试 rebuild 发现的确还存在不一致:SQL> alter index jingyu.idx_t_test_1 rebuild;

Index altered.

SQL> select id from jingyu.t_test where id = 4;

        ID
----------
         4

-- 先 drop 再 create index,确认一致:SQL> drop index jingyu.idx_t_test_1;

Index dropped.

SQL> create index jingyu.idx_t_test_1 on jingyu.t_test(id);

Index created.

SQL> select id from jingyu.t_test where id = 4;

no rows selected

当然,如果此时使用 dbv 检查数据文件,依然是有坏块的,上面所有操作只是跳过坏块,并没有解决。

[oracle@jyrac1 ~]$ dbv file=/opt/app/oracle/datafile/dbs_d_jingyu01.dbf

DBVERIFY: Release 11.2.0.4.0 - Production on Wed Mar 22 17:29:42 2017

Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.

DBVERIFY - Verification starting : FILE = /opt/app/oracle/datafile/dbs_d_jingyu01.dbf
Page 3893 is marked corrupt
Corrupt block relative dba: 0x01800f35 (file 6, block 3893)
Bad check value found during dbv: 
Data in bad block:
 type: 6 format: 2 rdba: 0x01800f35
 last change scn: 0x0000.003b68be seq: 0x1 flg: 0x06
 spare1: 0x0 spare2: 0x0 spare3: 0x0
 consistency value in tail: 0x68be0601
 check value in block header: 0x6485
 computed block checksum: 0xd398



DBVERIFY - Verification complete

Total Pages Examined         : 12800
Total Pages Processed (Data) : 2512
Total Pages Failing   (Data) : 0
Total Pages Processed (Index): 989
Total Pages Failing   (Index): 0
Total Pages Processed (Other): 9025
Total Pages Processed (Seg)  : 0
Total Pages Failing   (Seg)  : 0
Total Pages Empty            : 273
Total Pages Marked Corrupt   : 1
Total Pages Influx           : 0
Total Pages Encrypted        : 0
Highest block SCN            : 3907507 (0.3907507)

善后工作(与数据块恢复无关):
养成一个习惯,做任何实验,如果对实验环境改动较大,建议实验完毕后,尽量恢复到正常状态,避免今后测试其他案例时现修复环境。
我这里就是把实验环境恢复(6 号文件恢复为原来的 ASM 存储上):

RMAN> list copy  of datafile 6;

using target database control file instead of recovery catalog
List of Datafile Copies
=======================

Key     File S Completion Time Ckp SCN    Ckp Time       
------- ---- - --------------- ---------- ---------------
18      6    A 22-MAR-17       3895505    22-MAR-17      
        Name: +DATA1/jyzhao/datafile/dbs_d_jingyu.268.939306177
        Tag: TAG20170322T142256

16      6    A 22-MAR-17       3817798    22-MAR-17      
        Name: /opt/app/oracle/datafile/dbs_d_Jingyu01.dbf

14      6    A 22-MAR-17       3817798    22-MAR-17      
        Name: +FRA1/jyzhao/datafile/dbs_d_jingyu.368.939306031
        Tag: TAG20170322T142027


RMAN> switch datafile 6 to copy;

datafile 6 switched to datafile copy "+DATA1/jyzhao/datafile/dbs_d_jingyu.268.939306177"

RMAN> recover datafile 6;

Starting recover at 22-MAR-17
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=143 instance=jyzhao1 device type=DISK

starting media recovery
media recovery complete, elapsed time: 00:00:01

Finished recover at 22-MAR-17

RMAN> alter database open;

database opened

至此,已完成数据块恢复实例的整个实验。

此外,针对坏块问题,还有一种方式是设置 10231 event,具体可参考:

  • 《Oracle 数据块损坏篇之 10231 内部事件》

更多 Oracle 相关信息见Oracle 专题页面 http://www.linuxidc.com/topicnews.aspx?tid=12

本文永久更新链接地址:http://www.linuxidc.com/Linux/2017-04/143143.htm

正文完
星哥说事-微信公众号
post-qrcode
 0
星锅
版权声明:本站原创文章,由 星锅 于2022-01-22发表,共计18615字。
转载说明:除特殊说明外本站文章皆由CC-4.0协议发布,转载请注明出处。
【腾讯云】推广者专属福利,新客户无门槛领取总价值高达2860元代金券,每种代金券限量500张,先到先得。
阿里云-最新活动爆款每日限量供应
评论(没有评论)
验证码
【腾讯云】云服务器、云数据库、COS、CDN、短信等云产品特惠热卖中