Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Code sample - 23c BOOLEAN data type with JDBC + PLSQL23c jdbc bool plsql #311

Merged
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
90 changes: 90 additions & 0 deletions java/jdbc-bool-plsql/pom.xml
Original file line number Diff line number Diff line change
@@ -0,0 +1,90 @@
<?xml version="1.0" encoding="UTF-8"?>

<project xmlns="http://maven.apache.org/POM/4.0.0"
xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
xsi:schemaLocation="http://maven.apache.org/POM/4.0.0 http://maven.apache.org/xsd/maven-4.0.0.xsd">
<modelVersion>4.0.0</modelVersion>

<groupId>com.oracle.dev.jdbc</groupId>
<artifactId>jdbc-bool-plsql</artifactId>
<version>1.0-SNAPSHOT</version>

<name>jdbc-bool-plsql</name>
<description>The new BOOLEAN data type in Oracle Database 23c with PL/SQL and
the JDBC Drivers (21c, 23c)</description>
<url>
https://medium.com/oracledevs/the-new-boolean-data-type-in-oracle-database-23c-with-pl-sql-and-the-jdbc-drivers-21c-23c-c83957e7e21e</url>

<properties>
<project.build.sourceEncoding>UTF-8</project.build.sourceEncoding>
<maven.compiler.source>21</maven.compiler.source>
<maven.compiler.target>21</maven.compiler.target>
</properties>

<dependencies>
<dependency>
<groupId>com.oracle.database.jdbc</groupId>
<artifactId>ojdbc11-production</artifactId>
<version>23.4.0.24.05</version>
<type>pom</type>
</dependency>
<dependency>
<groupId>org.slf4j</groupId>
<artifactId>slf4j-api</artifactId>
<version>2.0.7</version>
</dependency>
<dependency>
<groupId>org.slf4j</groupId>
<artifactId>slf4j-simple</artifactId>
<version>2.0.7</version>
</dependency>

</dependencies>

<build>
<pluginManagement><!-- lock down plugins versions to avoid using Maven
defaults (may be moved to parent pom) -->
<plugins>
<plugin>
<artifactId>maven-clean-plugin</artifactId>
<version>3.1.0</version>
</plugin>
<plugin>
<artifactId>maven-site-plugin</artifactId>
<version>3.7.1</version>
</plugin>
<plugin>
<artifactId>maven-project-info-reports-plugin</artifactId>
<version>3.0.0</version>
</plugin>
<!-- see
http://maven.apache.org/ref/current/maven-core/default-bindings.html#Plugin_bindings_for_jar_packaging -->
<plugin>
<artifactId>maven-resources-plugin</artifactId>
<version>3.0.2</version>
</plugin>
<plugin>
<artifactId>maven-compiler-plugin</artifactId>
<version>3.8.0</version>
</plugin>
<plugin>
<artifactId>maven-surefire-plugin</artifactId>
<version>2.22.1</version>
</plugin>
<plugin>
<artifactId>maven-jar-plugin</artifactId>
<version>3.0.2</version>
</plugin>
<plugin>
<artifactId>maven-install-plugin</artifactId>
<version>2.5.2</version>
</plugin>
<plugin>
<artifactId>maven-deploy-plugin</artifactId>
<version>2.8.2</version>
</plugin>
</plugins>
</pluginManagement>
</build>

</project>
39 changes: 39 additions & 0 deletions java/jdbc-bool-plsql/script/StoredProcHqEmployee.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
CREATE USER JDBCSP_USER IDENTIFIED BY <JDBCSP_USER_PASSWORD>;
GRANT DB_DEVELOPER_ROLE TO JDBCSP_USER;
GRANT CREATE SESSION TO JDBCSP_USER;
GRANT UNLIMITED TABLESPACE TO JDBCSP_USER;

CREATE TABLE HQ_EMPLOYEE
(
"EMP_ID" NUMBER NOT NULL ENABLE,
"NAME" VARCHAR2(20 BYTE) DEFAULT NULL,
"ROLE" VARCHAR2(20 BYTE) DEFAULT NULL,
"ACTIVE" BOOLEAN,
PRIMARY KEY ("EMP_ID")
);
COMMIT;

CREATE OR REPLACE PROCEDURE INSERT_HQ_EMPLOYEE_PRC
(
in_emp_id IN HQ_EMPLOYEE.EMP_ID%TYPE,
in_name IN HQ_EMPLOYEE.NAME%TYPE,
in_role IN HQ_EMPLOYEE.ROLE%TYPE,
in_active IN HQ_EMPLOYEE.ACTIVE%TYPE,
out_result OUT VARCHAR2)
AS
BEGIN
INSERT INTO HQ_EMPLOYEE (EMP_ID, NAME, ROLE, ACTIVE)
VALUES (in_emp_id, in_name, in_role, in_active);
COMMIT;

out_result := 'TRUE';

EXCEPTION
WHEN OTHERS THEN
out_result := 'FALSE';
ROLLBACK;
END;

GRANT EXECUTE ON INSERT_HQ_EMPLOYEE_PRC TO JDBCSP_USER;

--- SELECT * FROM HQ_EMPLOYEE;
Original file line number Diff line number Diff line change
@@ -0,0 +1,102 @@
/*
Copyright (c) 2024 Oracle and/or its affiliates.

This software is dual-licensed to you under the Universal Permissive License
(UPL) 1.0 as shown at https://oss.oracle.com/licenses/upl or Apache License
2.0 as shown at http://www.apache.org/licenses/LICENSE-2.0. You may choose
either license.

Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at

https://www.apache.org/licenses/LICENSE-2.0

Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.
*/

package com.oracle.dev.jdbc;

import java.sql.CallableStatement;
import java.sql.SQLException;
import java.util.Properties;
import java.util.concurrent.ThreadLocalRandom;

import oracle.jdbc.OracleConnection;
import oracle.jdbc.pool.OracleDataSource;

public class JDBCStoredProcHqEmployee {

private final static String DB_URL = "jdbc:oracle:thin:@<DB_HOST>:<DB_PORT>/<DB_NAME>";
private final static String DB_USER = "<DB_USER>";
private final static String DB_PASSWORD = "<DB_PASSWORD>";

public static void main(String[] args) throws SQLException {

System.out.println("--------------------");
System.out.println("Input parameters");
System.out.println("--------------------");

int id = ThreadLocalRandom.current().nextInt();
System.out.println("ID: " + id);

String name = "Duke";
System.out.println("Name: " + name);

String role = "Mascott";
System.out.println("Role: " + role);

Properties info = new Properties();
info.put(OracleConnection.CONNECTION_PROPERTY_USER_NAME, DB_USER);
info.put(OracleConnection.CONNECTION_PROPERTY_PASSWORD, DB_PASSWORD);
info.put(OracleConnection.CONNECTION_PROPERTY_FAN_ENABLED, false);

// JDBC datasource
OracleDataSource ods = new OracleDataSource();
ods.setURL(DB_URL);
ods.setConnectionProperties(info);

// JDBC connection
try (OracleConnection con = (OracleConnection) ods.getConnection();

// CallableStatement
// https://docs.oracle.com/en/java/javase/19/docs/api/java.sql/java/sql/CallableStatement.html
CallableStatement stmt = con
.prepareCall("{call INSERT_HQ_EMPLOYEE_PRC(?,?,?,?,?)}");) {

// set IN parameters
stmt.setInt(1, id);
stmt.setString(2, name);
stmt.setString(3, role);

/*
* Please note that there was a PLSQL BOOLEAN type before 23c. What's new
* in 23c is the BOOLEAN type in SQL. What's interesting here is that
* we're using a BOOLEAN table column type as a parameter type in a PLSQL
* procedure
*/
stmt.setBoolean(4, true);

// register OUT parameter
stmt.registerOutParameter(5, java.sql.Types.VARCHAR);

stmt.executeUpdate();

// get OUT parameter
String result = stmt.getString(5);

System.out.println("--------------------\n");
System.out.println("Output parameter");
System.out.println("--------------------");
System.out.println("Procedured executed : " + result);

} catch (Exception e) {
e.printStackTrace();
}

}
}