Chinaunix首页 | 论坛 | 博客
  • 博客访问: 781029
  • 博文数量: 99
  • 博客积分: 0
  • 博客等级: 民兵
  • 技术积分: 1163
  • 用 户 组: 普通用户
  • 注册时间: 2016-09-22 09:50
个人简介

一个守望数据库的老菜鸟

文章分类

全部博文(99)

文章存档

2019年(21)

2018年(17)

2017年(37)

2016年(24)

我的朋友

分类: Oracle

2017-10-02 19:30:36

博客文章除注明转载外,均为原创。转载请注明出处。
本文链接地址:http://blog.chinaunix.net/uid-31396856-id-5772868.html


外部表都是只读表 , 不能进行 update,insert,delete操作
Oracle 提供两种访问驱动 :
1.ORACLE_LOADER 
ORACLE_LOADER利用oracle loader技术从外部表读取数据.
2.ORACLE_DATAPUMP
      提供卸载数据的能力 , 即把数据从数据库里导入一个外部表 , 再由一个或几个外部表导入到数据库里。对于AS subquery 的子句必须使用 ORACLE_DATAPUMP . 创建用于卸载数据的外部表时,不能制定列名.

1.创建directory
(1)创建用户授予至少create any directory的权限
SQL> conn /as sysdba
Connected.
SQL> 
SQL> create user test identified by test;

User created.


SQL> grant dba to test;

Grant succeeded.
(2)
SQL> host mkdir -p /u01/outdata
SQL> CREATE DIRECTORY ext_dir AS '/u01/outdata';       

Directory created.
SQL> GRANT read,write on DIRECTORY ext_dir to test;

Grant succeeded.

2.基于oracle_datapump的外部表实现
(1)准备外部表创建脚本:
CREATE  TABLE emp_xt
    ORGANIZATION EXTERNAL
    (
      TYPE ORACLE_DATAPUMP
      DEFAULT DIRECTORY ext_dir
      LOCATION ('emp_xt.dmp')
    )
    AS SELECT * FROM scott.emp;

SQL> conn test/test
Connected.
SQL> CREATE  TABLE emp_xt
  2      ORGANIZATION EXTERNAL
  3      (
  4        TYPE ORACLE_DATAPUMP
  5        DEFAULT DIRECTORY ext_dir
  6        LOCATION ('emp_xt.dmp')
  7      )
  8      AS SELECT * FROM scott.emp;

Table created.

(2)验证表的正确性
[oracle@oraserv outdata]$ ls -lrt
total 16
-rw-r----- 1 oracle dba 12288 Jan 26 19:01 emp_xt.dmp
-rw-r--r-- 1 oracle dba    41 Jan 26 19:01 EMP_XT_2290.log
[oracle@oraserv outdata]$ 

SQL> select * from emp_xt;

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 19-APR-87       3000                    20
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500          0         30
      7876 ADAMS      CLERK           7788 23-MAY-87       1100                    20
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10

14 rows selected.

SQL> select * from emp_xt minus select * from scott.emp;
no rows selected

(3)删除外部表或者目录对象
一般情况下,先删除外部表,然后再删除目录对象,如果目录对象中有多个表,应删除所有表之后再删除目录对象。
如果在未删除外部表的情况下,强制删除了目录,在查询到被删除的外部表时,将收到"对象不存在"的错误信息。


(4)测试并行

CREATE TABLE emp_xt_1
    ORGANIZATION EXTERNAL
    (                   
      TYPE ORACLE_DATAPUMP
      DEFAULT DIRECTORY ext_dir
      LOCATION ('emp_xt1.dmp', 'emp_xt2.dmp', 'emp_xt3.dmp')
    )                   
    PARALLEL 3          
    AS SELECT * FROM scott.emp;

比较数据:
SELECT * FROM scott.emp MINUS SELECT * FROM emp_xt_1;

SQL> SELECT * FROM scott.emp MINUS SELECT * FROM emp_xt_1;

no rows selected


2.基于oracle_loader的外部表

第一种创建办法:
EXAMPLE: Creating an External Table and Loading Data
The file empxt1.dat contains the following sample data:

360,Jane,Janus,ST_CLERK,121,17-MAY-2001,3000,0,50,jjanus
361,Mark,Jasper,SA_REP,145,17-MAY-2001,8000,.1,80,mjasper
362,Brenda,Starr,AD_ASST,200,17-MAY-2001,5500,0,10,bstarr
363,Alex,Alda,AC_MGR,145,17-MAY-2001,9000,.15,80,aalda

The file empxt2.dat contains the following sample data:

401,Jesse,Cromwell,HR_REP,203,17-MAY-2001,7000,0,40,jcromwel
402,Abby,Applegate,IT_PROG,103,17-MAY-2001,9000,.2,60,aapplega
403,Carol,Cousins,AD_VP,100,17-MAY-2001,27000,.3,90,ccousins
404,John,Richardson,AC_ACCOUNT,205,17-MAY-2001,5000,0,110,jrichard

建表语句如下:
CREATE TABLE ext_emply
                   (employee_id       NUMBER(4), 
                    first_name        VARCHAR2(20),
                    last_name         VARCHAR2(25), 
                    job_id            VARCHAR2(10),
                    manager_id        NUMBER(4),
                    hire_date         DATE,
                    salary            NUMBER(8,2),
                    commission_pct    NUMBER(2,2),
                    department_id     NUMBER(4),
                    email             VARCHAR2(25) 
                   ) 
     ORGANIZATION EXTERNAL 
     ( 
       TYPE ORACLE_LOADER 
       DEFAULT DIRECTORY ext_dir 
       ACCESS PARAMETERS 
       ( 
         records delimited by newline 
         fields terminated by ',' 
         optionally enclosed by '"'
         missing field values are null 
         ( employee_id, first_name, last_name, job_id, manager_id, 
           hire_date char date_format date mask "dd-mon-yyyy", 
           salary, commission_pct, department_id, email 
         ) 
       ) 
       LOCATION ('empxt1.dat') 
     )
     PARALLEL 
     REJECT LIMIT UNLIMITED; 

第二种创建方法,利用sql loader
(1)创建数据源文本
SQL> select empno||','||ename||','||job||','||mgr||','||hiredate||','||sal||','||comm||','||deptno from emp;

EMPNO||','||ENAME||','||JOB||','||MGR||','||HIREDATE||','||SAL||','||COMM||','||DEPTNO
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
7369,SMITH,CLERK,7902,17-DEC-80,800,,20
7499,ALLEN,SALESMAN,7698,20-FEB-81,1600,300,30
7521,WARD,SALESMAN,7698,22-FEB-81,1250,500,30
7566,JONES,MANAGER,7839,02-APR-81,2975,,20
7654,MARTIN,SALESMAN,7698,28-SEP-81,1250,1400,30
7698,BLAKE,MANAGER,7839,01-MAY-81,2850,,30
7782,CLARK,MANAGER,7839,09-JUN-81,2450,,10
7788,SCOTT,ANALYST,7566,19-APR-87,3000,,20
7839,KING,PRESIDENT,,17-NOV-81,5000,,10
7844,TURNER,SALESMAN,7698,08-SEP-81,1500,0,30
7876,ADAMS,CLERK,7788,23-MAY-87,1100,,20
7900,JAMES,CLERK,7698,03-DEC-81,950,,30
7902,FORD,ANALYST,7566,03-DEC-81,3000,,20
7934,MILLER,CLERK,7782,23-JAN-82,1300,,10


(2)建议语句

CREATE TABLE emp_ext2 (
    EMPNO NUMBER(4),
    ENAME VARCHAR2(10),
    JOB VARCHAR2(9),
    MGR NUMBER(4),
    HIREDATE DATE,
    SAL NUMBER(7,2),
    COMM NUMBER(7,2),
    DEPTNO NUMBER(2))
ORGANIZATION EXTERNAL 
 (TYPE ORACLE_LOADER DEFAULT DIRECTORY ext_dir
                      ACCESS PARAMETERS 
            (FIELDS TERMINATED BY ','
            optionally enclosed by '"'
            )
                      LOCATION ('ex_emp.txt')
  );
验证方法
select * from emp_ext2 minus select EMPNO,ENAME,JOB,MGR,HIREDATE,SAL,COMM,DEPTNO from emp;
SQL> select * from emp_ext2 minus select EMPNO,ENAME,JOB,MGR,HIREDATE,SAL,COMM,DEPTNO from emp;
no rows selected

第三种创建方式sql loder
1.数据库源
[oracle@oraserv outdata]$ vi emp2xt.dat 

7369,SMITH,CLERK,7902,17-DEC-80,800,,20
7499,ALLEN,SALESMAN,7698,20-FEB-81,1600,300,30
7521,WARD,SALESMAN,7698,22-FEB-81,1250,500,30
7566,JONES,MANAGER,7839,02-APR-81,2975,,20
7654,MARTIN,SALESMAN,7698,28-SEP-81,1250,1400,30
7698,BLAKE,MANAGER,7839,01-MAY-81,2850,,30
7782,CLARK,MANAGER,7839,09-JUN-81,2450,,10
7788,SCOTT,ANALYST,7566,19-APR-87,3000,,20
7839,KING,PRESIDENT,,17-NOV-81,5000,,10
7844,TURNER,SALESMAN,7698,08-SEP-81,1500,0,30
7876,ADAMS,CLERK,7788,23-MAY-87,1100,,20
7900,JAMES,CLERK,7698,03-DEC-81,950,,30
7902,FORD,ANALYST,7566,03-DEC-81,3000,,20
7934,MILLER,CLERK,7782,23-JAN-82,1300,,10

2.sql loader的控制文件emp2xt.ctl

load data
CHARACTERSET ZHS16GBK
infile './emp2xt.dat'
Append into table emp2xt
fields terminated by ','
optionally enclosed by '"'
trailing nullcols
   (EMPNO,
        ENAME,
        JOB,
        MGR,
        HIREDATE DATE "DD-MM-YY" NULLIF (HIREDATE="NULL"),
        SAL,
        COMM,
        DEPTNO
        )

3.使用SQLLDR的“external_table=generate_only”参数生成外部表创建语句
sqlldr test/test control=emp2xt.ctl external_table=generate_only

[oracle@oraserv outdata]$ cat emp2xt.log

SQL*Loader: Release 10.2.0.1.0 - Production on Sat Jan 26 20:16:38 2013

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

Control File:   emp2xt.ctl
Character Set ZHS16GBK specified for all input.

Data File:      ./emp2xt.dat
  Bad File:     emp2xt.bad
  Discard File:  none specified
 
 (Allow all discards)

Number to load: ALL
Number to skip: 0
Errors allowed: 50
Continuation:    none specified
Path used:      External Table

Table EMP2XT, loaded from every logical record.
Insert option in effect for this table: APPEND
TRAILING NULLCOLS option in effect

   Column Name                  Position   Len  Term Encl Datatype
------------------------------ ---------- ----- ---- ---- ---------------------
EMPNO                               FIRST     *   ,  O(") CHARACTER            
ENAME                                NEXT     *   ,  O(") CHARACTER            
JOB                                  NEXT     *   ,  O(") CHARACTER            
MGR                                  NEXT     *   ,  O(") CHARACTER            
HIREDATE                             NEXT     *   ,  O(") DATE DD-MM-YY        
    NULL if HIREDATE = 0X4e554c4c(character 'NULL')
SAL                                  NEXT     *   ,  O(") CHARACTER            
COMM                                 NEXT     *   ,  O(") CHARACTER            
DEPTNO                               NEXT     *   ,  O(") CHARACTER            



CREATE DIRECTORY statements needed for files
------------------------------------------------------------------------
CREATE DIRECTORY SYS_SQLLDR_XT_TMPDIR_00000 AS './'


CREATE TABLE statement for external table:
------------------------------------------------------------------------
CREATE TABLE "SYS_SQLLDR_X_EXT_EMP2XT" 
(
  "EMPNO" NUMBER(4),
  "ENAME" VARCHAR2(10),
  "JOB" VARCHAR2(9),
  "MGR" NUMBER(4),
  "HIREDATE" DATE,
  "SAL" NUMBER(7,2),
  "COMM" NUMBER(7,2),
  "DEPTNO" NUMBER(2)
)
ORGANIZATION external 
(
  TYPE oracle_loader
  DEFAULT DIRECTORY SYS_SQLLDR_XT_TMPDIR_00000
  ACCESS PARAMETERS 
  (
    RECORDS DELIMITED BY NEWLINE CHARACTERSET ZHS16GBK
    BADFILE 'EXT_DIR':'emp2xt.bad'
    LOGFILE 'emp2xt.log_xt'
    READSIZE 1048576
    FIELDS TERMINATED BY "," OPTIONALLY ENCLOSED BY '"' LDRTRIM 
    MISSING FIELD VALUES ARE NULL 
    REJECT ROWS WITH ALL NULL FIELDS 
    (
      "EMPNO" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "ENAME" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "JOB" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "MGR" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "HIREDATE" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"'
        DATE_FORMAT DATE MASK "DD-MM-YY"
        NULLIF ("HIREDATE" = "NULL"),
      "SAL" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "COMM" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "DEPTNO" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"'
    )
  )
  location 
  (
    'emp2xt.dat'
  )
)REJECT LIMIT UNLIMITED


INSERT statements used to load internal tables:
------------------------------------------------------------------------
INSERT /*+ append */ INTO EMP2XT 
(
  EMPNO,
  ENAME,
  JOB,
  MGR,
  HIREDATE,
  SAL,
  COMM,
  DEPTNO
)
SELECT 
  "EMPNO",
  "ENAME",
  "JOB",
  "MGR",
  "HIREDATE",
  "SAL",
  "COMM",
  "DEPTNO"
FROM "SYS_SQLLDR_X_EXT_EMP2XT"


statements to cleanup objects created by previous statements:
------------------------------------------------------------------------
DROP TABLE "SYS_SQLLDR_X_EXT_EMP2XT"
DROP DIRECTORY SYS_SQLLDR_XT_TMPDIR_00000



Run began on Sat Jan 26 20:16:38 2013
Run ended on Sat Jan 26 20:16:38 2013

Elapsed time was:     00:00:00.26
CPU time was:         00:00:00.12



CREATE TABLE emp2xt_xt
(
  "EMPNO" NUMBER(4),
  "ENAME" VARCHAR2(10),
  "JOB" VARCHAR2(9),
  "MGR" NUMBER(4),
  "HIREDATE" DATE,
  "SAL" NUMBER(7,2),
  "COMM" NUMBER(7,2),
  "DEPTNO" NUMBER(2)
)
ORGANIZATION external 
(
  TYPE oracle_loader
  DEFAULT DIRECTORY ext_dir
  ACCESS PARAMETERS 
  (
    RECORDS DELIMITED BY NEWLINE CHARACTERSET ZHS16GBK
    FIELDS TERMINATED BY "," OPTIONALLY ENCLOSED BY '"' LDRTRIM 
    MISSING FIELD VALUES ARE NULL 
    REJECT ROWS WITH ALL NULL FIELDS 
    (
      "EMPNO" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "ENAME" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "JOB" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "MGR" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "HIREDATE" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"'
        DATE_FORMAT DATE MASK "DD-MM-YY"
        NULLIF ("HIREDATE" = "NULL"),
      "SAL" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "COMM" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"',
      "DEPTNO" CHAR(255)
        TERMINATED BY "," OPTIONALLY ENCLOSED BY '"'
    )
  )
  location 
  (
    'emp2xt.dat'
  )
)REJECT LIMIT UNLIMITED;

验证外部表数据
SQL> select * from emp2xt_xt;

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 19-APR-87       3000                    20
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500          0         30
      7876 ADAMS      CLERK           7788 23-MAY-87       1100                    20

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10

14 rows selected.




3.从外部表到oracle表加载数据

1.创建内部表或者加载数据
create table employee as select * from ext_emply where 1=2;


2.insert into
SQL> insert into employee select * from ext_emply where EMPLOYEE_ID <=400;

5 rows created.
4.
select * from DBA_EXTERNAL_TABLES ;
select * from DBA_EXTERNAL_LOCATIONS ;

SQL> select OWNER,TABLE_NAME,TYPE_OWNER,TYPE_NAME,DEFAULT_DIRECTORY_NAME from DBA_EXTERNAL_TABLES;

OWNER                          TABLE_NAME                     TYP TYPE_NAME                     DEFAULT_DIRECTORY_NAME
------------------------------ ------------------------------ --- ------------------------------ ----------------
TEST                           EMP_XT                         SYS ORACLE_DATAPUMP                EXT_DIR

SQL> col LOCATION format a50
SQL> select * from DBA_EXTERNAL_LOCATIONS

OWNER      TABLE_NAME                     LOCATION                                           DIR DIRECTORY_NAME
---------- ------------------------------ -------------------------------------------------- --- ------------------------------
TEST       EMP_XT                         emp_xt.dmp                                         SYS EXT_DIR

---The end

阅读(3676) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~