创建一个表: 记录rowid的分区段并作为处理的日志表:
DROP TABLE DEAL_TABLE_EXTENT;
CREATE TABLE DEAL_TABLE_EXTENT
(seq number,
OWNER VARCHAR2(30),
TABLE_NAME VARCHAR2(30),
EXTENT_ID NUMBER ,
FILE_ID NUMBER ,
BLOCK_ID NUMBER ,
BLOCKS NUMBER ,
RELATIVE_FNO NUMBER ,
MIN_ROWID ROWID,
NEXT_ROWID ROWID,
DEAL_FLAG NUMBER ,
DEAL_ROW NUMBER ,
BEGIN_TIME DATE,
END_TIME DATE,
ERR_MSG VARCHAR2(2000)
);
comment on column DEAL_TABLE_EXTENT.DEAL_FLAG is '处理标志:0 正在处理,1 处理完成,-1 ' ;
comment on column DEAL_TABLE_EXTENT.DEAL_ROW is '该extent已经处理的记录数' ;
insert into DEAL_TABLE_EXTENT
( seq ,
OWNER,
TABLE_NAME,
EXTENT_ID,
FILE_ID,
BLOCK_ID,
BLOCKS,
RELATIVE_FNO,
MIN_ROWID
)
select rownum,
owner,
segment_name,
EXTENT_ID,
FILE_ID,
BLOCK_ID,
BLOCKS,
RELATIVE_FNO,
dbms_rowid.rowid_create(1, OBJ_ID,FILE_ID,BLOCK_ID,0)
from (select owner,
segment_name,
EXTENT_ID,
FILE_ID,
BLOCK_ID,
BLOCKS,
RELATIVE_FNO,
(select object_id from dba_objects where object_name='PAIM_FILE_STORAGE' and owner='EPCISIMSDATA') OBJ_ID
from dba_extents
where segment_name = 'PAIM_FILE_STORAGE'
order by file_id, block_id);
commit ;
create index ix_DEAL_TABLE_EXTENT_seq on DEAL_TABLE_EXTENT(seq);
UPDATE DEAL_TABLE_EXTENT ATE1
SET NEXT_ROWID=(SELECT MIN_ROWID FROM DEAL_TABLE_EXTENT ATE2 WHERE ATE2.SEQ=ATE1.SEQ+1) ;
commit ;
-----------最后一个extent 特殊处理 ----------------------
UPDATE DEAL_TABLE_EXTENT ATE1
SET NEXT_ROWID= (select dbms_rowid.rowid_create(1, object_id,FILE_ID,BLOCK_ID+Blocks,0) from dba_objects where object_name='PAIM_FILE_STORAGE' and owner='EPCISIMSDATA')
where NEXT_ROWID is null ;
commit ;
创建存储过程,按ROWID分段处理
create or replace procedure push_paim_file_storage_1
is
---- PAIM_FILE_STORAGE 搬数据脚本
l_min_rowid rowid ;
l_next_rowid rowid ;
Begin
for i in (select seq,min_rowid,next_rowid from DEAL_TABLE_EXTENT
where seq<50000 AND (deal_flag<>'1' OR deal_flag is null) order by seq)
loop
begin
update DEAL_TABLE_EXTENT set BEGIN_TIME=SYSDATE WHERE SEQ=I.SEQ;
insert /*+ append */ into epcisimsdata.paim_file_storage
select * from epcisimsdata.paim_file_storage@TOCOWEPCISBS where rowid>=i.min_rowid and rowid<i.next_rowid;
update DEAL_TABLE_EXTENT set deal_flag='1',END_TIME=SYSDATE WHERE SEQ=I.SEQ;
COMMIT;
exception when others then
update DEAL_TABLE_EXTENT set deal_flag='0',END_TIME=SYSDATE WHERE SEQ=I.SEQ;
end ;
end loop ;
End ;
注意事项:
select rowid rid
,dbms_rowid.rowid_object(rowid) object_id
,dbms_rowid.rowid_relative_fno(rowid) fno
,dbms_rowid.rowid_block_number(rowid) block_num
,dbms_rowid.rowid_row_number(rowid) row_num
,PROGRAM_INTERFACE_TRACE.*
from PROGRAM_INTERFACE_TRACE sample block (0.001) order by rowed
可以看到, rowed的排序与FILE_ID也有关的, 而extend_id 与FILE_ID没有关系
ROWID的字符排和 ROWID 本身排序是两回事, 不能同一样处理
select rownum rn, a.* from (select ROWIDTOCHAR(rowid) rid
,dbms_rowid.rowid_object(rowid) object_id
,dbms_rowid.rowid_relative_fno(rowid) fno
,dbms_rowid.rowid_block_number(rowid) block_num
,dbms_rowid.rowid_row_number(rowid) row_num,
a.* from AJ50.AJ_JOBS a ) a order by rid
使用ROWIDTOCHAR 或者 CHARtoROWID转换