Accessing non-Oracle databases using stored procedures and JDBC

This tip demonstrates how to connect to non-Oracle databases from within Oracle stored procedures using JDBC.

I am sure a lot of developers have had the need to connect to non-Oracle databases from within Oracle 8i. Unless

Oracle has a transparent gateway for your non-Oracle database, this is not a very simple task. This tip demonstrates how to do exactly that in Oracle 8i.

This technique works only on versions 8i and above since it requires the Oracle JVM to be installed inside the database. We did our implementation for Progress and I have helped others use it with MS SQL Server. Ideally, it should work with any database that you can find a JDBC driver for. This tip has also been published on Oracle Magazine's Web site.

We have a Progress database in our environment and needed to access data in this database from within an Oracle stored procedure. We utilized Oracle's Java stored procedure functionality to make this possible. Here are the steps:

  1. We used Merant's JDBC driver for Progress. We loaded this driver into the Oracle database using loadjava as below:
    loadjava -u system/manager -resolve -resolver "((* PUBLIC) (* SYS) (* SYSTEM) (* -))" -grant PUBLIC -synonym slje.jar slje.jar 
    
    Please refer to the Oracle Java Tools Reference for documentation on the loadjava utility. We had to use (* -) to validate some of the classes in the jar file even though some references could not be resolved. This is typically OK if you are loading a commercially available jar file. We also granted everyone the ability to use the driver (grant option) and created a public synonym too (synonym option).
  2. Next we wrote a Java program that would accept a SQL string to execute on our Progress database and display the results as below:
    import java.util.*; 
    import java.sql.*; 
    import java.lang.reflect.*; 
    import java.util.Date; 
    import java.io.*; 
    import intersolv.*; 
    
    public class execQuery 
    
    { 
    
    public static void doQuery(String sqlString, String db){ 
    
    // REGISTER DRIVER 
        try { 
          Driver d = 
    (Driver)Class.forName("intersolv.jdbc.sequelink.SequeLinkDriver").newInstance(); 
        } catch (Exception e) { 
          System.out.println(e); 
        } 
    
    // GET CONNECTION 
       Connection con = null; 
       String userName = "scott"; 
       String password = "tiger"; 
       try{ 
          if ( db.equals("Production") ) 
            con = 
    DriverManager.getConnection("jdbc:sequelink://seqllinkhost:5050/[Progress];
           Database=/u15/proddb -H prodmach -S proddbserv -U dbuser -P dbpass",userName,password); 
          else 
            con = 
    DriverManager.getConnection("jdbc:sequelink://seqllinkhost:5050/[Progress];
           Database=/u15/devdb -H devmach -S devdbserv -U dbuser -P dbpass",userName,password); 
       }catch(Exception e){ 
          System.out.println(e); 
       } 
    
    
     // CREATE STATEMENT 
       Statement stmt = null; 
       try { 
           stmt = con.createStatement(); 
       } catch (Exception e){ 
           System.out.println(e); 
       } 
    
     // EXECUTE QUERY 
       ResultSet results = null; 
       try { 
           results = stmt.executeQuery(sqlString); 
       } catch (Exception e){ 
           System.out.println(e); 
       } 
    // GET ALL RESULTS 
       StringBuffer buf = new StringBuffer(); 
       try { 
           ResultSetMetaData rsmd = results.getMetaData(); 
           int numCols = rsmd.getColumnCount(); 
           int i, rowcount = 0; 
    
           while (results.next()){ 
              for (i=1; i <= numCols; i++) { 
                  if (i > 1) buf.append(","); 
                  buf.append(results.getString(i)); 
              } 
              buf.append("n"); 
              rowcount++; 
          } 
          System.out.println(buf); 
          System.out.flush(); 
          results.close(); 
      } catch (Exception e) { 
          System.out.println(e); 
      } 
    
    // CLOSE RESULT SET 
      try { 
          results.close(); 
      } catch (Exception e){ 
          System.out.println(e); 
      } 
    // CLOSE STATEMENT 
      try { 
          stmt.close(); 
      } catch (Exception e) { 
          System.out.println(e); 
      } 
    // CLOSE CONNECTION 
      try { 
          con.close(); 
      } catch (Exception e) { 
          System.out.println(e); 
      } 
    
    } 
    } 
    
  3. This Java code was then compiled:
    javac execQuery.java 
    
  4. Next this code is also loaded into the Oracle database in Scott's schema as below:
     
    loadjava -u scott/tiger -resolve -resolver "((* PUBLIC) (* SYS) (* SYSTEM) (* -))" execQuery.class 
    
  5. Next the Java stored procedure execQuery.doQuery needs to be published so it is accessible to SQL and PL/SQL as below:
    create or replace procedure do_Query(sqlString varchar2, db varchar2) 
         as language java name 'execQuery.doQuery(java.lang.String,java.lang.String)'; 
    / 
    
    We did not need to publish the JDBC driver because that is being used from with the Java code.
  6. Now we execute the code via SQL*Plus:
    SQL> set serveroutput on 
    SQL> call dbms_java.set_output(10000); 
    
    Call completed. 
    
    SQL> begin 
      2    do_Query('select ename,dept from emp','Development'); 
      3  end; 
      4  / 
    Vishal Shah,IS 
    John Doe,Sales 
    Steve Mathews,Marketing 
    
    PL/SQL procedure successfully completed. 
    
    SQL> 
    
We used this technique with Progress. You should be able to use a similar technique with your non-Oracle RDBMS. Hope this helps!!

For More Information

  • Feedback: E-mail the editor with your thoughts about this tip.
  • More tips: Hundreds of free Oracle tips and scripts.
  • Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
  • Ask the Experts: Our SQL, database design, Oracle, SQL Server, DB2, metadata, and data warehousing gurus are waiting to answer your toughest questions.
  • Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
  • Best Web Links: Oracle tips, tutorials, and scripts from around the Web.

This was first published in November 2002

Dig deeper on Oracle stored procedures

Pro+

Features

Enjoy the benefits of Pro+ membership, learn more and join.

0 comments

Oldest 

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

SearchDataManagement

SearchBusinessAnalytics

SearchSAP

SearchSQLServer

TheServerSide

SearchDataCenter

SearchContentManagement

SearchFinancialApplications

Close