2
1

Delete article

Deleted articles cannot be recovered.

Draft of this article would be also deleted.

Are you sure you want to delete this article?

More than 5 years have passed since last update.

DBMS_LOB.LOADCLOBFROMFILEプロシージャを使ってテキストファイルを Oracle Database の CLOB型列 に ロードする。

Last updated at Posted at 2016-08-15

表題の通り、DBMS_LOB.LOADCLOBFROMFILEプロシージャ で
テキストファイル を CLOB型列 に ロードするやで彡(゚)(゚)

まずCLOB型の列を持つテーブルとディレクトリ・オブジェクトを作ります。

CONNECT AYSHIBAT/xxxxxxxx
CREATE TABLE TEST_CLOB (
    C1 NUMBER
  , C2 CLOB
);
ALTER TABLE TEST_CLOB ADD CONSTRAINT TEST_CLOB_PK PRIMARY KEY(C1) USING INDEX;

CONNECT /AS SYSDBA
CREATE DIRECTORY DIR_AYSHIBAT as '/home/oracle/work/ayshibat';
GRANT READ, WRITE ON DIRECTORY DIR_AYSHIBAT TO AYSHIBAT;

テキストファイルをディレクトリ・オブジェクトのパスに置きます。

$ pwd
/home/oracle/work/ayshibat
$ ls -la
total 112
drwxr-xr-x 2 oracle oinstall   4096 Aug 15 11:49 .
drwxr-xr-x 3 oracle oinstall   4096 Aug 15 11:45 ..
-rw-r--r-- 1 oracle oinstall 102000 Aug 15 11:47 test_clob_data.txt
$

件数が無いのを確認して、DBMS_LOB.LOADCLOBFROMFILEプロシージャでテキストファイルをCLOB型列に流し込むと……

SELECT C1, DBMS_LOB.GETLENGTH(C2) FROM TEST_CLOB;

no rows selected

DECLARE
  bfile_p  BFILE;       -- BFILE pointer
  clob_loc CLOB;        -- CLOB locator
  n_c1     NUMBER;      -- TEST_CLOB Column C1
  n_doffs  NUMBER := 1; -- dest_offset
  n_soffs  NUMBER := 1; -- src_offset
  n_lctx   NUMBER := 0; -- lang_context
  n_warn   NUMBER;      -- warning
BEGIN
  -- BFILE pointer set
  bfile_p := BFILENAME('DIR_AYSHIBAT', 'test_clob_data.txt');
  -- Insert record and CLOB locator get
  SELECT NVL(MAX(C1), 0) + 1 INTO n_c1 FROM TEST_CLOB;
  INSERT INTO TEST_CLOB VALUES (n_c1, EMPTY_CLOB())
  RETURNING C2 INTO clob_loc;
  -- File open
  DBMS_LOB.FILEOPEN(bfile_p, DBMS_LOB.FILE_READONLY);
  -- LOAD CLOB from text file
  DBMS_LOB.LOADCLOBFROMFILE(
      clob_loc                   -- CLOB locator
    , bfile_p                    -- BFILE pointer
    , DBMS_LOB.LOBMAXSIZE        -- amount
    , n_doffs                    -- dest_offset
    , n_soffs                    -- src_offset
    , NLS_CHARSET_ID('AL32UTF8') -- BFILE Characterset ID
    , n_lctx                     -- lang_context
    , n_warn                     -- warning
  );
  COMMIT;
  -- File close
  DBMS_LOB.FILECLOSE(bfile_p);
END;
/

PL/SQL procedure successfully completed.

件数とバイト数を確認すると、上手く行ったやで彡(^)(^)

SELECT C1, DBMS_LOB.GETLENGTH(C2) FROM TEST_CLOB;

        C1 DBMS_LOB.GETLENGTH(C2)
---------- ----------------------
         1                 102000

マニュアル類(※11gR2版)は下記やで彡(゚)(゚)

DBMS_LOBパッケージ
LOADCLOBFROMFILEプロシージャ
http://docs.oracle.com/cd/E16338_01/appdev.112/b56262/d_lob.htm#i998978

SQL言語リファレンス
BFILENAME
http://docs.oracle.com/cd/E16338_01/server.112/b56299/functions019.htm#i76871

SQL言語リファレンス
EMPTY_BLOB、EMPTY_CLOB
http://docs.oracle.com/cd/E16338_01/server.112/b56299/functions056.htm#i77384

SQL言語リファレンス
NLS_CHARSET_ID
http://docs.oracle.com/cd/E16338_01/server.112/b56299/functions108.htm#i78230

2
1
0

Register as a new user and use Qiita more conveniently

  1. You get articles that match your needs
  2. You can efficiently read back useful information
  3. You can use dark theme
What you can do with signing up
2
1

Delete article

Deleted articles cannot be recovered.

Draft of this article would be also deleted.

Are you sure you want to delete this article?