2016年(18)
分类: Oracle
2016-06-22 19:39:52
在有些时候,exp的dmp文件因为某种原因损坏(比如磁盘异常,exp过程损坏等),导致imp导入无法继续,下面的处理方法(直接读取dmp文件)来对dmp文件进行抢救性恢复,最大程度减少数据丢失损失
SQL> create table t_xifenfei as select * from dba_objects; Table created. SQL> select count(*) from t_xifenfei; COUNT(*) ---------- 90915 [oracle@localhost ~]$ exp chf/xifenfei@pdb1 file=/tmp/t_xifenfei.dmp tables=t_xifenfei Export: Release 12.1.0.2.0 on Sun Apr 27 21:39:26 2014 Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved. Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options Export done in US7ASCII character set and AL16UTF16 NCHAR character set server uses WE8MSWIN1252 character set (possible charset conversion) About to export specified tables via Conventional Path ... . . exporting table T_XIFENFEI 90915 rows exported EXP-00091: Exporting questionable statistics. Export terminated successfully with warnings. [oracle@localhost ~]$ od -x /tmp/t_xifenfei.dmp |head -10 0000000 0003 4501 5058 524f 3a54 3156 2e32 3130 0000020 302e 0a30 4344 4648 520a 4154 4c42 5345 0000040 380a 3931 0a32 0a30 3237 300a 000a 0001 0000060 07b2 00d0 0001 0000 0000 0000 0000 0013 0000100 2020 2020 2020 2020 2020 2020 2020 2020 * 0000140 2020 2020 2020 2020 7553 206e 7041 2072 0000160 3732 3220 3a31 3933 323a 2036 3032 3431 0000200 742f 706d 742f 785f 6669 6e65 6566 2e69 0000220 6d64 0070 0000 0000 0000 0000 0000 0000 --strings命令看dmp文件 [oracle@localhost ~]$ strings /tmp/t_xifenfei.dmp |head -50 EXPORT:V12.01.00 DCHF RTABLES 8192 Tue Apr 29 0:39:49 2014/tmp/t_xifenfei.dmp #G#G #G#G +08:00 BYTE UNUSED INTERPRETED DISABLE:ALL METRICST TABLE "T_XIFENFEI" CREATE TABLE "T_XIFENFEI" ("OWNER" VARCHAR2(128), "OBJECT_NAME" VARCHAR2(128), "SUBOBJECT_NAME" VARCHAR2(128), "OBJECT_ID" NUMBER, "DATA_OBJECT_ID" NUMBER, "OBJECT_TYPE" VARCHAR2(23), "CREATED" DATE, "LAST_DDL_TIME" DATE, "TIMESTAMP" VARCHAR2(19), "STATUS" VARCHAR2(7), "TEMPORARY" VARCHAR2(1), "GENERATED" VARCHAR2(1), "SECONDARY" VARCHAR2(1), "NAMESPACE" NUMBER, "EDITION_NAME" VARCHAR2(128), "SHARING" VARCHAR2(13), "EDITIONABLE" VARCHAR2(1), "ORACLE_MAINTAINED" VARCHAR2(1)) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 STORAGE(INITIAL 13631488 NEXT 1048576 MINEXTENTS 1 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" LOGGING NOCOMPRESS INSERT INTO "T_XIFENFEI" ("OWNER", "OBJECT_NAME", "SUBOBJECT_NAME", "OBJECT_ID", "DATA_OBJECT_ID", "OBJECT_TYPE", "CREATED", "LAST_DDL_TIME", "TIMESTAMP", "STATUS", "TEMPORARY", "GENERATED", "SECONDARY", "NAMESPACE", "EDITION_NAME", "SHARING", "EDITIONABLE", "ORACLE_MAINTAINED") VALUES (:1, :2, :3, :4, :5, :6, :7, :8, :9, :10, :11, :12, :13, :14, :15, :16, :17, :18) PUBLIC V$DATAGUARD_CONFIG SYNONYM 2014-04-22:17:51:05 VALID METADATA LINK V_$DATAGUARD_STATS VIEW 2014-04-22:17:51:05 --破坏exp dmp文件 [oracle@localhost ~]$ dd if=/dev/zero of=/tmp/t_xifenfei.dmp bs=1024 count=1 conv=notrunc 1+0 records in 1+0 records out 1024 bytes (1.0 kB) copied, 6.0291e-05 seconds, 17.0 MB/s [oracle@localhost ~]$ od -x /tmp/t_xifenfei.dmp |head -10 0000000 0000 0000 0000 0000 0000 0000 0000 0000 * 0020000 0064 0000 6000 2401 050f 0c0b 0c03 050c 0020020 0504 060d 0709 0508 0505 0505 050f 0505 0020040 0505 050a 0505 0505 0504 0706 0808 4723 0020060 4723 1108 0823 4111 47b0 8300 b200 d007 0020100 0003 0000 0000 0000 0000 0000 0000 0000 0020120 0000 0000 0000 0000 0000 0000 0000 0000 0020140 0000 0000 0000 0064 0000 6000 2401 050f 0020160 0c0b 0c03 050c 0504 060d 0709 0508 0505 --损坏后的dmp文件使用strings命令看 [oracle@localhost ~]$ strings /tmp/t_xifenfei.dmp |head -50 #G#G #G#G +08:00 BYTE UNUSED INTERPRETED DISABLE:ALL METRICST TABLE "T_XIFENFEI" CREATE TABLE "T_XIFENFEI" ("OWNER" VARCHAR2(128), "OBJECT_NAME" VARCHAR2(128), "SUBOBJECT_NAME" VARCHAR2(128), "OBJECT_ID" NUMBER, "DATA_OBJECT_ID" NUMBER, "OBJECT_TYPE" VARCHAR2(23), "CREATED" DATE, "LAST_DDL_TIME" DATE, "TIMESTAMP" VARCHAR2(19), "STATUS" VARCHAR2(7), "TEMPORARY" VARCHAR2(1), "GENERATED" VARCHAR2(1), "SECONDARY" VARCHAR2(1), "NAMESPACE" NUMBER, "EDITION_NAME" VARCHAR2(128), "SHARING" VARCHAR2(13), "EDITIONABLE" VARCHAR2(1), "ORACLE_MAINTAINED" VARCHAR2(1)) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 STORAGE(INITIAL 13631488 NEXT 1048576 MINEXTENTS 1 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" LOGGING NOCOMPRESS INSERT INTO "T_XIFENFEI" ("OWNER", "OBJECT_NAME", "SUBOBJECT_NAME", "OBJECT_ID", "DATA_OBJECT_ID", "OBJECT_TYPE", "CREATED", "LAST_DDL_TIME", "TIMESTAMP", "STATUS", "TEMPORARY", "GENERATED", "SECONDARY", "NAMESPACE", "EDITION_NAME", "SHARING", "EDITIONABLE", "ORACLE_MAINTAINED") VALUES (:1, :2, :3, :4, :5, :6, :7, :8, :9, :10, :11, :12, :13, :14, :15, :16, :17, :18) PUBLIC V$DATAGUARD_CONFIG SYNONYM 2014-04-22:17:51:05 VALID METADATA LINK V_$DATAGUARD_STATS --imp 导入dmp文件失败 [oracle@localhost ~]$ imp chf/xifenfei@pdb1 file=/tmp/t_xifenfei.dmp full=y Import: Release 12.1.0.2.0 - on Sun Apr 27 22:02:40 2014 Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved. Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options IMP-00037: Character set marker unknown IMP-00000: Import terminated unsuccessfully
这里通过分析可以知道,exp dmp文件虽然损坏了一点,但是通过strings命令看,相关记录依然存在,因此可以通过工具去读exp dmp文件,然后分析得出相关数据
CPFL> SEARCH TABLE T_XIFENFEI FROM EXPFILE /tmp/t_xifenfei.dmp 8461: TABLE "T_XIFENFEI" 8480: CREATE TABLE "T_XIFENFEI" ("OWNER" VARCHAR2(128), "OBJECT_NAME" VARCHAR2(128), "SUBOBJECT_NAME" VARCHAR2(128), "OBJECT_ID" NUMBER, "DATA_OBJECT_ID" NUMBER, "OBJECT_TYPE" VARCHAR2(23), "CREATED" DATE, "LAST_DDL_TIME" DATE, "TIMESTAMP" VARCHAR2(19), "STATUS" VARCHAR2(7), "TEMPORARY" VARCHAR2(1), "GENERATED" VARCHAR2(1), "SECONDARY" VARCHAR2(1), "NAMESPACE" NUMBER, "EDITION_NAME" VARCHAR2(128), "SHARING" VARCHAR2(13), "EDITIONABLE" VARCHAR2(1), "ORACLE_MAINTAINED" VARCHAR2(1)) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 STORAGE(INITIAL 8388608 NEXT 1048576 MINEXTENTS 1 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" LOGGING NOCOMPRESS 9145: INSERT INTO "T_XIFENFEI" ("OWNER", "OBJECT_NAME", "SUBOBJECT_NAME", "OBJECT_ID", "DATA_OBJECT_ID", "OBJECT_TYPE", "CREATED", "LAST_DDL_TIME", "TIMESTAMP", "STATUS", "TEMPORARY", "GENERATED", "SECONDARY", "NAMESPACE", "EDITION_NAME", "SHARING", "EDITIONABLE", "ORACLE_MAINTAINED") VALUES (:1, :2, :3, :4, :5, :6, :7, :8, :9, :10, :11, :12, :13, :14, :15, :16, :17, :18) Conventional export 9644: start of table data 12331252: TABLE "T_XIFENFEI" 12331349: ENDTABLE CPFL> UNLOAD TABLE "T_XIFENFEI" ("OWNER" VARCHAR2(128), "OBJECT_NAME" VARCHAR2(128), "SUBOBJECT_NAME" VARCHAR2(128), "OBJECT_ID" NUMBER, "DATA_OBJECT_ID" NUMBER, "OBJECT_TYPE" VARCHAR2(23), "CREATED" DATE, "LAST_DDL_TIME" DATE, "TIMESTAMP" VARCHAR2(19), "STATUS" VARCHAR2(7), "TEMPORARY" VARCHAR2(1), "GENERATED" VARCHAR2(1), "SECONDARY" VARCHAR2(1), "NAMESPACE" NUMBER, "EDITION_NAME" VARCHAR2(128), "SHARING" VARCHAR2(13), "EDITIONABLE" VARCHAR2(1), "ORACLE_MAINTAINED" VARCHAR2(1)) expfile /tmp/t_xifenfei.dmp from 8480 until 12331349 --因为exp dmp文件损坏记录 CPFL: Error: column 1 length 21059 exceeds max bind size 128 0000000000 45415445 20544142 4c452022 545f5849 EATE TAB LE " T_XI 0000000016 46454e46 45492220 28224f57 4e455222 FENF EI" ("OW NER" 0000000032 20564152 43484152 VAR CHAR 8480: column 1 type VARCHAR2 size 21059 failed 8480: row 1 failed row conversion failure, retrying from offset 8481 CPFL: Error: Zero (illegal) length column number 2 ………… CPFL: Error: Zero (illegal) length column number 1 9644: succesful conversion 1164 bytes skipped due to conversion problems 131877: row 1000 ok 253310: row 2000 ok ………… 12200617: row 90000 ok Unloaded 90915 rows, end of table marker at 12322835 [oracle@localhost CPFL]$ ls -ltr T_XIFENFEI.* -rw-r--r-- 1 oracle oinstall 17230747 Apr 27 22:12 T_XIFENFEI.dat -rw-r--r-- 1 oracle oinstall 1489 Apr 27 22:17 T_XIFENFEI.ctl
SQL> create table t_xifenfei_exp as select * from t_xifenfei where 1=0; Table created. [oracle@localhost CPFL]$ more T_XIFENFEI.ctl load data CHARACTERSET UTF8 infile 'T_XIFENFEI.dat' insert into table "T_XIFENFEI_EXP" ---修改为T_XIFENFEI_EXP表 fields terminated by whitespace ( "OWNER" CHAR(128) enclosed by X'7C' ,"OBJECT_NAME" CHAR(128) enclosed by X'7C' ,"SUBOBJECT_NAME" CHAR(29) enclosed by X'7C' ,"OBJECT_ID" CHAR(5) enclosed by X'7C' ,"DATA_OBJECT_ID" CHAR(5) enclosed by X'7C' ,"OBJECT_TYPE" CHAR(20) enclosed by X'7C' ,"CREATED" DATE "DD-MON-YYYY AD HH24:MI:SS" enclosed by X'7C' ,"LAST_DDL_TIME" DATE "DD-MON-YYYY AD HH24:MI:SS" enclosed by X'7C' ,"TIMESTAMP" CHAR(19) enclosed by X'7C' ,"STATUS" CHAR(5) enclosed by X'7C' ,"TEMPORARY" CHAR(1) enclosed by X'7C' ,"GENERATED" CHAR(1) enclosed by X'7C' ,"SECONDARY" CHAR(1) enclosed by X'7C' ,"NAMESPACE" CHAR(2) enclosed by X'7C' ,"EDITION_NAME" CHAR(1) enclosed by X'7C' ,"SHARING" CHAR(13) enclosed by X'7C' ,"EDITIONABLE" CHAR(1) enclosed by X'7C' ,"ORACLE_MAINTAINED" CHAR(1) enclosed by X'7C' ,"UNEXP_STATUS" FILLER CHAR(3) enclosed by X'7C' ) [oracle@localhost CPFL]$ sqlldr chf/xifenfei@pdb1 control=T_XIFENFEI.ctl SQL*Loader: Release 12.1.0.1.0 on Sun Apr 27 22:17:54 2014 Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved. Path used: Conventional Commit point reached - logical record count 64 Commit point reached - logical record count 128 Commit point reached - logical record count 192 ………… Commit point reached - logical record count 90887 Commit point reached - logical record count 90915 Table "T_XIFENFEI_EXP": 90915 Rows successfully loaded. Check the log file: T_XIFENFEI.log for more information about the load. [oracle@localhost CPFL]$ sqlplus chf/xifenfei@pdb1 SQL*Plus: Release 12.1.0.2.0 Beta on Sun Apr 27 22:18:08 2014 Copyright (c) 1982, 2014, Oracle. All rights reserved. Last Successful login time: Sun Apr 27 2014 22:17:54 +08:00 Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options SQL> select count(*) from t_xifenfei_exp; COUNT(*) ---------- 90915 SQL> select * from t_xifenfei 2 minus 3 select * from t_xifenfei_exp; no rows selected
通过这里可以看出来,在exp dmp文件有部分损坏的情况下,还是可以通过直接读取dmp文件的方式恢复全部或者部分exp dmp文件中内容(具体恢复量取决于dmp文件损坏程度)
--------------------------------------ORACLE-DBA----------------------------------------
最权威、专业的Oracle案例资源汇总之案例:Oracle exp dmp文件损坏 通过CPFL工具抽取dmp中的数据表进行恢复
原文唯一网址: