Inserting CLOB Values with setClob() Method

This section describes how to insert CLOB values with the PreparedStatement.setClob() method.

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

To test this, I wrote the following program to copy some records with CLOB values as new records back into the same table. During the copy process, the CLOB values are also modified with some Clob object methods - The first 32 characters are converted to upper case characters.

/* OracleClobSetClob.java
 * Copyright (c) HerongYang.com. All Rights Reserved.
 */
import java.io.*;
import java.sql.*;
public class OracleClobSetClob {
  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 Article WHERE Subject LIKE 'Copy of %'");

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

// Looping though the first 3 records
      ResultSet res = sta.executeQuery(
        "SELECT * FROM Article 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");
        Clob body = res.getClob("Body");

// Modifying the Clob object
        String chuck = body.getSubString(1,32);
        chuck = chuck.toUpperCase();
        body.setString(1,chuck);

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

// Checking the new records
      res = sta.executeQuery(
        "SELECT * FROM Article WHERE Subject LIKE 'Copy of %'");
      while (res.next()) {
        System.out.println("Record ID: "+res.getInt("ID"));
        System.out.println("   Subject = "+res.getString("Subject"));
        String body = res.getString("Body");
        if (body.length() > 100) body = body.substring(0,100);
        System.out.println("   Body = "+body+"...");
      }
      res.close();

      sta.close();
      con.close();
    } catch (Exception e) {
      e.printStackTrace();
    }
  }
}

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

herong> Progra~1\java\jdk1.8.0_45\bin\java
   -cp .;\local\lib\ojdbc14.jar OracleClobSetClob
Copying record ID: 1
java.sql.SQLException:
ORA-22920: row containing the LOB value is not locked
   at oracle.jdbc.driver.T4CTTIoer.processError(T4CTTIoer.java:447)
   at oracle.jdbc.driver.T4CTTIoer.processError(T4CTTIoer.java:389)
   at oracle.jdbc.driver.T4CTTIoer.processError(T4CTTIoer.java:382)
   at oracle.jdbc.driver.T4C8TTILob.processError(T4C8TTILob.java:792)
   at oracle.jdbc.driver.T4CTTIfun.receive(T4CTTIfun.java:513)
   at oracle.jdbc.driver.T4CTTIfun.doRPC(T4CTTIfun.java:227)
   at oracle.jdbc.driver.T4C8TTIClob.write(T4C8TTIClob.java:450)
   at oracle.jdbc.driver.T4CConnection.putChars(...)
   at oracle.sql.CLOB.putChars(CLOB.java:547)
   at oracle.sql.CLOB.setString(CLOB.java:1167)
   at OracleClobSetClob.main(OracleClobSetClob.java:42)

The problem is caused by the Oracle JDBC driver implementation of ResultSet objects. The Clob object returned by getClob() is still tied up to the ResultSet object. When Clob 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

 Overview of CLOB (Character Large Object)

 Create Tables with CLOB Columns

 Inserting CLOB Values with SQL INSERT Statements

 Inserting CLOB Values with setString() Method

 Inserting CLOB Values with setCharacterStream() Method

 Closing InputStream Too Early on setCharacterStream()

 Retrieving CLOB Values with getString() Method

 Retrieving CLOB Values with getCharacterStream() Method

 Retrieving CLOB Values with getClob() Method

Inserting CLOB Values with setClob() Method

 Oracle BLOB (Binary Large Object) - BLOB

 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

 Additional Tutorial Notes to Be Added

 Outdated Tutorials

 References

 Full Version in PDF/EPUB