DBA Tips Archive for Oracle

  


[an error occurred while processing this directive]

No Title

[an error occurred while processing this directive]

by Michael New, MichaelNew@earthlink.net, Gradation LLC

Contents

Introduction

The following example is part of the Oracle LOB Examples Collection.

This example demonstrates how to populate a BLOB column with a a list of binary (image) files.

Prior to Oracle 8i, LOBs were loaded into the database via direct SQL DML, OCI, and PL/SQL DBMS_LOB APIs. Now, SQL*Loader can be used to load these data types.

Example

Create a table used to store the data and BLOB (image).


DROP TABLE test_blob CASCADE CONSTRAINTS / Table dropped. CREATE TABLE test_blob ( id NUMBER(15) , username VARCHAR2(30) , file_name VARCHAR2(1000) , image BLOB , timestamp DATE ) / Table created. CREATE OR REPLACE DIRECTORY EXAMPLE_LOB_DIR AS '/u04/app/oracle/lobs' / Directory created.

Download several binary images files and put them in the same directory as the SQL*Loader control file.

  scsi_se.gif
  scsi_hvd_diff.gif
  scsi_lvd.gif
  scsi_lvd_se.gif

Next, generate a SQL*Loader control file that can be used to load all data and binary image files.

load_test_blob_data.ctl


load data infile * replace into table test_blob FIELDS TERMINATED BY ',' ( id INTEGER external , username CHAR , file_name CHAR , image LOBFILE(file_name) TERMINATED BY EOF NULLIF file_name='NONE' , timestamp SYSDATE ) begindata 1,JHUNTER,scsi_se.gif 2,MHUNTER,scsi_hvd_diff.gif 3,AHUNTER,scsi_lvd.gif 4,AHUNTER,scsi_lvd_se.gif

Finally, generate a PL/SQL procedure that can be used to dump all binary images from the BLOB column to the disk.

write_blob_to_file.sql


CREATE OR REPLACE PROCEDURE "WRITE_BLOB_TO_FILE" AS -- +----------------------------------------------------+ -- | PROGRAM VARIABLES | -- +----------------------------------------------------+ v_out_outdir VARCHAR2(2000) := 'EXAMPLE_LOB_DIR'; v_out_filename VARCHAR2(500); v_out_filename_ext VARCHAR2(4) := '.out'; v_out_filename_full VARCHAR2(500); v_file_count NUMBER := 0; v_file_handle UTL_FILE.FILE_TYPE; -- +----------------------------------------------------+ -- | DYNAMIC SQL VARIABLES | -- +----------------------------------------------------+ TYPE v_lob_cur_typ IS REF CURSOR; v_lob_cur v_lob_cur_typ; v_sql_string VARCHAR2(4000); -- +----------------------------------------------------+ -- | BLOB WRITE VARIABLES | -- +----------------------------------------------------+ v_blob_loc BLOB; v_buffer RAW(32767); v_buffer_size CONSTANT BINARY_INTEGER := 32767; v_amount BINARY_INTEGER; v_offset NUMBER(38); -- +----------------------------------------------------+ -- | EXCEPTIONS | -- +----------------------------------------------------+ invalid_directory_path EXCEPTION; PRAGMA EXCEPTION_INIT(invalid_directory_path, -29280); table_does_not_exist EXCEPTION; PRAGMA EXCEPTION_INIT(table_does_not_exist, -00942); invalid_identifier EXCEPTION; PRAGMA EXCEPTION_INIT(invalid_identifier, -00904); SQL_cmd_not_prop_ended EXCEPTION; PRAGMA EXCEPTION_INIT(SQL_cmd_not_prop_ended, -00933); BEGIN -- +----------------------------------------------------+ -- | ENABLE SERVER-SIDE OUTPUT | -- +----------------------------------------------------+ DBMS_OUTPUT.ENABLE(1000000); v_sql_string := 'SELECT file_name, image FROM scott.test_blob'; OPEN v_lob_cur FOR v_sql_string; LOOP FETCH v_lob_cur INTO v_out_filename, v_blob_loc; EXIT WHEN v_lob_cur%NOTFOUND; v_file_count := v_file_count + 1; v_out_filename_full := v_out_filename || v_out_filename_ext; v_file_handle := UTL_FILE.FOPEN(v_out_outdir, v_out_filename_full, 'wb', 32767); v_amount := v_buffer_size; v_offset := 1; DECLARE invalid_LOB_locator EXCEPTION; PRAGMA EXCEPTION_INIT(invalid_LOB_locator, -06502); BEGIN WHILE v_amount >= v_buffer_size LOOP DBMS_LOB.READ( lob_loc => v_blob_loc, amount => v_amount, offset => v_offset, buffer => v_buffer); v_offset := v_offset + v_amount; UTL_FILE.PUT_RAW( file => v_file_handle, buffer => v_buffer, autoflush => true); UTL_FILE.FFLUSH(file => v_file_handle); END LOOP; EXCEPTION WHEN invalid_LOB_locator THEN UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '+----------------------------+'); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '| *** ERROR *** |'); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '+----------------------------+'); UTL_FILE.NEW_LINE(file => v_file_handle); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => 'Invalid LOB Locator Exception for :'); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '==================================='); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => ' --> ' || v_out_filename); UTL_FILE.NEW_LINE(file => v_file_handle); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => 'SQL Text:'); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '==================================='); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => ' --> ' || v_sql_string); UTL_FILE.FFLUSH(file => v_file_handle); WHEN others THEN UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '+----------------------------+'); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '| *** ERROR *** |'); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '+----------------------------+'); UTL_FILE.NEW_LINE(file => v_file_handle); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => 'WHEN OTHERS ERROR'); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => '================='); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => ' --> SQL CODE : ' || SQLCODE); UTL_FILE.PUT_LINE(file => v_file_handle, buffer => ' --> SQL ERROR MESSAGE : ' || SQLERRM); UTL_FILE.FFLUSH(file => v_file_handle); END; UTL_FILE.FCLOSE(v_file_handle); END LOOP; CLOSE v_lob_cur; DBMS_OUTPUT.PUT_LINE('Wrote out ' || v_file_count || ' file(s) to ' || v_out_outdir || '.'); EXCEPTION WHEN invalid_directory_path THEN DBMS_OUTPUT.PUT_LINE('** ERROR ** : Invalid Directory Path: ' || v_out_outdir); WHEN table_does_not_exist THEN DBMS_OUTPUT.PUT_LINE('** ERROR ** : Table Not Found.'); DBMS_OUTPUT.PUT_LINE('--> SQL: ' || v_sql_string); WHEN invalid_identifier THEN DBMS_OUTPUT.PUT_LINE('** ERROR ** : Invalid Identifier.'); DBMS_OUTPUT.PUT_LINE('--> SQL: ' || v_sql_string); WHEN SQL_cmd_not_prop_ended THEN DBMS_OUTPUT.PUT_LINE('** ERROR ** : SQL command not properly ended.'); DBMS_OUTPUT.PUT_LINE('--> SQL: ' || v_sql_string); END; /


SQL> @write_blob_to_file.sql Procedure created.

Test


[oracle@racnode1 ~]$ cd /u04/app/oracle/lobs [oracle@racnode1 lobs]$ sqlldr userid=scott/tiger control=load_test_blob_data.ctl log=load_test_blob_data.log SQL*Loader: Release 11.2.0.3.0 - Production on Mon Aug 3 00:54:21 2009 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. Commit point reached - logical record count 4 [oracle@racnode1 lobs]$ sqlplus scott/tiger SQL> SELECT id, username, file_name, DBMS_LOB.GETLENGTH(image) Length, timestamp FROM test_blob ORDER BY id; ID USERNAME FILE_NAME LENGTH TIMESTAMP ---------- ---------- ------------------------- ---------- -------------------- 1 JHUNTER scsi_se.gif 4200 14-MAR=2012 20:26:03 2 MHUNTER scsi_hvd_diff.gif 5041 14-MAR=2012 20:26:03 3 AHUNTER scsi_lvd.gif 3505 14-MAR=2012 20:26:03 4 AHUNTER scsi_lvd_se.gif 4279 14-MAR=2012 20:26:03 SQL> EXEC write_blob_to_file PL/SQL procedure successfully completed. SQL> exit [oracle@racnode1 lobs]$ ls -l /u04/app/oracle/lobs/*.gif -rw-r--r-- 1 oracle oinstall 5041 Mar 14 20:28 /u04/app/oracle/lobs/scsi_hvd_diff.gif -rw-r--r-- 1 oracle oinstall 3505 Mar 14 20:28 /u04/app/oracle/lobs/scsi_lvd.gif -rw-r--r-- 1 oracle oinstall 4279 Mar 14 20:28 /u04/app/oracle/lobs/scsi_lvd_se.gif -rw-r--r-- 1 oracle oinstall 4200 Mar 14 20:28 /u04/app/oracle/lobs/scsi_se.gif [oracle@racnode1 lobs]$ ls -l /u04/app/oracle/lobs/*.out -rw-r--r-- 1 oracle asmadmin 5041 Mar 14 20:28 /u04/app/oracle/lobs/scsi_hvd_diff.gif.out -rw-r--r-- 1 oracle asmadmin 3505 Mar 14 20:28 /u04/app/oracle/lobs/scsi_lvd.gif.out -rw-r--r-- 1 oracle asmadmin 4279 Mar 14 20:28 /u04/app/oracle/lobs/scsi_lvd_se.gif.out -rw-r--r-- 1 oracle asmadmin 4200 Mar 14 20:28 /u04/app/oracle/lobs/scsi_se.gif.out

 

If you notice that the newly created files, *.out are 1 byte larger than the original, then read my article entitled CR/LF Added to Binary File When Using UTL_FILE.PUT_RAW for an explanation on why this happens and for the workaround.

Another SQL*Loader Control File

Notice that in the above example, we included not only the binary image file in a BLOB column, but we also included the file name of the file. This is often good practice. I came across a situation, however, where the file name was not to be stored within the table with the BLOB.

Consider the following example.


DROP TABLE test_blob CASCADE CONSTRAINTS / Table dropped. CREATE TABLE test_blob ( id NUMBER(15) , username VARCHAR2(30) , image BLOB , timestamp DATE ) / Table created.

When we constructed the SQL*Loader control file for the table in this article that DID include the file name, we simply used the same file_name column that we were loading into the table as a parameter to the LOBFILE() procedure. But like I just mentioned, what if we were not loading the file_name column? We need a place holder or the ability to define a dummy variable in the SQL*Loader control file for the text of the file name. We could then use that dummy variable as an argument the the LOBFILE() procedure. We can use the keyword FILLER to create this place holder variable. The following SQL*Loader file could be used for this type of situation.

load_test_blob_data.ctl


load data infile * replace into table test_blob FIELDS TERMINATED BY ',' ( id INTEGER external , username CHAR , ext_file_name FILLER CHAR , image LOBFILE(ext_file_name) TERMINATED BY EOF NULLIF ext_file_name='NONE' , timestamp SYSDATE ) begindata 1,JHUNTER,scsi_se.gif 2,MHUNTER,scsi_hvd_diff.gif 3,AHUNTER,scsi_lvd.gif 4,AHUNTER,scsi_lvd_se.gif

Now, let's check to see if this works:


[oracle@racnode1 lobs]$ sqlldr userid=scott/tiger control=load_test_blob_data.ctl log=load_test_blob_data.log SQL*Loader: Release 11.2.0.3.0 - Production on Wed Mar 14 20:32:33 2012 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. Commit point reached - logical record count 4 [oracle@racnode1 ~]$ sqlplus scott/tiger SQL> SELECT id, username, DBMS_LOB.GETLENGTH(image) Length, timestamp FROM test_blob; ID USERNAME LENGTH TIMESTAMP ---------- ---------- ---------- -------------------- 1 JHUNTER 4200 14-MAR-2012 20:32:33 2 MHUNTER 5041 14-MAR-2012 20:32:33 3 AHUNTER 3505 14-MAR-2012 20:32:33 4 AHUNTER 4279 14-MAR-2012 20:32:33

About the Author

Jeffrey Hunter is an Oracle Certified Professional, Java Development Certified Professional, Author, and an Oracle ACE. Jeff currently works as a Senior Database Administrator for The DBA Zone, Inc. located in Pittsburgh, Pennsylvania. His work includes advanced performance tuning, Java and PL/SQL programming, developing high availability solutions, capacity planning, database security, and physical / logical database design in a UNIX / Linux server environment. Jeff's other interests include mathematical encryption theory, tutoring advanced mathematics, programming language processors (compilers and interpreters) in Java and C, LDAP, writing web-based database administration tools, and of course Linux. He has been a Sr. Database Administrator and Software Engineer for over 20 years and maintains his own website site at: http://www.iDevelopment.info. Jeff graduated from Stanislaus State University in Turlock, California, with a Bachelor's degree in Computer Science and Mathematics.



Copyright (c) 1998-2017 Jeffrey M. Hunter. All rights reserved.

All articles, scripts and material located at the Internet address of http://www.idevelopment.info is the copyright of Jeffrey M. Hunter and is protected under copyright laws of the United States. This document may not be hosted on any other site without my express, prior, written permission. Application to host any of the material elsewhere can be made by contacting me at jhunter@idevelopment.info.

I have made every effort and taken great care in making sure that the material included on my web site is technically accurate, but I disclaim any and all responsibility for any loss, damage or destruction of data or any other property which may arise from relying on it. I will in no case be liable for any monetary damages arising from such loss, damage or destruction.

Last modified on
Thursday, 15-Mar-2012 09:47:18 EDT
Page Count: 28692