ITPUX技术网

交流 . 资讯 . 分享
Make progress together!
Oracle数据库DBA高级工程师培训视频
Oracle数据库培训-备份恢复-性能优化-集群容灾
mysql数据库视频教程

Oracle imp导入数据时报IMP-00032与IMP-00008的解决方法

内容发布:风哥| 发布时间:2014-4-22 15:45:28
Oracle imp导入数据时报IMP-00032与IMP-00008的解决方法

Symptoms

You try to import an export dump using the original import utility (imp) and received the errors:
IMP-00032: SQL statement exceeded buffer length
IMP-00008: unrecognized statement in the export file
Let's follow the next example that demonstrates this.
-- create a big table (with a large DDL, 1000 columns) in schema test
connect test/test
create table big_table
(
   col000000000000000000000000001 varchar2(4000) not null,
   col000000000000000000000000002 varchar2(4000) not null,
   col000000000000000000000000003 varchar2(4000) not null,
   col000000000000000000000000004 varchar2(4000) not null,
   col000000000000000000000000005 varchar2(4000) not null,
   col000000000000000000000000006 varchar2(4000) not null,
   col000000000000000000000000007 varchar2(4000) not null,
   col000000000000000000000000008 varchar2(4000) not null,
   col000000000000000000000000009 varchar2(4000) not null,
   col000000000000000000000000010 varchar2(4000) not null,
   .... 1000 columns
   col000000000000000000000001000 varchar2(4000) not null
);

-- insert one row into table
declare
  i number := 1;
   
begin
  insert into big_table values  
  (
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     lpad (to_char (i), 1000, '0'),
     .... 1000 columns
     lpad (to_char (i), 1000, '0')
  );   
  commit;   
end;
/
Export the table with:

#> exp test/test file=big_table.dmp tables=big_table
This ends with:
Export: Release 11.1.0.7.0 - Production on Mon Jun 22 11:52:53 2009

Copyright (c) 1982, 2007, Oracle. All rights reserved.

Connected to: Oracle Database 11g Enterprise Edition Release 11.1.0.7.0 - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Export done in WE8MSWIN1252 character set and AL16UTF16 NCHAR character set

About to export specified tables via Conventional Path ...
. . exporting table          BIG_TABLE           1 rows exported
Export terminated successfully without warnings.

Drop the table in schema TEST and import it back from written dump with:

#> imp test/test file=big_table.dmp tables=big_table
This ends with:
Import: Release 11.1.0.7.0 - Production on Mon Jun 22 11:53:55 2009

Copyright (c) 1982, 2007, Oracle. All rights reserved.

Connected to: Oracle Database 11g Enterprise Edition Release 11.1.0.7.0 - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

Export file created by EXPORT:V11.01.00 via conventional path
import done in WE8MSWIN1252 character set and AL16UTF16 NCHAR character set
. importing TEST's objects into TEST
IMP-00032: SQL statement exceeded buffer length
IMP-00032: SQL statement exceeded buffer length
IMP-00008: unrecognized statement in the export file:
R2(4000) NOT NULL ENABLE, "COL000000000000000000000000945" VARCHAR2(4000) NOT
NULL ENABLE, "COL000000000000000000000000946" VARCHAR2(4000) NOT NULL ENABLE, "C
OL000000000000000000000000947" VARCHAR2(4000) NOT NULL ENABLE, "COL0000000000000
00000000000948"...
IMP-00032: SQL statement exceeded buffer length
IMP-00008: unrecognized statement in the export file:
000000000000000000000000000000000000000000000000000000000000000000000000000000
00000000000000000000000000000000000000000000000000000000000000000000000000000000
00000000000000000000000000000000000000000000000000000000000000000000000000000000
000000000000000...
. importing TEST's objects into TEST
Import terminated successfully with warnings.

Cause
The internal BUFFER (default 32 KB, if not specified in imp command line) is also used to transfer the DDL statements from export dump file to Oracle server. If the DDL exceeds the BUFFER length, then IMP-32 is raised.
To obtain the DDL length run at export (source) site the statement:

select dbms_lob.getlength (dbms_metadata.get_ddl ('TABLE', 'BIG_TABLE', 'TEST')) "SQL_LENGTH" from dual;

SQL_LENGTH
----------
     67270

1 row selected.

The length of the DDL statement is in this case 67270 bytes, which exceeds the default BUFFER length (30720 bytes ~ 32 KB).

Solution
Increase the BUFFER size:
#> imp test/test file=big_table.dmp tables=big_table buffer=100000
and the import succeeds:
Import: Release 11.1.0.7.0 - Production on Mon Jun 22 12:10:15 2009

Copyright (c) 1982, 2007, Oracle. All rights reserved.

Connected to: Oracle Database 11g Enterprise Edition Release 11.1.0.7.0 - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

Export file created by EXPORT:V11.01.00 via conventional path
import done in WE8MSWIN1252 character set and AL16UTF16 NCHAR character set
. importing TEST's objects into TEST
. importing TEST's objects into TEST
. . importing table          "BIG_TABLE"          1 rows imported
Import terminated successfully without warnings.




上一篇:FAQ – Automatic Undo Management (AUM) / System Managed Undo (SMU)
下一篇:Oracle ASM 磁盘组介绍
189070296,150201289

专业提供Oracle数据库服务、主机、存储、备份、中间件等相关技术支持服务,QQ号:176140749
关注ITPUX技术网微信公众号itpux_com  ,了解本站最新技术资料的分享.

欢迎加QQ群,提供超多高质量Oracle/Unix/Linux技术文档与视频教程的下载。

Oracle/MySQL/Linux群4-5:189070296  150201289  
Oracle/MySQL/Linux群6-8:244609803   522261684   522651731
备注:请勿重复加群,另请注明 from itpux

加群分享视频教程部分如下:

1、公开课视频:Oracle/MySQL数据库工程师职业发展前景讲解(免费)
http://edu.51cto.com/course/7015.html

2、51CTO学院Oracle数据库高级工程师培训(高薪就业.课程介绍)
http://edu.51cto.com/px/train/131?xiaotu

3、Oracle DBA数据库高级工程师培训视频课程1.1(系列78套+七大阶段+上千案例)
套餐视频地址: http://edu.51cto.com/topic/1121.html

4、MySQL数据库(终身门徒)套餐:http://edu.51cto.com/sd/1e1a6

回复

使用道具 举报

1框架
您需要登录后才可以回帖 登录 | 立即注册

本版积分规则

快速回复 返回顶部 返回列表