来自农村的老实娃
分类: Oracle
2008-09-18 10:20:07
在利用NETWORK_LINK方式导出的时候,出现了这个错误。
详细错误信息如下:
bash-3.00$ expdp yangtk/yangtk directory=d_temp dumpfile=jiangsu.dp network_link=test113 logfile=jiangsu.log tables=cat_org
Export: Release11.1.0.6.0 - 64bit Production on星期二, 16 9月, 2008 17:08:22
Copyright (c) 2003, 2007, Oracle. All rights reserved.
连接到: Oracle Database11gEnterprise Edition Release11.1.0.6.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
ORA-31631:需要权限
ORA-39149:无法将授权用户链接到非授权用户
检查Oracle的错误手册:
ORA-39149: cannot link privileged user to non-privileged user
Cause: A Data Pump job initiated be a user with EXPORT_FULL_DATABASE/IMPORT_FULL_DATABASE roles specified a network link that did not correspond to a user with equivalent roles on the remote database.
Action: Specify a network link that maps users to identically privileged users in the remote database.
错误描述的比较清楚,不过这个错误很难理解,难道一个权限大的用户不能通过数据库链导出一个权限小的用户。
当然,了解了这个错误的原因,其实问题很容易解决。在本地创建一个新用户,不要授权EXP_FULL_DATABASE/IMP_FULL_DATABASE角色,就可以导出:
bash-3.00$ sqlplus "/ as sysdba"
SQL*Plus: Release11.1.0.6.0 - Production on星期二9月16 16:53:48 2008
Copyright (c) 1982, 2007, Oracle. All rights reserved.
连接到:
Oracle Database11gEnterprise Edition Release11.1.0.6.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
SQL> col grantee format a15
SQL> col granted_role format a15
SQL> select grantee, granted_role from dba_role_privs
2 where grantee = 'YANGTK';
GRANTEE GRANTED_ROLE
--------------- ---------------
YANGTK CONNECT
YANGTK RESOURCE
YANGTK DBA
SQL> drop user test cascade;
用户已删除。
SQL> create user test identified by test
2 default tablespace users
3 quota unlimited on users;
用户已创建。
SQL> grant connect to test;
授权成功。
SQL> grant create table, create database link to test;
授权成功。
SQL> grant read, write on directory d_temp to test;
授权成功。
SQL> conn test/test
已连接。
SQL> create database link test113 connect tojiangsuidentified byjiangsu
2 using '172.0.2.113/test';
数据库链接已创建。
SQL> select * from ;
GLOBAL_NAME
--------------------------------------------------------------------------------
TEST
SQL> exit
从Oracle Database11gEnterprise Edition Release11.1.0.6.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options断开
使用这个用户就执行导出了:
bash-3.00$ expdp yangtk/yangtk directory=d_temp dumpfile=jiangsu.dp network_link=test113 logfile=jiangsu.log tables=cat_org
Export: Release11.1.0.6.0 - 64bit Production on星期二, 16 9月, 2008 17:08:22
Copyright (c) 2003, 2007, Oracle. All rights reserved.
连接到: Oracle Database11gEnterprise Edition Release11.1.0.6.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
ORA-31631:需要权限
ORA-39149:无法将授权用户链接到非授权用户
bash-3.00$ expdp test/test directory=d_temp dumpfile=jiangsu.dp network_link=test113 logfile=jiangsu.log tables=cat_org
Export: Release11.1.0.6.0 - 64bit Production on星期二, 16 9月, 2008 17:09:10
Copyright (c) 2003, 2007, Oracle. All rights reserved.
连接到: Oracle Database11gEnterprise Edition Release11.1.0.6.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
启动"TEST"."SYS_EXPORT_TABLE_01": test/******** directory=d_temp dumpfile=jiangsu.dp network_link=test113 logfile=jiangsu.log tables=cat_org
正在使用BLOCKS方法进行估计...
处理对象类型TABLE_EXPORT/TABLE/TABLE_DATA
使用BLOCKS方法的总估计: 6 MB
处理对象类型TABLE_EXPORT/TABLE/TABLE
处理对象类型TABLE_EXPORT/TABLE/GRANT/OWNER_GRANT/OBJECT_GRANT
处理对象类型TABLE_EXPORT/TABLE/INDEX/INDEX
处理对象类型TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
处理对象类型TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
处理对象类型TABLE_EXPORT/TABLE/COMMENT
处理对象类型TABLE_EXPORT/TABLE/TRIGGER
处理对象类型TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
. .导出了"JIANGSU"."CAT_ORG" 4.390 MB 31827行
已成功加载/卸载了主表"TEST"."SYS_EXPORT_TABLE_01"
******************************************************************************
TEST.SYS_EXPORT_TABLE_01的转储文件集为:
/data/jiangsu.dp
作业"TEST"."SYS_EXPORT_TABLE_01"已于17:09:57成功完成
如果可以修改远端的用户,那么更简单,只需要给远端用户授权EXP_FULL_DATABASE角色就可以了:
-bash-3.00$ sqlplus "/ as sysdba"
SQL*Plus: Release10.2.0.3.0 - Production on Tue Sep 16 17:16:27 2008
Copyright (c) 1982, 2006, Oracle. All Rights Reserved.
Connected to:
Oracle Database10gEnterprise Edition Release10.2.0.3.0 - 64bit Production
With the Partitioning and Data Mining options
SQL> select global_name from global_name;
GLOBAL_NAME
--------------------------------------------------------------------------------
TEST
SQL> grant exp_full_database tojiangsu;
Grant succeeded.
下面再次使用yangtk执行导出:
bash-3.00$ expdp yangtk/yangtk directory=d_temp dumpfile=jiangsu1.dp network_link=test113 logfile=jiangsu.log tables=cat_org
Export: Release11.1.0.6.0 - 64bit Production on星期二, 16 9月, 2008 17:19:25
Copyright (c) 2003, 2007, Oracle. All rights reserved.
连接到: Oracle Database11gEnterprise Edition Release11.1.0.6.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
启动"YANGTK"."SYS_EXPORT_TABLE_01": yangtk/******** directory=d_temp dumpfile=jiangsu1.dp network_link=test113 logfile=jiangsu.log tables=cat_org
正在使用BLOCKS方法进行估计...
处理对象类型TABLE_EXPORT/TABLE/TABLE_DATA
使用BLOCKS方法的总估计: 6 MB
处理对象类型TABLE_EXPORT/TABLE/TABLE
处理对象类型TABLE_EXPORT/TABLE/GRANT/OWNER_GRANT/OBJECT_GRANT
处理对象类型TABLE_EXPORT/TABLE/INDEX/INDEX
处理对象类型TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
处理对象类型TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
处理对象类型TABLE_EXPORT/TABLE/COMMENT
处理对象类型TABLE_EXPORT/TABLE/TRIGGER
处理对象类型TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
. .导出了"JIANGSU"."CAT_ORG" 4.390 MB 31827行
已成功加载/卸载了主表"YANGTK"."SYS_EXPORT_TABLE_01"
******************************************************************************
YANGTK.SYS_EXPORT_TABLE_01的转储文件集为:
/data/jiangsu1.dp
作业"YANGTK"."SYS_EXPORT_TABLE_01"已于17:19:45成功完成
问题倒是很容易解决,只是不理解Oracle为什么处理不了这么简单的问题。而且关键的是,Oracle似乎没有把这个问题当作bug