10G版本以前分区表导入的方法:
分区表在导入时,一般来说,有两种情况
1、在导入数据库中,与被导入表的分区相关的表空间已对等建立好(表空间名也是与exp数据库中一致的),那么这种情况,与普通表的imp操作是一样的
2、但多数情况下,我们不知道exp数据库中该表的物理结构,此时,可以执行以下步骤
(1)、从dmp文件中获取分区表的物理结构,执行如下命令
C:\Documents and Settings\qcui>imp qcui/qcui@ora9 file=d:\temp\p.dmp fromuser=bi touser=qcui ignore=y tables=(dhfa_revenue_base) indexfile=d:\temp\dhfa.sql 经由直接路径导出由EXPORT:V09.02.00创建的导出文件 警告: 此对象由 BI 导出, 而不是当前用户 已经完成ZHS16GBK字符集和AL16UTF16 NCHAR 字符集中的导入 . . 正在跳过分区 "DHFA_REVENUE_BASE":"PART_2004" . . 正在跳过分区 "DHFA_REVENUE_BASE":"PART_2005" . . 正在跳过分区 "DHFA_REVENUE_BASE":"PART_2006" . . 正在跳过分区 "DHFA_REVENUE_BASE":"PART_2007" . . 正在跳过分区 "DHFA_REVENUE_BASE":"PART_2008" 成功终止导入,但出现警告。
(2)、根据需要编辑该表的DDL脚本(在本例中就是 d:\temp\dhfa.sql)。
– 如果希望重新规划该表的物理存储结构,则可以先创建好表空间,然后直接编辑DDL脚本,并创建该表
– 如果希望分区表相关的分区表空间就按照exp库组织,那么创建好相关的表空间,直接执行该DDL脚本,即可
3、执行分区表的导入,导入时比一般的imp操作,参数上多增加一个 ignore=y 就可以了
如果是10g及以上版本,可以使用参数REMAP_TABLESPACE 来映射表空间
1.在ascii数据库中建立3个tablespaces:tbs1,tbs2,tbs3;
SQL> create tablespace tbs1 datafile 'tbs1_data1' size 10M; Tablespace created. SQL> create tablespace tbs2 datafile 'tbs2_data1' size 10M; Tablespace created. SQL> create tablespace tbs3 datafile 'tbs3_data1' size 10M; Tablespace created.
2.建立分区数据库表tbs_t:
SQL> create table tbs_t(a int ) partition by range(a) 2 ( 3 partition tbs1 values less than (100), 4 partition tbs2 values less than (200), 5 partition tbs3 values less than (maxvalue)); Table created.
3.在tbs_t中插入数据commit后数据:
SQL> select * from tbs_t; A ---------- 1 2 3 100 101 102 103 202 402 502 602 11 rows selected.
4.使用expdp导出数据表tbs_t:
E:/tmp>expdp scott/tiger directory=dump_dest tables=tbs_t parallel=2 Export: Release 10.2.0.1.0 - Production on Wednesday, 20 April, 2011 16:41:46 Copyright (c) 2003, 2005, Oracle. All rights reserved. Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production With the Partitioning, OLAP and Data Mining options Starting "SCOTT"."SYS_EXPORT_TABLE_01": scott/******** directory=dump_dest tables=tbs_t parallel=2 Estimate in progress using BLOCKS method... Processing object type TABLE_EXPORT/TABLE/TABLE_DATA Total estimation using BLOCKS method: 192 KB Processing object type TABLE_EXPORT/TABLE/TABLE . . exported "SCOTT"."TBS_T":"TBS1" 4.937 KB 3 rows . . exported "SCOTT"."TBS_T":"TBS2" 4.945 KB 4 rows . . exported "SCOTT"."TBS_T":"TBS3" 4.945 KB 4 rows Master table "SCOTT"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded ****************************************************************************** Dump file set for SCOTT.SYS_EXPORT_TABLE_01 is: E:/TMP/EXPDAT.DMP Job "SCOTT"."SYS_EXPORT_TABLE_01" successfully completed at 16:41:55
5.将产生的”E:/TMP/EXPDAT.DMP”文件导入无分区数据库ocp10g;
SQL> select instance_name from v$instance; INSTANCE_NAME ---------------- ocp10g SQL> select tablespace_name from dba_tablespaces; TABLESPACE_NAME ------------------------------ SYSTEM UNDOTBS1 SYSAUX TEMP USERS UNDOTBS2 EXAMPLE USERTBS USERTBS1 UNDO_SMALL 10 rows selected. E:/tmp>impdp scott/tiger dumpfile=expdat.dmp directory=dump_dest remap_tablespace=tbs1:usertbs remap_tablespace=tbs2:usertbs remap_tablespace=tbs3:usertbs Import: Release 10.2.0.1.0 - Production on Wednesday, 20 April, 2011 16:47:09 Copyright (c) 2003, 2005, Oracle. All rights reserved. Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production With the Partitioning, OLAP and Data Mining options Master table "SCOTT"."SYS_IMPORT_FULL_01" successfully loaded/unloaded Starting "SCOTT"."SYS_IMPORT_FULL_01": scott/******** dumpfile=expdat.dmp directory=dump_dest remap_tablespace=tbs1:usertbs remap_tablespace=tbs2:use rtbs remap_tablespace=tbs3:usertbs Processing object type TABLE_EXPORT/TABLE/TABLE Processing object type TABLE_EXPORT/TABLE/TABLE_DATA . . imported "SCOTT"."TBS_T":"TBS1" 4.937 KB 3 rows . . imported "SCOTT"."TBS_T":"TBS2" 4.945 KB 4 rows . . imported "SCOTT"."TBS_T":"TBS3" 4.945 KB 4 rows Job "SCOTT"."SYS_IMPORT_FULL_01" successfully completed at 16:47:22
6.imp数据成功:
SQL> conn scott/tiger Connected. SQL> select * from tbs_t; A ---------- 1 2 3 100 101 102 103 202 402 502 602 11 rows selected.