Inserting BLOB Values with setBlob() Method

This section describes how to insert BLOB values with the PreparedStatement.setBlob() method.

If you want to insert a BLOB column with a character string that comes from a java.sql.Blob object, you can directly set the value with PreparedStatement.setBlob() method.

To test this, I wrote the following program to copy some records with BLOB values as new records back into the same table. During the copy process, the BLOB values are also modified with some Blob object methods - The first 6 bytes are replaced with 0 values.

/* OracleBlobSetBlob.java
 * Copyright (c) HerongYang.com. All Rights Reserved.
 */
import java.io.*;
import java.sql.*;
public class OracleBlobSetBlob {
  public static void main(String [] args) {
    Connection con = null;
    try {
      oracle.jdbc.pool.OracleDataSource ds
        = new oracle.jdbc.pool.OracleDataSource();
      ds.setDriverType("thin");
      ds.setServerName("localhost");
      ds.setPortNumber(1521);
      ds.setDatabaseName("XE");
      ds.setUser("Herong");
      ds.setPassword("TopSecret");
      con = ds.getConnection();

// Deleting records for re-testing
      Statement sta = con.createStatement();
      sta.executeUpdate(
        "DELETE FROM Image WHERE Subject LIKE 'Copy of %'");

// Creating a PreparedStatement for inserting new records
      PreparedStatement ps = con.prepareStatement(
        "INSERT INTO Image (Subject, Body, ID) VALUES (?,?,?)");

// Looping though the first 3 records
      ResultSet res = sta.executeQuery(
        "SELECT * FROM Image ORDER BY ID");
      int i = 0;
      while (res.next() && i<3) {
        i++;
        System.out.println("Copying record ID: "+res.getInt("ID"));
        String subject = res.getString("Subject");
        Blob body = res.getBlob("Body");

// Modifying the Blob object
        byte[] chuck = {(byte)0x00, (byte)0x00, (byte)0x00,
          (byte)0x00, (byte)0x00, (byte)0x00};
        body.setBytes(1,chuck);

// Inserting a new record with setBlob()
        ps.setString(1, "Copy of "+subject);
        ps.setBlob(2,body);
        ps.setInt(3,res.getInt("ID"));
        ps.executeUpdate();
      }
      ps.close();
      res.close();

// Checking the new records
      res = sta.executeQuery(
        "SELECT * FROM Image WHERE Subject LIKE 'Copy of %'");
      while (res.next()) {
        System.out.println("Record ID: "+res.getInt("ID"));
        System.out.println("   Subject = "+res.getString("Subject"));
        byte[] body = res.getBytes("Body");
        String bodyHex = bytesToHex(body, 32);
        System.out.println("   Body in HEX = "+bodyHex+"...");
      }
      res.close();

      sta.close();
      con.close();
    } catch (Exception e) {
      e.printStackTrace();
    }
  }
  public static String bytesToHex(byte[] bytes, int max) {
    StringBuffer buffer = new StringBuffer();
    for (int i=0; i<bytes.length && i<max; i++) {
      buffer.append(Integer.toHexString(bytes[i] & 0xFF));
    }
    return buffer.toString().toUpperCase();
  }
}

Unfortunately, my program failed because Oracle JDBC driver requires that the result set row must be locked:

herong> java -cp .;ojdbc11.jar OracleBlobSetBlob

Copying record ID: 1
java.sql.SQLException:
  ORA-22920: row containing the LOB value is not locked
 at oracle.jdbc.driver.DatabaseError.throwSqlException(
   DatabaseError.java:112)
 at oracle.jdbc.driver.T4CTTIoer.processError(T4CTTIoer.java:331)
 at oracle.jdbc.driver.T4CTTIoer.processError(T4CTTIoer.java:283)
 at oracle.jdbc.driver.T4CTTIoer.processError(T4CTTIoer.java:278)
 at oracle.jdbc.driver.T4C8TTILob.receiveReply(T4C8TTILob.java:930)
 at oracle.jdbc.driver.T4C8TTILob.write(T4C8TTILob.java:249)
 at oracle.jdbc.driver.T4CConnection.putBytes(
   T4CConnection.java:1971)
 at oracle.sql.BLOB.setBytes(BLOB.java:725)
 at OracleBlobSetBlob.main(OracleBlobSetBlob.java:43)

The problem is caused by the Oracle JDBC driver implementation of ResultSet objects. The Blob object returned by getBlob() is still tied up to the ResultSet object. When Blob object is updated, Oracle consider that the ResultSet is updated, which requires locking the row in the database for automatic updates.

In another word, Oracle does not allow you to update result set. If you do, Oracle will try to persist the changes back to the database.

Table of Contents

 About This Book

 JDBC (Java Database Connectivity) Introduction

 JDK (Java SE) Installation

 Installing and Running Java DB - Derby

 Derby (Java DB) JDBC Driver

 Derby (Java DB) JDBC DataSource Objects

 Java DB (Derby) - DML Statements

 Java DB (Derby) - ResultSet Objects of Queries

 Java DB (Derby) - PreparedStatement

 MySQL Installation on Windows

 MySQL JDBC Driver (MySQL Connector/J)

 MySQL - PreparedStatement

 MySQL - Reference Implementation of JdbcRowSet

 MySQL - JBDC CallableStatement

 MySQL CLOB (Character Large Object) - TEXT

 MySQL BLOB (Binary Large Object) - BLOB

 Oracle Express Edition Installation on Windows

 Oracle JDBC Drivers

 Oracle - Reference Implementation of JdbcRowSet

 Oracle - PreparedStatement

 Oracle - JBDC CallableStatement

 Oracle CLOB (Character Large Object) - TEXT

Oracle BLOB (Binary Large Object) - BLOB

 Overview of BLOB (Binary Large Object)

 Create Tables with CLOB Columns

 Inserting BLOB Values with SQL INSERT Statements

 Inserting BLOB Values with setBytes() Method

 Inserting BLOB Values with setBinaryStream() Method

 Closing InputStream Too Early on setBinaryStream()

 Retrieving BLOB Values with getBytes() Method

 Retrieving BLOB Values with getBinaryStream() Method

 Retrieving BLOB Values with getBlob() Method

Inserting BLOB Values with setBlob() Method

 Copying BLOB Values to New Rows

 Microsoft SQL Server Express Edition

 Microsoft JDBC Driver for SQL Server

 Microsoft JDBC Driver - Query Statements and Result Sets

 Microsoft JDBC Driver - DatabaseMetaData Object

 Microsoft JDBC Driver - DDL Statements

 Microsoft JDBC Driver - DML Statements

 SQL Server - PreparedStatement

 SQL Server CLOB (Character Large Object) - TEXT

 SQL Server BLOB (Binary Large Object) - BLOB

 JDBC-ODBC Bridge Driver - sun.jdbc.odbc.JdbcOdbcDriver

 JDBC-ODBC Bridge Driver - Flat Text Files

 JDBC-ODBC Bridge Driver - MS Access

 JDBC-ODBC Bridge Driver - MS SQL Server

 Summary of JDBC Drivers and Database Servers

 Using Connection Pool with JDBC

 Archived Tutorials

 References

 Full Version in PDF/EPUB