数据库expdp导出遇到ORA-01555和ORA-22924错误的解决方案
冯工
4269 阅读
0 评论
2 点赞
今天给客户备份数据库,使用expdp数据泵导出数据表时,发现遇到ORA-01555和ORA-22924错误,下面是整个处理过程的分析与解决方案:
1 2 3 4 | ORA-31693: Table data object AMBASE.inq_d_list failed to load /unload and is being skipped due to error: ORA-02354: error in exporting/importing data ORA-01555: snapshot too old: rollback segment number with name "" too small ORA-22924: snapshot too old |
1.查看表空间使用率
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | SELECT UPPER (F.TABLESPACE_NAME) AS "表空间名" , D.TOT_GROOTTE_MB AS "表空间大小(M)" , D.TOT_GROOTTE_MB-F.TOTAL_BYTES AS "已使用空间(M)" , TO_CHAR(ROUND((D.TOT_GROOTTE_MB - F.TOTAL_BYTES) / D.TOT_GROOTTE_MB * 100,2), '990.99' ) || '%' "使用比" , F.TOTAL_BYTES AS "空闲空间(M)" , F.MAX_BYTES AS "最大块(M)" FROM ( SELECT TABLESPACE_NAME, ROUND( SUM (BYTES) / (1024 * 1024), 2) TOTAL_BYTES, ROUND( MAX (BYTES) / (1024 * 1024), 2) MAX_BYTES FROM SYS.DBA_FREE_SPACE GROUP BY TABLESPACE_NAME) F, ( SELECT DD.TABLESPACE_NAME, ROUND( SUM (DD.BYTES) / (1024 * 1024), 2) TOT_GROOTTE_MB FROM SYS.DBA_DATA_FILES DD GROUP BY DD.TABLESPACE_NAME) D WHERE D.TABLESPACE_NAME = F.TABLESPACE_NAME ORDER BY 1; |
2.看到ORA-01555错误,还以为是经典错误,尝试调整undo_retention参数
1 | SYS@cams> alter system set undo_retention=18000 scope=both; |
修改后再次导出,问题依旧存在,显然问题和 undo_retention没关系,再把参数改回去。
3.猜测是表空间有问题,这里尝试对 CAMS_CORE下的索引和LOB 进行表空间迁移。
(1)新建新的表空间
(2)拼接表空间迁移语句,前面已有文章写到了表空间迁移方案
(3)执行表空间迁移语句
1 | alter table AMBASE.inq_d_list move lob(正文内容) store as (tablespace ams_data); |
执行到该语句的时候提示错误:
1 2 | ORA-01555: 快照过旧: 回退段号 (名称为 "") 过小 ORA-22924: 快照太旧 |
这里,问题应该比较明显了,有部分 LOB数据有问题。
4.寻找问题解决方案(MOS)
使用关键字 “expdp ORA-01555 ORA-22924 LOB”进行查找:
Export Fails With Errors ORA-2354 ORA-1555 ORA-22924 And How To Confirm LOB Segment Corruption Using Export Utility (文档 ID 833635.1)
5.参考MOS给出的解决方案,动手处理问题
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 | set concat off create table corrupted_lob_data (corrupted_rowid rowid); set concat off declare error_1555 exception; pragma exception_init(error_1555,-1555); num number; begin for cursor_lob in ( select rowid r, &&lob_column from &table_owner.&table_with_lob) loop begin num := dbms_lob.instr (cursor_lob.&&lob_column, hextoraw ( '889911' )) ; exception when error_1555 then insert into corrupted_lob_data values (cursor_lob.r); commit ; end ; end loop; end ; / Enter value for table_owner: AMBASE Enter value for table_with_lob: inq_d_list Enter value for lob_column: 正文内容 old 6: for cursor_lob in ( select rowid r, &&lob_column from &table_owner.&table_with_lob) loop new 6: for cursor_lob in ( select rowid r, EX_STACK from CAMS_CORE.BP_EXCEPTION_LOG) loop old 8: num := dbms_lob.instr (cursor_lob.&&lob_column, hextoraw ( '889911' )) ; new 8: num := dbms_lob.instr (cursor_lob.EX_STACK, hextoraw ( '889911' )) ; PL/SQL procedure successfully completed. |
查看存在问题的数据记录:
1 2 | select * from AMBASE.inq_d_list where rowid in ( select * from AMBASE.corrupted_lob_data ); |
确实存在20条数据, CLOB 字段数据显示为error ,显然有问题。
MOS上给出的导出方案是将问题数据exclude掉,这里为了彻底解决问题,将20条数据的COLB字段置空。然后再次导出数据库数据,不再提示报错。
CLOB字段置空操作:
1 2 | update AMBASE.inq_d_list set 正文内容 = empty_clob() where rowid in (select corrupted_rowid from AMBASE.corrupted_data); |
- 本文分类:数据库运维
- 本文标签:无
- 浏览次数:4269 次浏览
- 发布日期:2020-05-10 21:15:04
- 本文链接:https://dbs-service.cn/a/271.html
发表评论 取消回复