Chinaunix首页 | 论坛 | 博客
  • 博客访问: 3385915
  • 博文数量: 631
  • 博客积分: 10716
  • 博客等级: 上将
  • 技术积分: 8397
  • 用 户 组: 普通用户
  • 注册时间: 2008-04-01 22:35
文章分类

全部博文(631)

文章存档

2020年(2)

2019年(22)

2018年(4)

2017年(37)

2016年(22)

2015年(1)

2013年(12)

2012年(20)

2011年(19)

2010年(20)

2009年(282)

2008年(190)

分类: Oracle

2019-02-13 11:40:44

-//前几天看链接 
--//提到几种方式不影响数据的恢复,突然看到reuse storage选项,感觉在truncate时使用该参数时存储空间不会回收, 
--//感觉这样应该还是会降低高水位标志.

--//使用reuse storage选项,存储空间不会回收,另外在truncate时,数据段号data_object_id会发生变化,自己想想是否 
--//可以通过修改相应数据库的段号指向新的段号来实现恢复.自己动手测试看看.

1.环境: 
SCOTT@book> @ ver1 
PORT_STRING                    VERSION        BANNER 
------------------------------ -------------- -------------------------------------------------------------------------------- 
x86_64/Linux 2.4.xx            11.2.0.4.0     Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production

create table empx as select * from emp;

SCOTT@book> select rowid,empx.* from empx where rownum=1; 
ROWID                   EMPNO ENAME      JOB              MGR HIREDATE                   SAL       COMM     DEPTNO 
------------------ ---------- ---------- --------- ---------- ------------------- ---------- ---------- ---------- 
AAAWFOAAEAAAALbAAA       7369 SMITH      CLERK           7902 1980-12-17 00:00:00        800                    20

SCOTT@book> @ rowid AAAWFOAAEAAAALbAAA 
    OBJECT       FILE      BLOCK        ROW ROWID_DBA            DBA                  TEXT 
---------- ---------- ---------- ---------- -------------------- -------------------- ---------------------------------------- 
     90446          4        731          0  0x10002DB           4,731                alter system dump datafile 4 block 731 ;

SCOTT@book> select object_id,data_object_id from dba_objects where owner=user and object_name='EMPX'; 
OBJECT_ID DATA_OBJECT_ID 
---------- -------------- 
     90446          90446

SCOTT@book> column PARTITION_NAME noprint 
SCOTT@book> select * from dba_extents where owner=user and segment_name='EMPX'; 
OWNER  SEGMENT_NAME         SEGMENT_TYPE       TABLESPACE_NAME                 EXTENT_ID    FILE_ID   BLOCK_ID      BYTES     BLOCKS RELATIVE_FNO 
------ -------------------- ------------------ ------------------------------ ---------- ---------- ---------- ---------- ---------- ------------ 
SCOTT  EMPX                 TABLE              USERS                                   0          4        728      65536          8            4

SCOTT@book> truncate table empx reuse storage; 
Table truncated.

SCOTT@book> select object_id,data_object_id from dba_objects where owner=user and object_name='EMPX'; 
OBJECT_ID DATA_OBJECT_ID 
---------- -------------- 
     90446          90447

--//可以发现truncate后data_object_id=90447发生变化.

SCOTT@book> select * from dba_extents where owner=user and segment_name='EMPX'; 
OWNER  SEGMENT_NAME         SEGMENT_TYPE       TABLESPACE_NAME                 EXTENT_ID    FILE_ID   BLOCK_ID      BYTES     BLOCKS RELATIVE_FNO 
------ -------------------- ------------------ ------------------------------ ---------- ---------- ---------- ---------- ---------- ------------ 
SCOTT  EMPX                 TABLE              USERS                                   0          4        728      65536          8            4

SCOTT@book> alter system checkpoint; 
System altered.

2.看看是否通过修改相应块的段号:

BBED> set dba 4,728 
        DBA             0x010002d8 (16777944 4,728)

BBED> p /d ktbbh.ktbbhsid. 
union ktbbhsid, 4 bytes                     @24 
   ub4 ktbbhsg1                             @24       90446 
   ub4 ktbbhod1                             @24       90446 
--//可以发现truncate后数据段ID还是原来的90446,如果有数据插入段号就发生变化.我想通过修改段号实现数据恢复.

BBED> assign dba 4,731 ktbbh.ktbbhsid.ktbbhod1=90447; 
Warning: contents of previous BIFILE will be lost. Proceed? (Y/N) y 
ub4 ktbbhod1                                @24       0x0001614f

BBED> sum apply dba 4,731 
Check value for File 4, Block 731: 
current = 0x9cc2, required = 0x9cc2

3.检查是否能正常显示: 
SCOTT@book> alter system flush buffer_cache; 
System altered.

SCOTT@book> select rowid,empx.* from empx ; 
no rows selected

--//不行!!看看直接使用rowid是否可以查询. 
SCOTT@book> select rowid,empx.* from empx where rowid=dbms_rowid.rowid_create (1, 90447, 4, 731, 0) ; 
ROWID                   EMPNO ENAME      JOB              MGR HIREDATE                   SAL       COMM     DEPTNO 
------------------ ---------- ---------- --------- ---------- ------------------- ---------- ---------- ---------- 
AAAWFPAAEAAAALbAAA       7369 SMITH      CLERK           7902 1980-12-17 00:00:00        800                    20

--//可以发现使用rowid可以查询对应记录.如果写成如下: 
SCOTT@book> select rowid,empx.* from empx where rowid between dbms_rowid.rowid_create (1, 90447, 4, 731, 0) and dbms_rowid.rowid_create (1, 90447, 4, 731, 1); 
no rows selected

--//因为执行计划是这样: 
Plan hash value: 4633905 
------------------------------------------------------------------------------------- 
| Id  | Operation                   | Name | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | 
------------------------------------------------------------------------------------- 
|   0 | SELECT STATEMENT            |      |        |       |     2 (100)|          | 
|*  1 |  TABLE ACCESS BY ROWID RANGE| EMPX |      1 |    99 |     2   (0)| 00:00:01 | 
------------------------------------------------------------------------------------- 
Query Block Name / Object Alias (identified by operation id): 
------------------------------------------------------------- 
   1 - SEL$1 / EMPX@SEL$1 
Predicate Information (identified by operation id): 
--------------------------------------------------- 
   1 - access(ROWID>=CHARTOROWID("DBMS_ROWID"."ROWID_CREATE"(1,90447,4,731,0) 
              ) AND ROWID<=CHARTOROWID("DBMS_ROWID"."ROWID_CREATE"(1,90447,4,731,1))) 
--//执行计划TABLE ACCESS BY ROWID RANGE,注意范围这个关键字.这样要访问段头,因为是truncate表后降低了高水位标识, 
--//这样oracle认为要访问的数据块在高水位之上,这样就没有结果集. 
--//而前面的执行计划是TABLE ACCESS BY USER ROWID.直接通过rowid访问块.越过了数据段头的访问. 
SCOTT@book> @ &r/dpc '' '' 
PLAN_TABLE_OUTPUT 
------------------------------------- 
SQL_ID  3vzm2qyuft1dh, child number 0 
------------------------------------- 
select rowid,empx.* from empx where rowid=dbms_rowid.rowid_create (1, 90447, 4, 731, 0) 
Plan hash value: 3191763077 
------------------------------------------------------------------------------------ 
| Id  | Operation                  | Name | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | 
------------------------------------------------------------------------------------ 
|   0 | SELECT STATEMENT           |      |        |       |     1 (100)|          | 
|   1 |  TABLE ACCESS BY USER ROWID| EMPX |      1 |    99 |     1   (0)| 00:00:01 | 
------------------------------------------------------------------------------------ 
Query Block Name / Object Alias (identified by operation id): 
------------------------------------------------------------- 
   1 - SEL$1 / EMPX@SEL$1

3.有了以上思路,应该可以恢复全部记录. 
--//实际上就是当段头损坏.

SCOTT@book> CREATE TABLE empy tablespace tea  AS SELECT * FROM empx where  1=0; 
Table created.

--//网上找到的脚本,参考链接: 
set serveroutput on 
set concat off 
DECLARE 
nrows number; 
rid rowid; 
dobj number; 
ROWSPERBLOCK number; 
BEGIN 
ROWSPERBLOCK:=736;  --估算最大的一个块中记录条数,8K最多736条记录1块. 
nrows:=0;

select data_object_id  into dobj 
from dba_objects 
where owner = 'SCOTT' 
and object_name = 'EMPX' 
-- and subobject_name = '

'  Add this condition if table is partitioned 
;

for i in (select relative_fno, block_id, block_id+blocks-1 totblocks 
           from dba_extents 
           where owner = 'SCOTT' 
             and segment_name = 'EMPX' 
-- and partition_name = '

' Add this condition if table is partitioned 
-- and file_id != This condition is only used if a datafile needs to be skipped due to ORA-376 (A) 
          order by extent_id) 
loop 
   for br in i.block_id..i.totblocks loop 
    for j in 1..ROWSPERBLOCK loop 
    begin 
      rid := dbms_rowid.ROWID_CREATE(1,dobj,i.relative_fno, br , j-1); 
      insert into empy 
      select /*+ ROWID(A) */ * 
      from empx A 
      where rowid = rid; 
      if sql%rowcount = 1 then nrows:=nrows+1; end if; 
      if (mod(nrows,10000)=0) then commit; end if; 
    exception when others then null; 
    end; 
    end loop; 
  end loop; 
end loop; 
COMMIT; 
dbms_output.put_line('Total rows:'||to_char(nrows)); 
END; 
/

--//执行后: 
SCOTT@book> select * from empy; 
     EMPNO ENAME      JOB              MGR HIREDATE                   SAL       COMM     DEPTNO 
---------- ---------- --------- ---------- ------------------- ---------- ---------- ---------- 
      7369 SMITH      CLERK           7902 1980-12-17 00:00:00        800                    20 
      7499 ALLEN      SALESMAN        7698 1981-02-20 00:00:00       1600        300         30 
      7521 WARD       SALESMAN        7698 1981-02-22 00:00:00       1250        500         30 
      7566 JONES      MANAGER         7839 1981-04-02 00:00:00       2975                    20 
      7654 MARTIN     SALESMAN        7698 1981-09-28 00:00:00       1250       1400         30 
      7698 BLAKE      MANAGER         7839 1981-05-01 00:00:00       2850                    30 
      7782 CLARK      MANAGER         7839 1981-06-09 00:00:00       2450                    10 
      7788 SCOTT      ANALYST         7566 1987-04-19 00:00:00       3000                    20 
      7839 KING       PRESIDENT            1981-11-17 00:00:00       5000                    10 
      7844 TURNER     SALESMAN        7698 1981-09-08 00:00:00       1500          0         30 
      7876 ADAMS      CLERK           7788 1987-05-23 00:00:00       1100                    20 
      7900 JAMES      CLERK           7698 1981-12-03 00:00:00        950                    30 
      7902 FORD       ANALYST         7566 1981-12-03 00:00:00       3000                    20 
      7934 MILLER     CLERK           7782 1982-01-23 00:00:00       1300                    10 
14 rows selected.

4.你可以将这个恢复不实际,我仅仅恢复一个块.而且是1条1条的恢复,应该效率很低.多个数据块就比较麻烦了,我仅仅提供1个解决方法. 
--//有时间写一个大一点的表的恢复.总之通过修改对于数据块的段号恢复是可行的.

阅读(1519) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~