From 0e4bdb9d0420f1da048b9827596f47263f4bb8b2 Mon Sep 17 00:00:00 2001 From: Kuassim Date: Tue, 24 Jul 2018 12:43:40 -0700 Subject: [PATCH 1/3] Added a basic Java Stored Proc --- .../BasicSamples/JavaStoredProcSample.java | 215 ++++++++++++++++++ 1 file changed, 215 insertions(+) create mode 100644 java/jdbc/BasicSamples/JavaStoredProcSample.java diff --git a/java/jdbc/BasicSamples/JavaStoredProcSample.java b/java/jdbc/BasicSamples/JavaStoredProcSample.java new file mode 100644 index 00000000..0d160ef5 --- /dev/null +++ b/java/jdbc/BasicSamples/JavaStoredProcSample.java @@ -0,0 +1,215 @@ +import java.sql.DriverManager; +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; + +import oracle.jdbc.pool.OracleDataSource; + + +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + DESCRIPTION + A very basic Java stored procedure sample. For more complex Java stored procedure samples, + please explore https://github.com/oracle/oracle-db-examples/tree/master/java/ojvm directory. + Java stored procedure in the database executed using the KPRB JDBC driver in the Oracle JVM instance. + To run the sample: + 1. loadjava -r -v -user jdbcuser/jdbcuser123 JavaStoredProcSample.java + This loads a java stored procedure in the database. + 2. sqlplus jdbcuser/jdbcuser123 @JavaStoredProcSample.sql + This script first creates a wrapper stored procedure for the java function. + This calls java stored procedure from sqlplus and print number of emplyoees in the department number 20. + */ +public class JavaStoredProcSample { + + // This stored procedure executes on same client connection/session in the database. + // So special JDBC URL use with default connection. + final static String DEFAULT_URL_IN_DB = "jdbc:default:connection:"; + + // Get the total number of employees for a given department. + // This method calls from the java stored procedure wrapper + // define in the JavaStoredProcSample.sql script. + public static int getEmpCountByDept(int deptNo) { + int count = 0; + + try { + // Get default connection on the current session from the client + Connection conn = DriverManager.getConnection(DEFAULT_URL_IN_DB); + + count = getEmpCountByDept(conn, deptNo); + } + catch(SQLException sqe) { + showError("getEmpCountByDept", sqe); + } + + // Returns the calculated result value + return count; + } + + // Get the total number of employees for a given department. + // This is a common method call from in database or out of database + // running of this sample. + static int getEmpCountByDept(Connection conn, int deptNo) { + int count = 0; + + // Execute a SQL query + String sql = "SELECT COUNT(1) FROM EMP WHERE DEPTNO = ?"; + + // Gets the result value + try(PreparedStatement pstmt = conn.prepareStatement(sql)) { + pstmt.setInt(1, deptNo); + try (ResultSet rs = pstmt.executeQuery()) { + if (rs.next()) { + count = rs.getInt(1); + } + } + } + catch(SQLException sqe) { + showError("getEmpCountByDept", sqe); + } + + // Returns the calculated result value + return count; + } + + // Display error message + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + + //================ All of the following code only for running this sample out of the database ======================================== + + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + + // You must provide non-default values for ALL 3 to execute the program + static String url = DEFAULT_URL; + static String user = DEFAULT_USER; + static String password = DEFAULT_PASSWORD; + + private Connection conn; + + + /** + * Entry point of the sample for running it out of the database. + * + * @param args + * Command line arguments. Supported command line options: -l + * -u + * @throws Exception + */ + public static void main(String args[]) throws Exception { + JavaStoredProcSample javaProc = new JavaStoredProcSample(); + + getRealUserPasswordUrl(args); + + // Get connection and initialize schema. + javaProc.setup(); + + // Call java stored proc out of database run + int deptNo = 20; + + int count = javaProc.getEmpCountByDept(javaProc.conn, deptNo); + show("" + count); + + // Disconnect from the database. + javaProc.cleanup(); + } + + // Gets connection to the database + void setup() throws SQLException { + conn = getConnection(); + } + + // Disconnect from the database + void cleanup() throws SQLException { + if (conn != null) { + conn.close(); + conn = null; + } + } + + + // ==============================Utility Methods============================== + + private Connection getConnection() throws SQLException { + // Create an OracleDataSource instance and set properties + OracleDataSource ods = new OracleDataSource(); + ods.setUser(user); + ods.setPassword(password); + ods.setURL(url); + + return ods.getConnection(); + } + + static void getRealUserPasswordUrl(String args[]) throws Exception { + // URL can be modified in file, or taken from command-line + url = getOptionValue(args, "-l", DEFAULT_URL); + + // DB user can be modified in file, or taken from command-line + user = getOptionValue(args, "-u", DEFAULT_USER); + + // DB user's password can be modified in file, or explicitly entered + readPassword(" Password for " + user + ": "); + } + + // Get specified option value from command-line, or use default value + static String getOptionValue(String args[], String optionName, + String defaultVal) { + String argValue = ""; + + try { + int i = 0; + String arg = ""; + boolean found = false; + + while (i < args.length) { + arg = args[i++]; + if (arg.equals(optionName)) { + if (i < args.length) + argValue = args[i++]; + if (argValue.startsWith("-") || argValue.equals("")) { + argValue = defaultVal; + } + found = true; + } + } + + if (!found) { + argValue = defaultVal; + } + } catch (Exception e) { + showError("getOptionValue", e); + } + return argValue; + } + + static void readPassword(String prompt) throws Exception { + if (System.console() == null) { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + showln(prompt); + password = r.readLine(); + } else { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } + } + + private static void show(String msg) { + System.out.println(msg); + } + + // Show message line without new line + private static void showln(String msg) { + System.out.print(msg); + } +} From 148ac4bb17924d1f5c680804dea0e4da7ce2f0a5 Mon Sep 17 00:00:00 2001 From: Kuassim Date: Tue, 24 Jul 2018 17:42:35 -0700 Subject: [PATCH 2/3] Updated the Basic Samples Readme --- .../BasicSamples/JavaStoredProcSample.sql | 32 +++++++++++++++++++ java/jdbc/BasicSamples/Readme.md | 2 ++ 2 files changed, 34 insertions(+) create mode 100644 java/jdbc/BasicSamples/JavaStoredProcSample.sql diff --git a/java/jdbc/BasicSamples/JavaStoredProcSample.sql b/java/jdbc/BasicSamples/JavaStoredProcSample.sql new file mode 100644 index 00000000..a1c37031 --- /dev/null +++ b/java/jdbc/BasicSamples/JavaStoredProcSample.sql @@ -0,0 +1,32 @@ +Rem JavaStoredProcSample.sql +Rem +Rem Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. +Rem +Rem NAME +Rem JavaStoredProcSample.sql +Rem +Rem DESCRIPTION +Rem This SQL script is for creating a wrapper for a java stored procedure; +REm then calls it and displays the output. + +REM +REM Wrapper (a.k.a. Call Spec) for invoking JavaStoredProcSample.getEmpCountByDept(int) +REM + +CREATE OR REPLACE FUNCTION GET_EMP_COUNT_BY_DEPT (dept_no NUMBER) + RETURN NUMBER AS LANGUAGE JAVA + NAME 'JavaStoredProcSample.getEmpCountByDept(int) return int'; +/ + +REM +REM Enable the output of GET_EMP_COUNT_BY_DEPT() then invoke it. +REM + +set echo on +set serveroutput on size 5000 +call dbms_java.set_output (5000); + +VARIABLE v NUMBER; +CALL GET_EMP_COUNT_BY_DEPT(20) INTO :v; +PRINT v + diff --git a/java/jdbc/BasicSamples/Readme.md b/java/jdbc/BasicSamples/Readme.md index 2cc4bd1c..c70c632b 100644 --- a/java/jdbc/BasicSamples/Readme.md +++ b/java/jdbc/BasicSamples/Readme.md @@ -49,6 +49,8 @@ but, will hit error when connecting as these are dummy values. * **UCPMaxConnReuse.java**: Shows how applications use the MaxConnectionReuseTime and MaxConnectionReuseCount features of UCP. * **UCPMultiUsers.java**: Shows how JDBC applications use UCPP to pool connections for different users. * **UCPTimeouts.java**: Shows key connection timeout features of UCP such as ConnectionWaitTimeout, InactiveConnectionTimeout, TimeToLiveConnectionTimeout, and AbandonedConnectionTimeout. +* **JavaStoredProcSample.java**: Shows a basic Java stored procedure. +* **JavaStoredProcSample.sql**: Shows how to create a wrapper for a Java stored procedure and execute it. From 8833e74ed472a548311c3af3e9bfc2f0f9035663 Mon Sep 17 00:00:00 2001 From: Kuassim Date: Tue, 24 Jul 2018 17:45:22 -0700 Subject: [PATCH 3/3] Minor fixes. --- java/jdbc/BasicSamples/JavaStoredProcSample.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/java/jdbc/BasicSamples/JavaStoredProcSample.sql b/java/jdbc/BasicSamples/JavaStoredProcSample.sql index a1c37031..2b208aa3 100644 --- a/java/jdbc/BasicSamples/JavaStoredProcSample.sql +++ b/java/jdbc/BasicSamples/JavaStoredProcSample.sql @@ -8,7 +8,6 @@ Rem Rem DESCRIPTION Rem This SQL script is for creating a wrapper for a java stored procedure; REm then calls it and displays the output. - REM REM Wrapper (a.k.a. Call Spec) for invoking JavaStoredProcSample.getEmpCountByDept(int) REM