前提是数据库上需要安装java虚拟机(JVM),使用下面的语句查看
select * from dba_registry where comp_id = 'JAVAVM'
为空,则未安装,请执行 $ORACLE_HOME/javavm/install/initjvm.sql安装.
一、如何创建java存储过程?
通常有三种方法来创建java存储过程。1. 使用oracle的sql语句来创建:
e.g. 使用create or replace and compile java source named "<name>" as
后边跟上java源程序。要求类的方法必须是public static的,才能用于存储过程。SQL> create or replace and compile java source named "javademo1"
2 as 3 import java.sql.*; 4 public class JavaDemo1 5 { 6 public static void main(String[] argv) 7 { 8 System.out.println("hello, java demo1"); 9 } 10 } 11 /Java 已创建。
SQL> show errors java source "javademo1"
没有错误。SQL> create or replace procedure javademo1
2 as 3 language java name ''JavaDemo1.main(java.lang.String[])''; 4 /过程已创建。
SQL> set serveroutput on
SQL> call javademo1();调用完成。
SQL> call dbms_java.set_output(5000);
调用完成。
SQL> call javademo1();
hello, java demo1调用完成。
SQL> call javademo1();
hello, java demo1调用完成。2. 使用外部class文件来装载创建e.g. 这里既然用到了外部文件,必然要将class文件放到oracle Server的某一目录下边。 public class OracleJavaProc{ public static void main(String[] argv) { System.out.println("It''s a Java Oracle procedure."); }} SQL> grant create any directory to scott;授权成功。
SQL> conn scott/tiger@iihero.oracledb
已连接。SQL> create or replace directory test_dir as ''d:\oracle'';目录已创建。
SQL> create or replace java class using bfile(test_dir, ''OracleJavaProc.CLASS'')
2 /Java 已创建。
SQL> create or replace procedure testjavaproc as language java name ''OracleJavaProc.main(java.lang.String[])'';
2 /过程已创建。
SQL> call testjavaproc();
调用完成。
SQL> execute testjavaproc;
PL/SQL 过程已成功完成。
SQL> set serveroutput on size 5000
SQL> call dbms_java.set_output(5000);调用完成。
SQL> execute testjavaproc;
It''s a Java Oracle procedure.3. 我推荐的一种方法,直接使用loadjava命令远程装载并创建。 先创建一个类, e.g. import java.sql.*;import oracle.jdbc.*;public class OracleJavaProc ...{
//Add a salgrade to the database.
public static void addSalGrade(int grade, int losal, int hisal) ...{System.out.println("Creating new salgrade for EMPLOYEE...");
try ...{
Connection conn = DriverManager.getConnection("jdbc:default:connection:");String sql =
"INSERT INTO salgrade " + "(GRADE,LOSAL,HISAL) " + "VALUES(?,?,?)"; PreparedStatement pstmt = conn.prepareStatement(sql); pstmt.setInt(1,grade); pstmt.setInt(2,losal); pstmt.setInt(3,hisal); pstmt.executeUpdate(); pstmt.close(); } catch(SQLException e) ...{ System.err.println("ERROR! Adding Salgrade: " + e.getMessage()); } }}使用loadjava命令将其装载到服务器端并编译: D:eclipse3.1workspacedbtest>loadjava -u scott/tiger@iihero.oracledb -v -resolve OracleJavaProc.javaarguments: ''-u'' ''scott/tiger@iihero.oracledb ''-v'' ''-resolve'' ''OracleJavaProc.java''creating : source OracleJavaProcloading : source OracleJavaProcresolving: source OracleJavaProc查询一下状态: 连接到:Oracle9i Enterprise Edition Release 9.2.0.1.0 - ProductionWith the Partitioning, OLAP and Oracle Data Mining optionsJServer Release 9.2.0.1.0 - ProductionSQL> SELECT object_name, object_type, status FROM user_objects WHERE object_type LIKE ''JAVA%'';
OBJECT_NAME
--------------------------------------------------------------------------------OBJECT_TYPE STATUS
------------------------------------ --------------OracleJavaProcJAVA CLASS VALIDOracleJavaProc
JAVA SOURCE VALID测试一下存储过程: SQL> create or replace procedure add_salgrade(id number, losal number, hisal number) as language java name ''OracleJavaProc.addSalGrade(int, int, int)''; 2 /过程已创建。
SQL> set serveroutput on size 2000
SQL> call dbms_java.set_output(2000);调用完成。
SQL> execute add_salgrade(6, 10000, 15000);
Creating new salgrade for EMPLOYEE...PL/SQL 过程已成功完成。
SQL> select * from salgrade where grade=6;
GRADE LOSAL HISAL
---------- ---------- ---------- 6 10000 15000二、如何更新你已经编写的java存储过程?
假如要往类OracleJavaProc里添加一个存储过程方法,如何开发?
正确的步骤应该是先dropjava, 改程序,再loadjava。e.g.修改OracleJavaProc类内容如下:
import java.sql.*;import oracle.jdbc.*;public class OracleJavaProc ...{
// Add a salgrade to the database.
public static void addSalGrade(int grade, int losal, int hisal) ...{System.out.println("Creating new salgrade for EMPLOYEE...");
try ...{
Connection conn = DriverManager.getConnection("jdbc:default:connection:");String sql =
"INSERT INTO salgrade " + "(GRADE,LOSAL,HISAL) " + "VALUES(?,?,?)"; PreparedStatement pstmt = conn.prepareStatement(sql); pstmt.setInt(1,grade); pstmt.setInt(2,losal); pstmt.setInt(3,hisal); pstmt.executeUpdate(); pstmt.close(); } catch(SQLException e) ...{ System.err.println("ERROR! Adding Salgrade: " + e.getMessage()); } } public static int getHiSal(int grade) ...{ try ...{ Connection conn = DriverManager.getConnection("jdbc:default:connection:"); String sql = "SELECT hisal FROM salgrade WHERE grade = ?"; PreparedStatement pstmt = conn.prepareStatement(sql);pstmt.setInt(1, grade); ResultSet rset = pstmt.executeQuery(); int res = 0; if (rset.next()) ...{ res = rset.getInt(1); } rset.close(); return res; } catch (SQLException e) ...{ System.err.println("ERROR! Querying Salgrade: " + e.getMessage()); return -1; } }}如何更新呢?
D:eclipse3.1workspacedbtest>dropjava -u scott -v OracleJavaProcD:/tiger@iihero.oracledbeclipse3.1workspacedbtest>loadjava -u scott -v -resolve Or
acleJavaProc/tiger@iihero.oracledb.javaarguments: ''-u'' ''scott/tiger@iihero.oracledb'' ''-v'' ''-resolve'' ''OracleJavaProc.java''creating : source OracleJavaProcloading : source OracleJavaProcresolving: source OracleJavaProc后边的应用示例: SQL> create or replace function query_hisal(grade number) return number as language java name ''OracleJavaProc.getHiSal(int) return int''; 2 /函数已创建。
SQL> set serveroutput on size 2000
SQL> call dbms_java.set_output(2000);调用完成。
SQL> select query_hisal(5) from dual;QUERY_HISAL(5)
-------------- 9999