数据泵的跨版本问题

数据泵在10g刚推出的时候,跨版本的问题并不明显,而等到11.2推出之后,数据泵同样存在处理跨版本的问题。
Oracle原始的EXP/IMP导出、导入工具的扩版本特性对于从8/9版本就接触数据库的人来说,应该是基本常识了——低版本导出,目标版本导入。
而对于数据泵来说,很多人并没有意识到这一点,事实上数据泵如果从低版本导出,高版本导入是不需要额外处理的,而大多数的需求不是版本相同,就是版本升级,因此很多人没有注意到数据泵的版本问题。
不过如果数据泵从高版本导入大低版本,如果不加处理,就会出现下面的错误:

[orat1@hpserver2 ~]$ expdp test/test dumpfile=d_tmp:tab1.dp TABLES=tab1 
Export: Release 11.2.0.3.0 - Production ON Mon Apr 27 09:50:10 2012
Copyright (c) 1982, 2011, Oracle AND/OR its affiliates. ALL rights reserved.
Connected TO: Oracle DATABASE 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
WITH the Partitioning, OLAP, DATA Mining AND REAL Application Testing options
Starting "TEST"."SYS_EXPORT_TABLE_01": test/******** dumpfile=d_tmp:tab1.dp tables=tab1 
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 64 KB
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
. . exported "TEST"."TAB1" 6.593 KB 63 rows
Master table "TEST"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for TEST.SYS_EXPORT_TABLE_01 is:
/tmp/tab1.dp
Job "TEST"."SYS_EXPORT_TABLE_01" successfully completed at 09:50:17

11.2导入的文件,10.2直接导入报错:

[orat3@hpserver2 ~]$ impdp test/test directory=d_tmp dumpfile=tab1.dp
Import: Release 10.2.0.4.0 - 64bit Production ON Monday,27 April, 2012 9:50:25
Copyright (c) 2003, 2007, Oracle. ALL rights reserved.
Connected TO: Oracle DATABASE 10g Enterprise Edition Release 10.2.0.4.0 - 64bit Production
WITH the Partitioning, OLAP, DATA Mining AND REAL Application Testing options
ORA-39001: invalid argument VALUE
ORA-39000: bad dump file specification
ORA-39142: incompatible version NUMBER 3.1 IN dump file "/tmp/tab1.dp"

正确的方式是在高版本导出的时候指定导出的版本,比如导入版本为10204,那么在11.2上导出时通过VERSION=10.2.0.4,确保导出的数据和结构和低版本兼容。

[orat1@hpserver2 ~]$ expdp test/test dumpfile=d_tmp:tab110204.dp TABLES=tab1 version=10.2.0.4
Export: Release 11.2.0.3.0 - Production ON Mon Apr 27 09:52:03 2012
Copyright (c) 1982, 2011, Oracle AND/OR its affiliates. ALL rights reserved.
Connected TO: Oracle DATABASE 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
WITH the Partitioning, OLAP, DATA Mining AND REAL Application Testing options
Starting "TEST"."SYS_EXPORT_TABLE_01": test/******** dumpfile=d_tmp:tab110204.dp tables=tab1 version=10.2.0.4 
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 64 KB
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
. . exported "TEST"."TAB1" 6.406 KB 63 rows
Master table "TEST"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for TEST.SYS_EXPORT_TABLE_01 is:
/tmp/tab110204.dp
Job "TEST"."SYS_EXPORT_TABLE_01" successfully completed at 09:52:09

这样在10.2.0.4数据库上就可以直接导入了。

[orat3@hpserver2 ~]$ impdp test/test directory=d_tmp dumpfile=tab110204.dp
Import: Release 10.2.0.4.0 - 64bit Production ON Monday, 27 April, 2012 9:54:35
Copyright (c) 2003, 2007, Oracle. ALL rights reserved.
Connected TO: Oracle DATABASE 10g Enterprise Edition Release 10.2.0.4.0 - 64bit Production
WITH the Partitioning, OLAP, DATA Mining AND REAL Application Testing options
Master TABLE "TEST"."SYS_IMPORT_FULL_01" successfully loaded/unloaded
Starting "TEST"."SYS_IMPORT_FULL_01": test/******** directory=d_tmp dumpfile=tab110204.dp 
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
. . imported "TEST"."TAB1" 6.406 KB 63 rows
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
Job "TEST"."SYS_IMPORT_FULL_01" successfully completed at 09:54:36
This entry was posted in ORACLE and tagged , , , , , . Bookmark the permalink.

Leave a Reply

Your email address will not be published. Required fields are marked *