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 provides a demonstration of how to load data into different LOB columns using only SQL. It is possible to insert data directly into LOB columns up to 4K. Even though you are only accessing the locator, the data is stored as appropriate behind the scenes. When inserting directly into a BLOB, either the string must be a hex as an implicit HEXTORAW will be done or you can call UTL_RAW.CAST_TO_RAW('your string') to convert it for you. Note that '48656C6C6F' = 'Hello'.

After inserting data into our test_lob table, we can select it back (with the exception of the BFILE column). When SELECTing using SQL*Plus, that we are only fetching the LOB locator. SQL*Plus will also then fetch the corresponding data. If we were to use a 3GL or PL/SQL, we can insert data from a character string (like in our example), but not select it back like we can do within SQL*Plus.

Example


DROP TABLE test_bfile CASCADE CONSTRAINTS / Table dropped. CREATE TABLE test_lob ( id NUMBER(15) , clob_field CLOB , blob_field BLOB , bfile_field BFILE ) / Table created. CREATE OR REPLACE DIRECTORY EXAMPLE_LOB_DIR AS '/u04/app/oracle/oralobfiles' / Directory created. INSERT INTO test_lob VALUES ( 1001 , 'Some data for record 1001' , '48656C6C6F' || UTL_RAW.CAST_TO_RAW(' there!') , BFILENAME('EXAMPLE_LOB_DIR', 'file1.txt') ); 1 row created. COMMIT; Commit complete. SELECT id , clob_field "Clob" , UTL_RAW.CAST_TO_VARCHAR2(blob_field) "Blob" FROM test_lob; Id Clob Blob ---- ------------------------- ------------- 1001 Some data for record 1001 Hello there!

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
Wednesday, 14-Mar-2012 19:57:24 EDT
Page Count: 8935