JDBC for SQL Server - Herong's Tutorial Examples - v3.14, by Herong Yang
Inserting CLOB Values with setCharacterStream() Method
This section describes how to insert CLOB values with the PreparedStatement.setCharacterStream() method.
If you want to insert the entire content of a text file into a CLOB column, you should create a Reader object from this file, and use the PreparedStatement.setCharacterStream() method to pass the text file content to the CLOB column through the Reader object. There are 3 versions of the setCharacterStream() method, two of them were added as part of JDBC 4.0 (Java 1.6). Your JDBC driver may not support them:
To test those setCharacterStream() methods, wrote the following program:
/* SqlServerClobSetCharacterStream.java * Copyright (c) HerongYang.com. All Rights Reserved. */ import java.io.*; import java.sql.*; public class SqlServerClobSetCharacterStream { 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 the record for re-testing String subject = "Test of setCharacterStream() methods"; Statement sta = con.createStatement(); sta.executeUpdate("DELETE FROM Article WHERE Subject = '" +subject+"'"); // Inserting CLOB value with a PreparedStatement PreparedStatement ps = con.prepareStatement( "INSERT INTO Article (Subject, Body) VALUES (?,?)"); ps.setString(1, subject); Reader bodyIn = new FileReader("SqlServerClobSetCharacterStream.java"); // Test 1 - This will not work with JDBC 3.0 drivers // ps.setCharacterStream(2, bodyIn); // Test 2 - This will not work with JDBC 3.0 drivers // File fileIn = new File("SqlServerClobSetCharacterStream.java"); // ps.setCharacterStream(2, bodyIn, fileIn.length()); // Test 3 - This works with JDBC 3.0 drivers File fileIn = new File("SqlServerClobSetCharacterStream.java"); ps.setCharacterStream(2, bodyIn, (int) fileIn.length()); int count = ps.executeUpdate(); bodyIn.close(); ps.close(); // Retrieving CLOB value with getString() sta = con.createStatement(); ResultSet res = sta.executeQuery("SELECT * FROM Article" +" WHERE Subject = '"+subject+"'"); res.next(); System.out.println("The inserted record: "); System.out.println(" Subject = "+res.getString("Subject")); System.out.println(" Body = " +res.getString("Body").substring(0,256)); res.close(); sta.close(); con.close(); } catch (Exception e) { e.printStackTrace(); } } }
Since JDBC Driver 4.2 is a JDBC 4.2 driver, all 3 tests are working:
herong> java -cp .;mssql-jdbc-9.4.1.jre16.jar \ SqlServerClobSetCharacterStream The inserted record: Subject = Test of setCharacterStream() methods Body = /* SqlServerClobSetCharacterStream.java * Copyright (c) HerongYang.com. All Rights Reserved. */ import java.io.*; import java.sql.*; public class SqlServerClobSetCharacterStream { public static void main(String [] args) { Connection con = nul
If you are using a JDBC 3.0 driver, setCharacterStream(int parameterIndex, Reader reader) will not work. Here is what I got with the "Test 1" section open in my program with sqljdbc.jar and JDK 1.6. Remember that sqljdbc.jar is a JDBC 3.0 driver.
herong> java -cp .;sqljdbc.jar SqlServerClobSetCharacterStream Exception in thread "main" java.lang.AbstractMethodError: com .microsoft.sqlserver.jdbc.SQLServerPreparedStatement .setCharacterStream(ILjava/io/Reader;)V at SqlServerClobSetCharacterStream.main(SqlServerClobSet...java:34)
If you are using a JDBC 3.0 driver, "Test 2" also failed for the same reason - fileIn.length() returns "long" and that setCharacterStream(int, Reader, long) is JDBC 4.0 method: Here is what I got with the "Test 2" section open in my program with sqljdbc.jar and JDK 1.6. Remember that sqljdbc.jar is a JDBC 3.0 driver.
herong> java -cp .;sqljdbc.jar SqlServerClobSetCharacterStream Exception in thread "main" java.lang.AbstractMethodError: com .microsoft.sqlserver.jdbc.SQLServerPreparedStatement .setCharacterStream(ILjava/io/Reader;J)V at SqlServerClobSetCharacterStream.main(SqlServerClobSet...java:38)
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