Oracle 8i | Oracle 9i | Oracle 10g | Oracle 11g | Oracle 12c | Miscellaneous | PL/SQL | SQL | Oracle RAC | Oracle Apps | Linux

Retrieving HTML and Binaries into Tables Over HTTP

This article gives two brief examples of how HTML pages and Binaries, such as images or documents, can be downloaded over HTTP and placed directly into tables. The code in this article uses two approaches. The first uses the UTL_HTTP and DBMS_LOB packages, while the second uses the HTTPURITYPE to achieve this.

HTML to CLOB

First we create a table to populate.

CREATE TABLE http_clob_test (
  id    NUMBER(10),
  url   VARCHAR2(255),
  data  CLOB,
  CONSTRAINT http_clob_test_pk PRIMARY KEY (id)
);

CREATE SEQUENCE http_clob_test_seq;

Next we create a procedure to retrieve and store the HTML data.

CREATE OR REPLACE PROCEDURE load_html_from_url (p_url  IN  VARCHAR2) AS
  l_http_request   UTL_HTTP.req;
  l_http_response  UTL_HTTP.resp;
  l_clob           CLOB;
  l_text           VARCHAR2(32767);
BEGIN
  -- Initialize the CLOB.
  DBMS_LOB.createtemporary(l_clob, FALSE);

  -- Make a HTTP request and get the response.
  l_http_request  := UTL_HTTP.begin_request(p_url);
  l_http_response := UTL_HTTP.get_response(l_http_request);

  -- Copy the response into the CLOB.
  BEGIN
    LOOP
      UTL_HTTP.read_text(l_http_response, l_text, 32766);
      DBMS_LOB.writeappend (l_clob, LENGTH(l_text), l_text);
    END LOOP;
  EXCEPTION
    WHEN UTL_HTTP.end_of_body THEN
      UTL_HTTP.end_response(l_http_response);
  END;

  -- Insert the data into the table.
  INSERT INTO http_clob_test (id, url, data)
  VALUES (http_clob_test_seq.NEXTVAL, p_url, l_clob);

  -- Relase the resources associated with the temporary LOB.
  DBMS_LOB.freetemporary(l_clob);
EXCEPTION
  WHEN OTHERS THEN
    UTL_HTTP.end_response(l_http_response);
    DBMS_LOB.freetemporary(l_clob);
    RAISE;
END load_html_from_url;
/

Finally we run the procedure with a suitable URL.

EXEC load_html_from_url('http://localhost/');

PL/SQL procedure successfully completed.

COLUMN url FORMAT A30
SELECT id,
       url,
       DBMS_LOB.getlength(data) AS length
FROM   http_clob_test;

        ID URL                                LENGTH
---------- ------------------------------ ----------
         1 http://localhost/                    1494

1 row selected.

SQL>

Binary to BLOB

First we create a table to populate.

CREATE TABLE http_blob_test (
  id    NUMBER(10),
  url   VARCHAR2(255),
  data  BLOB,
  CONSTRAINT http_blob_test_pk PRIMARY KEY (id)
);

CREATE SEQUENCE http_blob_test_seq;

Next we create a procedure to retrieve and store the binary data.

CREATE OR REPLACE PROCEDURE load_binary_from_url (p_url  IN  VARCHAR2) AS
  l_http_request   UTL_HTTP.req;
  l_http_response  UTL_HTTP.resp;
  l_blob           BLOB;
  l_raw            RAW(32767);
BEGIN
  -- Initialize the BLOB.
  DBMS_LOB.createtemporary(l_blob, FALSE);

  -- Make a HTTP request and get the response.
  l_http_request  := UTL_HTTP.begin_request(p_url);
  l_http_response := UTL_HTTP.get_response(l_http_request);

  -- Copy the response into the BLOB.
  BEGIN
    LOOP
      UTL_HTTP.read_raw(l_http_response, l_raw, 32766);
      DBMS_LOB.writeappend (l_blob, UTL_RAW.length(l_raw), l_raw);
    END LOOP;
  EXCEPTION
    WHEN UTL_HTTP.end_of_body THEN
      UTL_HTTP.end_response(l_http_response);
  END;

  -- Insert the data into the table.
  INSERT INTO http_blob_test (id, url, data)
  VALUES (http_blob_test_seq.NEXTVAL, p_url, l_blob);

  -- Relase the resources associated with the temporary LOB.
  DBMS_LOB.freetemporary(l_blob);
EXCEPTION
  WHEN OTHERS THEN
    UTL_HTTP.end_response(l_http_response);
    DBMS_LOB.freetemporary(l_blob);
    RAISE;
END load_binary_from_url;
/

Finally we run the procedure with a suitable URL.

EXEC load_binary_from_url('http://localhost/apache_pb.gif');

PL/SQL procedure successfully completed.

COLUMN url FORMAT A30
SELECT id,
       url,
       DBMS_LOB.getlength(data) AS length
FROM   http_blob_test;

        ID URL                                LENGTH
---------- ------------------------------ ----------
         1 http://localhost/apache_pb.gif       2326

1 row selected.

SQL>

HTTPURITYPE

The HTTPURITYPE does most of the hard work for us, as shown in these examples. First the CLOB.

CREATE OR REPLACE PROCEDURE load_html_from_url (p_url  IN  VARCHAR2) AS
  l_clob           CLOB;
BEGIN
  l_clob := HTTPURITYPE.createuri(p_url).getclob();

  -- Insert the data into the table.
  INSERT INTO http_clob_test (id, url, data)
  VALUES (http_clob_test_seq.NEXTVAL, p_url, l_clob);

END load_html_from_url;
/

EXEC load_html_from_url('http://localhost/');

Next the BLOB.

CREATE OR REPLACE PROCEDURE load_binary_from_url (p_url  IN  VARCHAR2) AS
  l_blob           BLOB;
BEGIN
  l_blob := HTTPURITYPE.createuri(p_url).getblob();

  -- Insert the data into the table.
  INSERT INTO http_blob_test (id, url, data)
  VALUES (http_blob_test_seq.NEXTVAL, p_url, l_blob);

END load_binary_from_url;
/

EXEC load_binary_from_url('http://localhost/apache_pb.gif');

For more information see:

Hope this helps. Regards Tim...

Back to the Top.