JDBC for SQL Server - Herong's Tutorial Examples - v3.14, by Herong Yang
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.
/* SqlServerClobSetClob.java * Copyright (c) HerongYang.com. All Rights Reserved. */ import java.io.*; import java.sql.*; public class SqlServerClobSetClob { public static void main(String [] args) { Connection con = null; try { com.microsoft.sqlserver.jdbc.SQLServerDataSource ds = new com.microsoft.sqlserver.jdbc.SQLServerDataSource(); ds.setServerName("localhost"); // ds.setPortNumber(60782); ds.setInstanceName("SQLEXPRESS"); ds.setDatabaseName("AdventureWorks2019"); ds.setUser("Herong"); ds.setPassword("T0pSecret"); 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) 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.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(); } } }
The program performed exactly as I expected:
herong> java -cp .;mssql-jdbc-9.4.1.jre16.jar SqlServerClobSetClob Copying record ID: 1 Copying record ID: 2 Copying record ID: 5 Record ID: 6 Subject = Copy of Test on INSERT statement Body = A BLOB (BINARY LARGE OBJECT) IS a large chunk of data which is stored in a database.... Record ID: 7 Subject = Copy of Test of the setString() method Body = HE IS WONDERFUL AND STRANGE AND who knows how old he is, he thought. Never have I had such a strong ... Record ID: 8 Subject = Copy of Test of setCharacterStream() methods Body = /* SQLSERVERCLOBSETCHARACTERSTREam.java * Copyright (c) HerongYang.com. All Rights Reserved. ...
Table of Contents
JDBC (Java Database Connectivity) Introduction
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
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
SQL Server BLOB (Binary Large Object) - BLOB
Using Connection Pool with JDBC
JDBC-ODBC Bridge Driver - sun.jdbc.odbc.JdbcOdbcDriver
JDBC-ODBC Bridge Driver - Flat Text Files
JDBC-ODBC Bridge Driver - MS Access