Home > Articles > Programming > Java

Like this article? We recommend

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 Oracle–specific 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:

  1. Call the packaged function using a JDBC CallableStatement object.

  2. The return value of the function which is a REF CURSOR is registered as an OUT parameter using the typecode OracleTypes.CURSOR.

  3. Execute the CallableStatement to obtain the REF CURSOR returned by the PL/SQL packaged function.

  4. 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.

  5. Process the resultset as desired—for 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.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020