Oracle JDBC Extensions
Oracle has provided extensions to the JDBC standard by introducing in its drivers the support of Oracle data types and objects. It has provided implementation of these extensions in the form of packages and interfaces that let a greater flexibility in accessing and manipulating data inside Oracle 8i database. The Oracle extensions can be categorized into two types, namely, Oracle type extensions and Oracle performance extensions. The Oracle JDBC OCI, thin and server-side internal drivers support both these types of Oracle extensions.
This section discusses the Oracle Type extensions. Oracle performance extensions are discussed later in the section "JDBC Performance Extensions."
Features of Oracle Extensions
The Oracle extensions include features for standard Oracle data types and Oracle objects.
-
Oracle Data Types
Oracle JDBC extensions provide type support to all Oracle SQL data types through classes in the oracle.sql.* package. These classes map to all Oracle SQL data types that allow direct access to SQL data without first converting it to Java format. This direct access also results in more accurate mathematical calculations that would otherwise have had loss of precision. Once data access and manipulation is over, the oracle.sql.* package classes have methods to convert the results back to the appropriate Java format. Data type mappings are also provided for the advanced data types such as ROWID, REF CURSOR, LOBS, BFILES, object types, object REFS, and collections such as VARRAYS and NESTED TABLES.
-
Oracle Objects
Objects can be incorporated in the Oracle 8i database in various forms, namely, object types, object tables, object-relational tables, and collections. For example, an object type can be defined with specific attributes and then an object table can be created based on this object type.
Oracle Objects can be used in JDBC Java applications, provided the following have been taken care of:
Proper mapping between Oracle object data types and Java classes
Populating the respective Java objects with object attributes
Transforming object attribute data between SQL and Java formats
Proper access to Object data
Oracle provides two ways to implement the above procedures, namely, using Struct types or custom Java classes. The first method involves mapping objects to standard java.sql.Struct class or to oracle.sql.STRUCT class. The second method involves implementing interfaces, namely, java.sql.SQLData interface or the Oracle extension interface oracle.sql.CustomDatum. Either of the two interface implementations can be used. java.sql.SQLData interface is a more general one and uses type maps to define the correspondence between Oracle object data types and Java classes. Type maps and other implementation techniques of Oracle objects are discussed in Chapter 4, "Advanced JDBC Programming."
Oracle JDBC Packages and Classes
This section outlines the Oracle extension packages implemented to support Oracle Type extensions. The implementation packages are as follows:
oracle.sql.*This package provides classes to support all Oracle type extensions and supports both JDK 1.2.x and JDK.1.1.x (i.e., JDBC 2.0 and JDBC 1.22 standards).
oracle.jdbc.driver.*This package provides classes for DML support in Oracle Type formats and also supports both JDK 1.2.x and JDK 1.1.x.
oracle.jdbc2.*This package is for JDK1.1.x implementation only and provides classes that support JDBC 2.0 features. This has interfaces that simulate the JDBC 2.0 interfaces in the standard java.sql.* package.
The implementation details of each package can be found in the Oracle documentation "Oracle 8i JDBC Developer's Guide and Reference."
Oracle Type Extensions
This section highlights the details of the special Oracle Type extensions, namely, ROWID and REF CURSOR types.
Oracle ROWID Type
ROWID is a unique identifier for a row and gives the logical address of a row. It is 18 characters long and its value represents the physical location where the row is stored. Oracle ROWID can be used to select rows using the ROWID pseudo-column and provides a very fast row retrieval. It can also be used in the WHERE clause, for example to filter out duplicate rows existing in a table. Another use of a WHERE clause is for faster UPDATE and DELETE operations. An example of using ROWID in an UPDATE statement is given below.
SQL> select ROWID, ename, sal from emp where job='MANAGER'; ROWID ENAME SAL ------------------ ---------- ---------- AAAGDxAABAAAH9EAAD JONES 2975 AAAGDxAABAAAH9EAAF BLAKE 2850 AAAGDxAABAAAH9EAAG CLARK 2450 SQL> update emp set sal = sal + 1000 where rowid = 'AAAGDxAABAAAH9EAAD'; 1 row updated. SQL> select ROWID, ename, sal from emp where job='MANAGER'; ROWID ENAME SAL ------------------ ---------- ---------- AAAGDxAABAAAH9EAAD JONES 3975 AAAGDxAABAAAH9EAAF BLAKE 2850 AAAGDxAABAAAH9EAAG CLARK 2450
ROWID is supported as a Java String. Oracle JDBC extensions provide the oracle.sql.ROWID class in the oracle.sql.* package for manipulating data using ROWIDs. This class acts as wrapper for the SQL ROWID data type. For Oraclespecific data types that are not part of the JDBC specification, an object is returned in the corresponding oracle.sql.* format. Since ROWID is one such data type, it is returned as an oracle.sql.ROWID.
ROWIDs
The ROWID pseudo-column can be included as part of a SELECT query just as any other table column. However, ROWIDs cannot be manually updated, it is updated by Oracle internally.
For querying purposes, when the ROWID pseudo-column is included as a column in a SELECT statement as part of a Statement object, its value can be retrieved by the getROWID() method of the corresponding Resultset object cast to OracleResultSet. Also, ROWID can be a part of a PreparedStatement as a bind parameter whose value can be set using the setROWID() method of the PreparedStatement object cast to OraclePreparedStatement.
The following example illustrates the use of ROWID. Specifically, for the purposes of this example, it increments the salary of each employee in a particular department by retrieving the rows based on individual ROWIDs.
import oracle.sql.*; import java.sql.*; import oracle.jdbc.driver.*; public class RowidExample { public static void main(String[] args) throws SQLException { int ret_code; Connection conn = null; try { //Load and register Oracle driver DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); //Establish a connection conn = DriverManager.getConnection("jdbc:oracle:thin:@training:1521: Oracle", "oratest", "oratest"); int i_deptno = 10; String sql1 = "SELECT ROWID, sal, comm FROM emp WHERE deptno = ?" ; String sql2 = "UPDATE emp SET sal = ? WHERE rowid = ?"; PreparedStatement pstmt1 = conn.prepareStatement(sql1); PreparedStatement pstmt2 = conn.prepareStatement(sql2); pstmt1.setInt(1, i_deptno); ResultSet rset = pstmt1.executeQuery(); while (rset.next()) { oracle.sql.ROWID i_rowid = ((OracleResultSet)rset).getROWID(1); // String i_rowid = ""; // i_rowid = rset.getString(1); float i_sal = rset.getFloat(2); float i_comm = rset.getFloat(3); pstmt2.setFloat(1, (float) (i_sal+(1.25*i_comm))); ((OraclePreparedStatement)pstmt2).setROWID (2, i_rowid); // pstmt2.setString(2, i_rowid); pstmt2.executeUpdate(); } rset.close(); pstmt1.close(); pstmt2.close(); conn.close(); } catch (SQLException e) {ret_code = e.getErrorCode(); System.err.println(ret_code + e.getMessage()); conn.close();} } }
Oracle REF CURSOR
A REF CURSOR is a weakly typed cursor type that identifies a cursor variable. A variable can defined of the REF CURSOR type and then a query can be opened for it. The cursor variable then acts as a pointer to the query or SELECT thus opened. Stored procedures or functions as well as packaged procedures or functions can return cursor variables of type REF CURSOR. The output consists of a resultset that holds the rows returned by the REF CURSOR. This output can be captured in a JDBC ResultSet object.
For the purposes of this section, we will use the following table to demonstrate the Oracle REF CURSOR type.
CREATE TABLE emp_with_type (empno number(10) primary key, ename varchar2(40) not null, etype varchar2(10) not null, job varchar2(15) not null, mgr number(10) references emp(empno), hiredate date not null, sal number(12,2) not null, comm number(4), deptno number(4) references dept(deptno));
This table is populated with the following INSERT statements:
INSERT INTO emp_with_type SELECT empno, ename, 'SENIOR', job, mgr, hiredate, sal, comm, deptno FROM emp WHERE deptno in (10, 20) union SELECT empno, ename, 'JUNIOR', job, mgr, hiredate, sal, comm, deptno FROM emp WHERE deptno = 30;
Next we create a packaged function that returns a REF CURSOR. This is shown below:
CREATE OR REPLACE PACKAGE pkg_refcur IS TYPE bonus_refcur IS REF CURSOR; FUNCTION f_refcur(ip_etype VARCHAR2) RETURN pkg_refcur.bonus_refcur; END pkg_refcur; / CREATE OR REPLACE PACKAGE BODY pkg_refcur IS FUNCTION f_refcur(ip_etype VARCHAR2) RETURN pkg_refcur.bonus_refcur IS v_bonus_refcur pkg_refcur.bonus_refcur; BEGIN IF ip_etype = 'JUNIOR' THEN OPEN v_bonus_refcur FOR SELECT etype, empno, ename, sal, 0.25*sal bonus, deptno FROM emp_with_type WHERE etype = ip_etype; ELSIF ip_etype = 'SENIOR' THEN OPEN v_bonus_refcur FOR SELECT etype, empno, ename, sal, 0.75*sal bonus, deptno FROM emp_with_type WHERE etype = ip_etype; END IF; RETURN (v_bonus_refcur); END f_refcur; END pkg_refcur; /
The next step is to write the JDBC program that calls the above packaged function and returns a resultset. The steps involved in this are as follows:
Call the packaged function using a JDBC CallableStatement object.
The return value of the function which is a REF CURSOR is registered as an OUT parameter using the typecode OracleTypes.CURSOR.
Execute the CallableStatement to obtain the REF CURSOR returned by the PL/SQL packaged function.
The CallableStatement object is cast to an OracleCallableStatement object to use the getCursor() method, which is an Oracle extension to the standard JDBC API, and returns the REF CURSOR into a ResultSet object.
Process the resultset as desiredfor example, write to an O/S file, and so on.
The complete JDBC program is given below:
import java.sql.*; import java.io.*; import oracle.jdbc.driver.*; public class RefCursorExample { public static void main(String[] args) throws SQLException, IOException { int ret_code; Connection conn = null; try { //Load and register Oracle driver DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); //Establish a connection conn = DriverManager.getConnection ("jdbc:oracle:thin:@training:1521:Oracle", "oratest", "oratest"); String i_etype = "SENIOR"; CallableStatement cstmt = conn.prepareCall ("{? = call pkg_refcur.f_refcur(?)}"); cstmt.registerOutParameter(1, OracleTypes.CURSOR); cstmt.setString(2, i_etype); cstmt.executeUpdate(); ResultSet rset; rset = ((OracleCallableStatement)cstmt).getCursor(1); String str = ""; while (rset.next()) str += rset.getString(1)+" "+ rset.getInt(2)+" "+rset.getString(3)+" "+rset.getFloat(4)+" "+rset.getFloat(5)+" "+rset.getInt(6)+"\n"; byte buf[] = str.getBytes(); OutputStream fp = new FileOutputStream("senior.lst"); fp.write(buf); fp.close(); rset.close(); cstmt.close(); conn.close(); } catch (SQLException e) {ret_code = e.getErrorCode(); System.err.println(ret_code + e.getMessage()); conn.close();} catch (IOException e) { System.err.println ("Java File I/O Error:"+ e.getMessage()); } } }
More on returning resultsets is detailed in the sub-section "Returning Resultsets" within the section "Handling Resultsets in JDBC," later in this chapter.