Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: Populating BLOB's from a SQL Script? - Solution

Re: Populating BLOB's from a SQL Script? - Solution

From: <Jared.Still_at_radisys.com>
Date: Thu, 09 Oct 2003 10:39:24 -0800
Message-ID: <F001.005D2941.20031009103924@fatcity.com>


Mark,

I didn't fully understand you're earlier post, but now it seems that the sqlunldr.pl script in the PDBA toolkit may do what you want.

http://www.oreilly.com/catalog/oracleperl/pdbatoolkit/

It will dump blobs to hex in a sqlldr compatible file, along with the control and parameters script to reload with sqlldr.

HTH Jared

"Mark Richard" <mrichard_at_transurban.com.au> Sent by: ml-errors_at_fatcity.com
 10/08/2003 08:09 PM
 Please respond to ORACLE-L  

        To:     Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com>
        cc: 
        Subject:        Re: Populating BLOB's from a SQL Script? - Solution



Ok, I got no suggestions but have found a rather clunky way to achieve this:

Assuming a blob exists in a table somewhere then a statement like "select dbms_lob.substr(data, 1000, 1) from table" can be used to retrieve 1000 bytes worth of data as hex.

For a new field a simple "insert into table (data) values (hextoraw('the_hex_returned_above'));" statement will insert the data in it's original form.

To work with BLOB's larger than 1K a looping process is required. The easiest way I've found to append data is a small pl/sql block:

declare

      new_data blob;
begin

      select data into new_data from table for update;
      dbms_lob.writeappend(new_data, <offset>,
hextoraw('the_hex_returned'));
end;

So, to summarise. It's possible to convert BLOB's to hex, place the results into a basic sql script and have then reloaded into a table. Unfortunately you can only work on 1K of data at a time but a simple program to generate the sql would overcome this problem. Net result = you can deliver binary data via sql scripts would too much hassle.

Hopefully this helps somebody out there.

Regards,

      Mark.   

                      "Mark Richard"   
                      <mrichard_at_transur        To:       Multiple 
recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> 
                      ban.com.au>              cc:    
                      Sent by:                 Subject:  Populating BLOB's 
from a SQL Script? 
                      ml-errors_at_fatcity   
                      .com   
  
  
                      07/10/2003 12:04   
                      Please respond to   
                      ORACLE-L   
  
  





Hi List,

I have been asked to look into the possibility of populating a BLOB column (Oracle 8i currently) using an SQL Script. All the examples I've ever seen
involve reading the blob from a file and inserting it directly to the table
though.

The reasoning behind this is the desire to deliver a single script which loads perhaps 50 images into a table. Performance isn't a problem, neither
is the size of the script.

Does anyone know of a way to do this? It is safe to assume the data already exists in a table if that helps to create the script. I was thinking perhaps a "rawtohex" type function may convert the binary data into something that can exist within a script. Am I on the right track?

Regards,

      Mark.

<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>

   Privileged/Confidential information may be contained in this message.

          If you are not the addressee indicated in this message
       (or responsible for delivery of the message to such person),
            you may not copy or deliver this message to anyone.
In such case, you should destroy this message and kindly notify the sender
           by reply e-mail or by telephone on (61 3) 9612-6999.
   Please advise immediately if you or your employer does not consent to
                Internet e-mail for messages of this kind.
        Opinions, conclusions and other information in this message
              that do not relate to the official business of
                         Transurban City Link Ltd
         shall be understood as neither given nor endorsed by it.
<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>





<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>

Privileged/Confidential information may be contained in this message. If you are not the addressee indicated in this message (or responsible for delivery of the message to such person), you may not copy or deliver this message to anyone.
In such a case, you should destroy this message and kindly notify the sender by reply e-mail or by telephone on (03) 9612-6999 or (61) 3 9612-6999.
Please advise immediately if you or your employer does not consent to Internet e-mail for messages of this kind. Opinions, conclusions and other information in this message that do not relate to the official business of Transurban Infrastructure Developments Limited and CityLink Melbourne Limited shall be understood as neither given
nor endorsed by them.

<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>


--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Mark Richard
  INET: mrichard_at_transurban.com.au

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).




<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>
Privileged/Confidential information may be contained in this message. If you are not the addressee indicated in this message (or responsible for delivery of the message to such person), you may not copy or deliver this message to anyone. In such case, you should destroy this message and kindly notify the sender by reply e-mail or by telephone on (61 3) 9612-6999. Please advise immediately if you or your employer does not consent to Internet e-mail for messages of this kind. Opinions, conclusions and other information in this message that do not relate to the official business of Transurban City Link Ltd shall be understood as neither given nor endorsed by it. <<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>> <<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>> Privileged/Confidential information may be contained in this message. If you are not the addressee indicated in this message (or responsible for delivery of the message to such person), you may not copy or deliver this message to anyone. In such a case, you should destroy this message and kindly notify the sender by reply e-mail or by telephone on (03) 9612-6999 or (61) 3 9612-6999. Please advise immediately if you or your employer does not consent to Internet e-mail for messages of this kind. Opinions, conclusions and other information in this message that do not relate to the official business of Transurban Infrastructure Developments Limited and CityLink Melbourne Limited shall be understood as neither given nor endorsed by them. <<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>> -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Mark Richard INET: mrichard_at_transurban.com.au Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: INET: Jared.Still_at_radisys.com Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).
Received on Thu Oct 09 2003 - 13:39:24 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US