diff --git a/java/AoJ/README.md b/java/AoJ/README.md index 64b3089b..369749e9 100644 --- a/java/AoJ/README.md +++ b/java/AoJ/README.md @@ -1,55 +1,128 @@ -# AoJ: ADBA over JDBC - -ADBA is Asynchronous Database Access, a non-blocking database access api that Oracle is proposing as a Java standard. ADBA was announced at [JavaOne 2016](https://static.rainfocus.com/oracle/oow16/sess/1461693351182001EmRq/ppt/CONF1578%2020160916.pdf) and presented again at [JavaOne 2017](http://www.oracle.com/technetwork/database/application-development/jdbc/con1491-3961036.pdf). The ADBA source is available for download from the [OpenJDK sandbox]( -http://hg.openjdk.java.net/jdk/sandbox/file/9d3b0eb749a9/src/jdk.incubator.adba) as part of the OpenJDK project. You can get involved in the ADBA specification effort by following the [JDBC Expert Group mailing list](http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/). - -Reading a bunch of JavaDoc and interfaces can be interesting, but it is not nearly as engaging as having actual running code to play with. To that end, we have uploaded the beginnings of an implementation of ADBA running over standard JDBC, AoJ. AoJ is available for download from [GitHub](https://github.com/oracle/oracle-db-examples/tree/master/java/AoJ) under the Apache license. It should run with any reasonably standard compliant JDBC driver. - -AoJ implements only a small part of ADBA, but it is enough to write interesting code. It provides partial implementations of DataSourceFactory, DataSource, Connection, OperationGroup, RowOperation, CountOperation, Transaction and others. These implementations are not complete but there is enough there to write interesting database programs. The code that is there is untested, but it does work to some extent. The saving grace is that you can download the source and improve it: add new features, fix bugs, try out alternate implementations. - -Oracle is not proposing AoJ as an open source project. However, because AoJ is released under the Apache license, the Java community can fork the code and create a true open source project with this upload as a base. Oracle developers may contribute when we have time, but this would have to be a Java community effort. - -We could have held this code back and worked on it longer. Instead we thought it better to get it to the community as soon as we could. We hope that you agree. - -## Sample Code - -The following test case should give you some idea of what AoJ can do. It uses the scott/tiger [schema](https://github.com/oracle/dotnet-db-samples/blob/master/schemas/scott.sql). It should run with any JDBC driver connecting to a database with the scott schema. - -`````` public void transactionSample() { - DataSourceFactory factory = DataSourceFactory.forName("com.oracle.adbaoverjdbc.DataSourceFactory"); - try (DataSource ds = factory.builder() - .url(URL) - .username(“scott") - .password(“tiger") - .build(); - Connection conn = ds.getConnection(t -> System.out.println("ERROR: " + t.getMessage()))) { - Transaction trans = conn.transaction(); - CompletionStage idF = conn.rowOperation("select empno, ename from emp where ename = ? for update") - .set("1", "CLARK", AdbaType.VARCHAR) - .collect(Collector.of( - () -> new int[1], - (a, r) -> {a[0] = r.get("empno", Integer.class); }, - (l, r) -> null, - a -> a[0]) - ) - .submit() - .getCompletionStage(); - conn.countOperation("update emp set deptno = ? where empno = ?") - .set("1", 50, AdbaType.INTEGER) - .set("2", idF, AdbaType.INTEGER) - .apply(c -> { - if (c.getCount() != 1L) { - trans.setRollbackOnly(); - throw new SqlException("updated wrong number of rows", null, null, -1, null, -1); - } - return c.getCount(); - }) - .onError(t -> t.printStackTrace()) - .submit(); - conn.catchErrors(); - conn.commitMaybeRollback(trans); - } - ForkJoinPool.commonPool().awaitQuiescence(1, TimeUnit.MINUTES); - } - - +# AoJ: ADBA over JDBC + +ADBA is Asynchronous Database Access, a non-blocking database access api that +Oracle is proposing as a Java standard. ADBA was announced at +[JavaOne 2016](https://static.rainfocus.com/oracle/oow16/sess/1461693351182001EmRq/ppt/CONF1578%2020160916.pdf) +and presented again at [JavaOne 2017](http://www.oracle.com/technetwork/database/application-development/jdbc/con1491-3961036.pdf). +The ADBA source is available for download from the [OpenJDK sandbox](http://hg.openjdk.java.net/jdk/sandbox/file/9d3b0eb749a9/src/jdk.incubator.adba) +as part of the OpenJDK project and the JavaDoc is available [here](http://cr.openjdk.java.net/~lancea/8188051/apidoc/jdk.incubator.adba-summary.html). +You can get involved in the ADBA specification effort by following the +[JDBC Expert Group mailing list](http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/). + +Reading a bunch of JavaDoc and interfaces can be interesting, but it is not nearly +as engaging as having actual running code to play with. To that end, we have +uploaded the beginnings of an implementation of ADBA running over standard JDBC, +AoJ. AoJ is available for download from [GitHub](https://github.com/oracle/oracle-db-examples/tree/master/java/AoJ) +under the Apache license. It should run with any reasonably standard compliant +JDBC driver. + +AoJ implements only a small part of ADBA, but it is enough to write interesting +code. It provides partial implementations of ```DataSourceFactory```, ```DataSource```, +```Connection```, ```OperationGroup```, ```RowOperation```, ```CountOperation```, +```Transaction``` and others. These implementations are not complete but there is +enough there to write interesting database programs. The code that is there is +untested, but it does work to some extent. The saving grace is that you can +download the source and improve it: add new features, fix bugs, try out alternate +implementations. + +Oracle is not proposing AoJ as an open source project. However, because AoJ is +released under the Apache license, the Java community can fork the code and create +a true open source project with this upload as a base. Oracle developers may +contribute when we have time, but this would have to be a Java community effort. + +We could have held this code back and worked on it longer. Instead we thought it +better to get it to the community as soon as we could. We hope that you agree. + +## Building AoJ + +AoJ and ADBA require JDK 9 or later. Download ADBA from the +[OpenJDK sandbox](http://hg.openjdk.java.net/jdk/sandbox/file/JDK-8188051-branch/src/jdk.incubator.adba/share/classes). It does not have any dependencies outside of Java SE. + +For building the API modules: +``` +$ mkdir -p mods/jdk.incubator.adba +$ javac -d mods/jdk.incubator.adba/ $(find jdk.incubator.adba -name "*.java") +$ jar --create --file=mlib/jdk.incubator.adba.jar --module-version=1.0 -C mods/jdk.incubator.adba/ . +```` +Download AoJ from +[GitHub](https://github.com/oracle/oracle-db-examples/tree/master/java/AoJ). Both +are modularized so be sure to include the module-info.java files. AoJ depends on +ADBA. The AoJ sample file depends on JUnit which is included with most IDEs but is +also available [here](https://github.com/junit-team/junit4). + +To run the sample file you will need a SQL database and corresponding JDBC driver. AoJ +has been run with [Oracle Database 12c](http://www.oracle.com/technetwork/database/enterprise-edition/downloads/index.html) +and [Oracle Database 12c JDBC](http://www.oracle.com/technetwork/database/application-development/jdbc/downloads/index.html), +but it should work with any reasonably standard compliant SQL database and JDBC +driver. The sample file uses the scott/tiger schema available +[here](https://github.com/oracle/dotnet-db-samples/blob/master/schemas/scott.sql). + +Start the database and load ```scott.sql```. Edit ```com.oracle.adbaoverjdbc.test.FirstLight.java``` +and set the constant ```URL``` to an appropriate value. AoJ will pass this value +to ```java.sql.DriverManager.getConnection```. If you are using a database other +than Oracle you should change the value of the constant ```TRIVIAL``` to some +very trivial ```SELECT``` query. + +## Sample Code + +The following test case should give you some idea of what AoJ can do. It should +run with any JDBC driver connecting to a database with the scott schema. This is +the last test in ```com.oracle.adbaoverjdbc.test.FirstLight.java```. For an +introduction to ADBA see the [JavaOne 2017 presentation](http://www.oracle.com/technetwork/database/application-development/jdbc/con1491-3961036.pdf). + + +```public void transactionSample() { + // get the AoJ DataSourceFactory + DataSourceFactory factory = DataSourceFactory.forName("com.oracle.adbaoverjdbc.DataSourceFactory"); + // get a DataSource and a Connection + try (DataSource ds = factory.builder() + .url(URL) + .username(“scott") + .password(“tiger") + .build(); + Connection conn = ds.getConnection(t -> System.out.println("ERROR: " + t.getMessage()))) { + // get a Transaction + Transaction trans = conn.transaction(); + // select the EMPNO of CLARK + CompletionStage idF = conn.rowOperation("select empno, ename from emp where ename = ? for update") + .set("1", "CLARK", AdbaType.VARCHAR) + .collect(Collector.of( + () -> new int[1], + (a, r) -> {a[0] = r.get("empno", Integer.class); }, + (l, r) -> null, + a -> a[0]) + ) + .submit() + .getCompletionStage(); + // update CLARK to work in department 50 + conn.countOperation("update emp set deptno = ? where empno = ?") + .set("1", 50, AdbaType.INTEGER) + .set("2", idF, AdbaType.INTEGER) + .apply(c -> { + if (c.getCount() != 1L) { + trans.setRollbackOnly(); + throw new SqlException("updated wrong number of rows", null, null, -1, null, -1); + } + return c.getCount(); + }) + .onError(t -> t.printStackTrace()) + .submit(); + + conn.catchErrors(); // resume normal execution if there were any errors + conn.commitMaybeRollback(trans); // commit (or rollback) the transaction + } + // wait for the async tasks to complete before exiting + ForkJoinPool.commonPool().awaitQuiescence(1, TimeUnit.MINUTES); + } +``` + +## AoJ Design Spec in 100 words or less + +The methods called by the user thread create a network +(i.e., [DAG](https://en.wikipedia.org/wiki/Directed_acyclic_graph)) of +```CompletableFuture```s. These ```CompleteableFuture```s asynchronously execute +the synchronous JDBC calls and the result processing code provided by the user +code. By default AoJ uses ```ForkJoinPool.commonPool()``` to execute +```CompletableFuture```s but the user code can provide another ```Executor```. +When the ```Connection``` is submitted the root of the ```CompleteableFuture``` +network is completed triggering execution of the rest of the network. diff --git a/java/AoJ/sql/README.md b/java/AoJ/sql/README.md new file mode 100644 index 00000000..e2a613f3 --- /dev/null +++ b/java/AoJ/sql/README.md @@ -0,0 +1,3 @@ +# Derby SQL + +For use with AoJ (slitghly different from Oracle SQL) diff --git a/java/AoJ/sql/derby.adba copy.sql b/java/AoJ/sql/derby.adba copy.sql new file mode 100644 index 00000000..93ae84ea --- /dev/null +++ b/java/AoJ/sql/derby.adba copy.sql @@ -0,0 +1,35 @@ +connect 'jdbc:derby:adbaDB;create=true'; +DROP TABLE EMP; +DROP TABLE DEPT; +CREATE TABLE DEPT(DEPTNO NUMERIC(2), DNAME VARCHAR(14), LOC VARCHAR(13), PRIMARY KEY(DEPTNO)); +CREATE TABLE EMP(EMPNO NUMERIC(4), ENAME VARCHAR(10), JOB VARCHAR(9), MGR NUMERIC(4), HIREDATE DATE, SAL NUMERIC(7,2), COMM NUMERIC(7,2), DEPTNO NUMERIC(2), PRIMARY KEY(EMPNO), foreign key(DEPTNO) references DEPT); +INSERT INTO DEPT VALUES(10,'ACCOUNTING','NEW YORK'); +INSERT INTO DEPT VALUES (20,'RESEARCH','DALLAS'); +INSERT INTO DEPT VALUES(30,'SALES','CHICAGO'); +INSERT INTO DEPT VALUES(40,'OPERATIONS','BOSTON'); +INSERT INTO EMP VALUES(7369,'SMITH','CLERK',7902, date('1980-12-17'), 800,NULL,20); +INSERT INTO EMP VALUES(7499,'ALLEN','SALESMAN',7698, date('1981-02-20'), 1600, 300, 30); +INSERT INTO EMP VALUES(7521,'WARD','SALESMAN',7698, date('1981-02-22'), 1250, 500, 30); +INSERT INTO EMP VALUES(7566,'JONES','MANAGER', 7839, date('1981-04-02'), 2975, NULL, 20); +INSERT INTO EMP VALUES(7654,'MARTIN','SALESMAN',7698, date('1981-09-28'), 1250,1400, 30); +INSERT INTO EMP VALUES(7698,'BLAKE','MANAGER',7839, date('1981-05-01'), 2850, NULL, 30); +INSERT INTO EMP VALUES(7782,'CLARK','MANAGER',7839, date('1981-06-05'), 2450, NULL, 10); +INSERT INTO EMP VALUES(7788,'SCOTT','ANALYST',7566, date('1987-07-13'), 3000, NULL, 20); +INSERT INTO EMP VALUES(7839,'KING','PRESIDENT',NULL, date('1981-11-17'), 5000, NULL, 10); + +INSERT INTO EMP VALUES(7844,'TURNER','SALESMAN',7698, date('1981-09-08'), 1500, 0, 30); +INSERT INTO EMP VALUES(7876,'ADAMS','CLERK',7788, date('1987-07-13'), 1100, NULL, 20); +INSERT INTO EMP VALUES(7900,'JAMES','CLERK',7698, date('1981-12-03'), 950, NULL, 30); +INSERT INTO EMP VALUES(7902,'FORD','ANALYST',7566, date('1981-12-03'), 3000, NULL, 20); +INSERT INTO EMP VALUES(7934,'MILLER','CLERK',7782, date('1982-01-23'), 1300, NULL, 10); + +DROP TABLE BONUS;; +CREATE TABLE BONUS(ENAME VARCHAR(10), JOB VARCHAR(9) ,SAL NUMERIC(7,2),COMM NUMERIC(7,2)) ; +DROP TABLE SALGRADE; +CREATE TABLE SALGRADE( GRADE NUMERIC,LOSAL NUMERIC(7,2),HISAL NUMERIC(7,2)); + +INSERT INTO SALGRADE VALUES (1,700,1200); +INSERT INTO SALGRADE VALUES (2,1201,1400); +INSERT INTO SALGRADE VALUES (3,1401,2000); +INSERT INTO SALGRADE VALUES (4,2001,3000); +INSERT INTO SALGRADE VALUES (5,3001,9999); diff --git a/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/Connection.java b/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/Connection.java index 6e803b73..342d821c 100644 --- a/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/Connection.java +++ b/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/Connection.java @@ -225,6 +225,12 @@ jdk.incubator.sql2.Submission submit(com.oracle.adbaoverjdbc.Operation V connectionPropertyValue(ConnectionProperty prop) { + V value = (V)properties.get(prop); + if (value == null) return (V)prop.defaultValue(); + else return value; + } + @@ -232,7 +238,9 @@ jdk.incubator.sql2.Submission submit(com.oracle.adbaoverjdbc.Operation op) { try { - Properties info = (Properties) ((Properties) properties.get(JdbcConnectionProperties.JDBC_CONNECTION_PROPERTIES)).clone(); + Properties info = (Properties)properties.get(JdbcConnectionProperties.JDBC_CONNECTION_PROPERTIES); + info = (Properties)(info == null ? JdbcConnectionProperties.JDBC_CONNECTION_PROPERTIES.defaultValue() + : info.clone()); info.setProperty("user", (String) properties.get(AdbaConnectionProperty.USER)); info.setProperty("password", (String) properties.get(AdbaConnectionProperty.PASSWORD)); String url = (String) properties.get(AdbaConnectionProperty.URL); diff --git a/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/Operation.java b/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/Operation.java index 6064854e..6d7d982d 100644 --- a/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/Operation.java +++ b/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/Operation.java @@ -48,24 +48,20 @@ abstract class Operation implements jdk.incubator.sql2.Operation { private static final Map CLASS_TO_JDBCTYPE = new HashMap<>(20); static { try { - CLASS_TO_JDBCTYPE.put(Boolean.class, JDBCType.BOOLEAN); CLASS_TO_JDBCTYPE.put(BigInteger.class, JDBCType.BIGINT); - CLASS_TO_JDBCTYPE.put(Class.forName("[B"), JDBCType.BINARY); - CLASS_TO_JDBCTYPE.put(Boolean.class, JDBCType.BIT); CLASS_TO_JDBCTYPE.put(Boolean.class, JDBCType.BOOLEAN); + CLASS_TO_JDBCTYPE.put(Byte.class, JDBCType.TINYINT); + CLASS_TO_JDBCTYPE.put(Class.forName("[B"), JDBCType.VARBINARY); CLASS_TO_JDBCTYPE.put(Character.class, JDBCType.CHAR); - CLASS_TO_JDBCTYPE.put(LocalDate.class, JDBCType.DATE); CLASS_TO_JDBCTYPE.put(Double.class, JDBCType.DOUBLE); CLASS_TO_JDBCTYPE.put(Float.class, JDBCType.FLOAT); CLASS_TO_JDBCTYPE.put(Integer.class, JDBCType.INTEGER); - CLASS_TO_JDBCTYPE.put(Float.class, JDBCType.REAL); - CLASS_TO_JDBCTYPE.put(Short.class, JDBCType.SMALLINT); - CLASS_TO_JDBCTYPE.put(LocalTime.class, JDBCType.TIME); + CLASS_TO_JDBCTYPE.put(LocalDate.class, JDBCType.DATE); CLASS_TO_JDBCTYPE.put(LocalDateTime.class, JDBCType.TIMESTAMP); - CLASS_TO_JDBCTYPE.put(OffsetTime.class, JDBCType.TIME_WITH_TIMEZONE); + CLASS_TO_JDBCTYPE.put(LocalTime.class, JDBCType.TIME); CLASS_TO_JDBCTYPE.put(OffsetDateTime.class, JDBCType.TIMESTAMP_WITH_TIMEZONE); - CLASS_TO_JDBCTYPE.put(Byte.class, JDBCType.TINYINT); - CLASS_TO_JDBCTYPE.put(Class.forName("[byte"), JDBCType.VARBINARY); + CLASS_TO_JDBCTYPE.put(OffsetTime.class, JDBCType.TIME_WITH_TIMEZONE); + CLASS_TO_JDBCTYPE.put(Short.class, JDBCType.SMALLINT); CLASS_TO_JDBCTYPE.put(String.class, JDBCType.VARCHAR); } catch (ClassNotFoundException ex) { /* should never happen */ } @@ -88,9 +84,9 @@ abstract class Operation implements jdk.incubator.sql2.Operation { ADBATYPE_TO_JDBCTYPE.put(AdbaType.FLOAT, JDBCType.FLOAT); ADBATYPE_TO_JDBCTYPE.put(AdbaType.INTEGER, JDBCType.INTEGER); ADBATYPE_TO_JDBCTYPE.put(AdbaType.JAVA_OBJECT, JDBCType.JAVA_OBJECT); - ADBATYPE_TO_JDBCTYPE.put(AdbaType.LONGNVARCHAR, JDBCType.LONGNVARCHAR); - ADBATYPE_TO_JDBCTYPE.put(AdbaType.LONGVARBINARY, JDBCType.LONGVARBINARY); - ADBATYPE_TO_JDBCTYPE.put(AdbaType.LONGVARCHAR, JDBCType.LONGVARBINARY); + ADBATYPE_TO_JDBCTYPE.put(AdbaType.LONG_NVARCHAR, JDBCType.LONGNVARCHAR); + ADBATYPE_TO_JDBCTYPE.put(AdbaType.LONG_VARBINARY, JDBCType.LONGVARBINARY); + ADBATYPE_TO_JDBCTYPE.put(AdbaType.LONG_VARCHAR, JDBCType.LONGVARBINARY); ADBATYPE_TO_JDBCTYPE.put(AdbaType.NCHAR, JDBCType.NCHAR); ADBATYPE_TO_JDBCTYPE.put(AdbaType.NCLOB, JDBCType.NCLOB); ADBATYPE_TO_JDBCTYPE.put(AdbaType.NULL, JDBCType.NULL); diff --git a/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/OperationGroup.java b/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/OperationGroup.java index 6f554c92..1f31a0ad 100644 --- a/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/OperationGroup.java +++ b/java/AoJ/src/com/oracle/adbaoverjdbc/com/oracle/adbaoverjdbc/OperationGroup.java @@ -16,13 +16,11 @@ package com.oracle.adbaoverjdbc; import jdk.incubator.sql2.ArrayCountOperation; -import jdk.incubator.sql2.DynamicMultiOperation; import jdk.incubator.sql2.LocalOperation; import jdk.incubator.sql2.OutOperation; import jdk.incubator.sql2.ParameterizedCountOperation; import jdk.incubator.sql2.ParameterizedRowOperation; import jdk.incubator.sql2.RowProcessorOperation; -import jdk.incubator.sql2.StaticMultiOperation; import jdk.incubator.sql2.Submission; import jdk.incubator.sql2.Transaction; import jdk.incubator.sql2.TransactionOutcome; @@ -34,6 +32,7 @@ import java.util.function.Consumer; import java.util.logging.Logger; import java.util.stream.Collector; +import jdk.incubator.sql2.MultiOperation; /** * Only sequential, dependent, unconditional supported. @@ -205,13 +204,7 @@ public RowProcessorOperation rowProcessorOperation(String sql) } @Override - public StaticMultiOperation staticMultiOperation(String sql) { - if ( ! isHeld() ) throw new IllegalStateException("TODO"); - throw new UnsupportedOperationException("Not supported yet."); //To change body of generated methods, choose Tools | Templates. - } - - @Override - public DynamicMultiOperation dynamicMultiOperation(String sql) { + public MultiOperation multiOperation(String sql) { if ( ! isHeld() ) throw new IllegalStateException("TODO"); throw new UnsupportedOperationException("Not supported yet."); //To change body of generated methods, choose Tools | Templates. } diff --git a/java/AoJ/test/com/oracle/adbaoverjdbc/test/FirstLight.java b/java/AoJ/test/com/oracle/adbaoverjdbc/test/FirstLight.java new file mode 100644 index 00000000..b54254ec --- /dev/null +++ b/java/AoJ/test/com/oracle/adbaoverjdbc/test/FirstLight.java @@ -0,0 +1,267 @@ +/* + * Copyright (c) 2018 Oracle and/or its affiliates. All rights reserved. + * + * 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 + * + * http://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.adbaoverjdbc.test; + +import jdk.incubator.sql2.AdbaType; +import jdk.incubator.sql2.Connection; +import jdk.incubator.sql2.DataSourceFactory; +import jdk.incubator.sql2.DataSource; +import jdk.incubator.sql2.Result; +import jdk.incubator.sql2.SqlException; +import jdk.incubator.sql2.Transaction; +import java.util.Properties; +import java.util.concurrent.CompletionStage; +import java.util.concurrent.ForkJoinPool; +import java.util.concurrent.TimeUnit; +import java.util.stream.Collector; +import org.junit.After; +import org.junit.AfterClass; +import org.junit.Before; +import org.junit.BeforeClass; +import org.junit.Test; +import static org.junit.Assert.*; +import static com.oracle.adbaoverjdbc.JdbcConnectionProperties.JDBC_CONNECTION_PROPERTIES; + +/** + * This is a quick and dirty test to check if anything at all is working. + * + * Depends on the scott/tiger schema availble here: + * https://github.com/oracle/dotnet-db-samples/blob/master/schemas/scott.sql + */ +public class FirstLight { + + // + // EDIT THESE + // + // Define these three constants with the appropriate values for the database + // and JDBC driver you want to use. Should work with ANY reasonably standard + // JDBC driver. These values are passed to DriverManager.getConnection. + public static final String URL = ""; + public static final String USER = "scott"; //"; + public static final String PASSWORD = "tiger"; //"; + // Define this to be the most trivial SELECT possible + public static final String TRIVIAL = "SELECT 1 FROM DUAL"; + + + public static final String FACTORY_NAME = "com.oracle.adbaoverjdbc.DataSourceFactory"; + + public FirstLight() { + } + + @BeforeClass + public static void setUpClass() { + } + + @AfterClass + public static void tearDownClass() { + } + + @Before + public void setUp() { + } + + @After + public void tearDown() { + } + + /** + * Verify that DataSourceFactory.forName works. Can't do anything without that. + */ + @Test + public void firstLight() { + assertEquals("com.oracle.adbaoverjdbc.DataSourceFactory", + DataSourceFactory.forName(FACTORY_NAME).getClass().getName()); + } + + /** + * Verify that can create a DataSource, though not a Connection. Should work + * even if there is no database. + */ + @Test + public void createDataSource() { + DataSourceFactory factory = DataSourceFactory.forName(FACTORY_NAME); + DataSource ds = factory.builder() + .url(URL) + .username(USER) + .password(PASSWORD) + .build(); + assertNotNull(ds); + } + + /** + * create a Connection and send a SQL to the database + */ + @Test + public void sqlOperation() { + Properties props = new Properties(); + props.setProperty("oracle.jdbc.implicitStatementCacheSize", "10"); + DataSourceFactory factory = DataSourceFactory.forName(FACTORY_NAME); + DataSource ds = factory.builder() + .url(URL) + .username(USER) + .password(PASSWORD) + .connectionProperty(JDBC_CONNECTION_PROPERTIES, props) + .build(); + Connection conn = ds.getConnection(t -> System.out.println("ERROR: " + t.getMessage())); + try (conn) { + assertNotNull(conn); + conn.operation(TRIVIAL).submit(); + } + ForkJoinPool.commonPool().awaitQuiescence(1, TimeUnit.MINUTES); + } + + /** + * Execute a few trivial queries. + */ + @Test + public void rowOperation() { + Properties props = new Properties(); + props.setProperty("oracle.jdbc.implicitStatementCacheSize", "10"); + DataSourceFactory factory = DataSourceFactory.forName(FACTORY_NAME); + try (DataSource ds = factory.builder() + .url(URL) + .username(USER) + .password(PASSWORD) + .connectionProperty(JDBC_CONNECTION_PROPERTIES, props) + .build(); + Connection conn = ds.getConnection(t -> System.out.println("ERROR: " + t.getMessage()))) { + assertNotNull(conn); + conn.rowOperation(TRIVIAL) + .collect(Collector.of(() -> null, + (a, r) -> { + System.out.println("Trivial: " + r.get("1", String.class)); + }, + (x, y) -> null)) + .submit(); + conn.rowOperation("select * from emp") + .collect(Collector.of( + () -> new int[1], + (int[] a, Result.Row r) -> { + a[0] = a[0]+r.get("sal", Integer.class); + }, + (l, r) -> l, + a -> (Integer)a[0])) + .submit() + .getCompletionStage() + .thenAccept( n -> {System.out.println("labor cost: " + n);}) + .toCompletableFuture(); + conn.rowOperation("select * from emp where empno = ?") + .set("1", 7782) + .collect(Collector.of( + () -> null, + (a, r) -> { + System.out.println("salary: $" + r.get("sal", Integer.class)); + }, + (l, r) -> null)) + .submit(); + } + ForkJoinPool.commonPool().awaitQuiescence(1, TimeUnit.MINUTES); + } + + /** + * check does error handling do anything + */ + @Test + public void errorHandling() { + Properties props = new Properties(); + props.setProperty("oracle.jdbc.implicitStatementCacheSize", "10"); + DataSourceFactory factory = DataSourceFactory.forName(FACTORY_NAME); + try (DataSource ds = factory.builder() + .url(URL) + .username(USER) + .password("invalid password") + .connectionProperty(JDBC_CONNECTION_PROPERTIES, props) + .build(); + Connection conn = ds.getConnection(t -> System.out.println("ERROR: " + t.toString()))) { + conn.rowOperation(TRIVIAL) + .collect(Collector.of(() -> null, + (a, r) -> { + System.out.println("Trivial: " + r.get("1", String.class)); + }, + (x, y) -> null)) + .onError( t -> { System.out.println(t.toString()); }) + .submit(); + } + + try (DataSource ds = factory.builder() + .url(URL) + .username(USER) + .password(PASSWORD) + .connectionProperty(JDBC_CONNECTION_PROPERTIES, props) + .build(); + Connection conn = ds.getConnection(t -> System.out.println("ERROR: " + t.toString()))) { + conn.rowOperation("select * from emp where empno = ?") + .set("1", 7782) + .collect(Collector.of( + () -> null, + (a, r) -> { + System.out.println("salary: $" + r.get("sal", Integer.class)); + }, + (l, r) -> null)) + .onError( t -> { System.out.println(t.getMessage()); } ) + .submit(); + } + ForkJoinPool.commonPool().awaitQuiescence(1, TimeUnit.MINUTES); + } + + /** + * Do something that approximates real work. Do a transaction. Uses + * Transaction, CompletionStage args, and catch Operation. + */ + @Test + public void transaction() { + Properties props = new Properties(); + props.setProperty("oracle.jdbc.implicitStatementCacheSize", "10"); + DataSourceFactory factory = DataSourceFactory.forName(FACTORY_NAME); + try (DataSource ds = factory.builder() + .url(URL) + .username(USER) + .password(PASSWORD) + .connectionProperty(JDBC_CONNECTION_PROPERTIES, props) + .build(); + Connection conn = ds.getConnection(t -> System.out.println("ERROR: " + t.toString()))) { + Transaction trans = conn.transaction(); + CompletionStage idF = conn.rowOperation("select empno, ename from emp where ename = ? for update") + .set("1", "CLARK", AdbaType.VARCHAR) + .collect(Collector.of( + () -> new int[1], + (a, r) -> {a[0] = r.get("empno", Integer.class); }, + (l, r) -> null, + a -> a[0]) + ) + .submit() + .getCompletionStage(); + idF.thenAccept( id -> { System.out.println("id: " + id); } ); + conn.countOperation("update emp set deptno = ? where empno = ?") + .set("1", 50, AdbaType.INTEGER) + .set("2", idF, AdbaType.INTEGER) + .apply(c -> { + if (c.getCount() != 1L) { + trans.setRollbackOnly(); + throw new SqlException("updated wrong number of rows", null, null, -1, null, -1); + } + return c.getCount(); + }) + .onError(t -> t.printStackTrace()) + .submit() + .getCompletionStage() + .thenAccept( c -> { System.out.println("updated rows: " + c); } ); + conn.catchErrors(); + conn.commitMaybeRollback(trans); + } + ForkJoinPool.commonPool().awaitQuiescence(1, TimeUnit.MINUTES); + } +} diff --git a/java/README.md b/java/README.md index e056adeb..00639583 100644 --- a/java/README.md +++ b/java/README.md @@ -1,16 +1,16 @@ # Java based examples -This is a repository of sample code that will demonstrate various concepts to assist Java developers in designing applications for accessing and processing data from the Oracle Database, leveraging Java Database Connectivity (JDBC), Universal Connection Pool (UCP); or running Java code directly in the database leveraging the embedded JVM (a.k.a. OJVM). - +This is a repository of sample code that will demonstrate various concepts to assist Java developers in designing applications for accessing and processing data in the Oracle Database, leveraging Java Database Connectivity (JDBC), Universal Connection Pool (UCP); or running Java code directly in the database leveraging the embedded JVM (a.k.a. OJVM). We have just added the AoJ sub-repository for the Asynchronous Java Database Access (ADBA) over JDBC. -# What's in Oracle database 12c Release 2 for Java Developers? -* **Java 8**: Java 8 in JDBC/UCP and OJVM; JDBC 4.2 -* **Performance**: JIT (OJVM), Network Compression over WAN (JDBC), Configurable connection health check frequency (UCP), PL/SQL Callbace interface (JDBC) -* **Scalability**: Shared Pool for Multi-Tenant Database (UCP), Shared Pool for Sharded database (UCP), Sharding Key APIs (JDBC, UCP), DRCP Proxy session sharing, DRCP support for multiple labels -* **High-Availability**: Java APIs for FAN events (SimpleFan.jar), Planned Maintenance in the driver (JDBC), Application Continuity for XA Datasources, Transaction Guard for XA Datasource -* **Security**: SSL v1.2 / TLS v 1.2 (JDBC) -* **Manageability**: XMLconfiguration (UCP), Enable/disable/suspend/resume feature level logging (JDBC), MAX_THINK_TIME for Transactions in progress (DRCP), new statistics view and AWR reports -* **Ease of Use** : Web Services Callout (OJCM), Long Identifiers (OJVM), PL/SQL Boolean (JDBC), Debugger for OJVM (Java Debug Wire Protocol) +## JDBC +Has the basic examples for JDBC and the Universal Connection Pool (UCP) code samples. +## OJVM +Has code samples for running Java in the database foreground process for in-place processing using the embedded JVM. + +## HRWebApp +A complete end to end MVC application. + +## AoJ +Has code samples for learning the Asynchronous Database Access over vanilla/synchronous JDBC. This is for functional testing only. -# [White paper](http://bit.ly/2orH5jf) -# [See our OTN landing page for more information and resources](http://www.oracle.com/technetwork/database/application-development/java/overview/index.html) +# [See our OTN landing page for more information and resources](http://www.oracle.com/technetwork/database/application-development/jdbc/overview/index.html) diff --git a/java/jdbc/AdvancedSamples/RefCursorInSample.java b/java/jdbc/AdvancedSamples/RefCursorInSample.java new file mode 100644 index 00000000..107e13ff --- /dev/null +++ b/java/jdbc/AdvancedSamples/RefCursorInSample.java @@ -0,0 +1,249 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + DESCRIPTION + + REF CURSOR as INPUT parameter sample. + This capability was added in the JDBC thin driver in 18c. + To run the sample, you must enter the DB user's password from the + console, and optionally specify the DB user and/or connect URL on + the command-line. You can also modify these values in this file + and recompile the code. + java RefCursorInSample -l -u + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.CallableStatement; +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; + +import oracle.jdbc.OracleTypes; +import oracle.jdbc.pool.OracleDataSource; +import oracle.jdbc.OracleCallableStatement; + +public class RefCursorInSample { + + 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 parameters to execute the program + static String url = DEFAULT_URL; + static String user = DEFAULT_USER; + static String password = DEFAULT_PASSWORD; + + // Connection object for REF CURSOR as INPUT parameter. + // The sample uses only one connection for all REF CURSOR + // operations in this demo program. + private Connection conn; + + // Package name used in this sample + private final String PACKAGE_NAME = "REF_CURSOR_IN_JDBC_SAMPLE"; + + // Function names used in this sample + private final String FUNCTION_NAME1 = "GET_EMP_CURSOR"; + private final String FUNCTION_NAME2 = "NAVIGATE_EMP_CURSOR"; + + + /** + * Entry point of the sample. + * + * @param args + * Command line arguments. Supported command line options: -l + * -u + * @throws Exception + */ + public static void main(String args[]) throws Exception { + RefCursorInSample refCursorSample = new RefCursorInSample(); + + getRealUserPasswordUrl(args); + + // Get a connection and initialize the schema. + refCursorSample.setup(); + + // Shows REF CURSOR IN with setCursor() call + refCursorSample.setCursorSample(); + + // Drop table and disconnect from the database. + refCursorSample.cleanup(); + } + + // Gets connection to the database and create a stored procedure. + void setup() throws SQLException { + conn = getConnection(); + createFunctions(); + } + + // Drop the stored procedure and disconnect from the database + void cleanup() throws SQLException { + if (conn != null) { + dropFunctions(); + conn.close(); + conn = null; + } + } + + // Shows how to use REF CURSOR IN with setCursor() call + void setCursorSample() throws SQLException { + + show("======== setCursor Sample ========"); + + // Prepare a PL/SQL call to get a REF CURSOR as an output + try ( CallableStatement call1 = + conn.prepareCall ("{ ? = call " + PACKAGE_NAME + "." + FUNCTION_NAME1 + "() }")) { + call1.registerOutParameter (1, OracleTypes.CURSOR); + call1.execute (); + try (ResultSet rset = (ResultSet)call1.getObject (1) ) { + + // Dump the first row from the cursor + show("Fetch first row of a ref cursor in Java:"); + if(rset.next ()) + show(rset.getString ("EMPNO") + " " + + rset.getString ("ENAME")); + + // Prepare a PL/SQL call to set a REF CURSOR as an input + try ( CallableStatement call2 = + conn.prepareCall ("{ ? = call " + PACKAGE_NAME + "." + FUNCTION_NAME2 + "(?) }")) { + + call2.registerOutParameter (1, OracleTypes.INTEGER); + ((OracleCallableStatement)call2).setCursor(2, rset); + call2.execute (); + + int empno = call2.getInt(1); + + show("Fetch second row of the ref cursor in PL/SQL: empno=" + empno); + + // Dump the rest of the cursor + show("Fetch rest of the ref cursor rows in Java:"); + while (rset.next ()) + show(rset.getString ("EMPNO") + " " + + rset.getString ("ENAME")); + + } // call2 + } // rset + } // call1 + } + + // ==============================Utility Methods============================== + + private void createFunctions() throws SQLException { + try (Statement stmt = conn.createStatement()) { + String sql = "CREATE OR REPLACE PACKAGE " + PACKAGE_NAME + " AS " + + " TYPE mycursortype IS REF CURSOR RETURN EMP%ROWTYPE; " + + " FUNCTION " + FUNCTION_NAME1 + " RETURN mycursortype; " + + " FUNCTION " + FUNCTION_NAME2 + " (mycursor mycursortype) RETURN NUMBER; " + + "END " + PACKAGE_NAME + ";"; + + stmt.execute (sql); + + sql = "CREATE OR REPLACE PACKAGE BODY " + PACKAGE_NAME + " AS " + + " FUNCTION " + FUNCTION_NAME1 + " RETURN mycursortype IS " + + " rc mycursortype; " + + " BEGIN " + + " OPEN rc FOR SELECT * FROM emp ORDER BY empno;" + + " RETURN rc; " + + " END " + FUNCTION_NAME1 + "; " + + " " + + " FUNCTION " + FUNCTION_NAME2 + " (mycursor mycursortype) RETURN NUMBER IS " + + " rc NUMBER; " + + " myrecord EMP%ROWTYPE;" + + " BEGIN " + + " FETCH mycursor INTO myrecord;" + + " rc := myrecord.EMPNO;" + + " RETURN rc; " + + " END " + FUNCTION_NAME2 + "; " + + " " + + "END " + PACKAGE_NAME + ";"; + + stmt.execute (sql); + } + } + + private void dropFunctions() throws SQLException { + try (Statement stmt = conn.createStatement()) { + stmt.execute ("DROP PACKAGE " + PACKAGE_NAME); + } + } + + 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)); + shownln(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 shownln(String msg) { + System.out.print(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } +} diff --git a/java/ucp/SharedPoolCodeSample.java b/java/jdbc/AdvancedSamples/SharedPoolCodeSample.java similarity index 100% rename from java/ucp/SharedPoolCodeSample.java rename to java/jdbc/AdvancedSamples/SharedPoolCodeSample.java diff --git a/java/ucp/SharedPoolCodeSample.xml b/java/jdbc/AdvancedSamples/SharedPoolCodeSample.xml similarity index 100% rename from java/ucp/SharedPoolCodeSample.xml rename to java/jdbc/AdvancedSamples/SharedPoolCodeSample.xml diff --git a/java/ucp/SharedPoolReadme.md b/java/jdbc/AdvancedSamples/SharedPoolReadme.md similarity index 100% rename from java/ucp/SharedPoolReadme.md rename to java/jdbc/AdvancedSamples/SharedPoolReadme.md diff --git a/java/jdbc/BasicSamples/DateTimeStampSample.java b/java/jdbc/BasicSamples/DateTimeStampSample.java new file mode 100755 index 00000000..acfa8b00 --- /dev/null +++ b/java/jdbc/BasicSamples/DateTimeStampSample.java @@ -0,0 +1,307 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ +/** + * DESCRIPTION + * + * This code sample illustrates the usage of below Oracle column data types - + *

+ * DATE, TIMESTAMP, TIMESTAMP WITH TIME ZONE and TIMESTAMP WITH LOCAL TIME ZONE + *

+ * The code sample creates a simple table with these data types and performs + * insert, update, and retrieval operation on the table. + *

+ * It is required that applications have Oracle JDBC driver jar (ojdbc8.jar) in + * the class-path, and that the database backend supports SQL (this sample uses + * an Oracle Database). + *

+ *

+ * To run the sample, you must enter the DB user's password from the console, + * and optionally specify the DB user and/or connect URL on the command-line. + * You can also modify these values in this file and recompile the code. + *

+ * + * java DateTimeStampSample -l -u + * + */ +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.Date; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.SQLType; +import java.sql.Statement; +import java.sql.Timestamp; +import java.time.LocalDateTime; +import java.time.ZonedDateTime; + +import oracle.jdbc.OracleType; +import oracle.jdbc.pool.OracleDataSource; + +public class DateTimeStampSample { + + // Either modify user and url values to point your DB or + // provide these values using command line arguments. + private static String user = "myuser"; + private static String password = "mypassword"; + private static String url = "jdbc:oracle:thin:@//myhost:1521/myservice"; + + public static void main(String[] args) throws Exception { + + // These 2 can be either default or from command-line + url = getOptionValue(args, "-l", url); + user = getOptionValue(args, "-u", user); + + // DB user's Password must be entered + readPassword(" Enter Password for " + user + ": "); + + DateTimeStampSample demo = new DateTimeStampSample(); + demo.run(); + } + + void run() throws SQLException { + try (Connection conn = getConnection()) { + + // Truncate the existing table + truncateTable(conn); + + // employee details + int empId = 1001; + Date dateOfBirth = Date.valueOf("1988-09-04"); + LocalDateTime joiningDate = LocalDateTime.now(); + ZonedDateTime dateOfResignation = ZonedDateTime + .parse("2018-05-09T22:22:22-08:00[PST8PDT]"); + Timestamp dateOfLeaving = Timestamp.valueOf(LocalDateTime.now()); + Employee e = new Employee(empId, dateOfBirth, joiningDate, + dateOfResignation, dateOfLeaving); + show("\nInsert employee record into table with id = "+empId); + insertEmployee(e, conn); + + show("\nEmployee details of employee = " + empId); + Employee emp = getEmployeeDetails(1001, conn); + if (emp != null) + emp.print(); + + show("Update the employee details of employee = " + empId); + updateEmployee(empId, conn); + + show("\nUpdated details of employee = " + empId); + Employee emp1 = getEmployeeDetails(1001, conn); + if (emp1 != null) + emp1.print(); + + show("JDBCDateTimeSample demo completes."); + } + + } + + /** + * Inserts employee data into table using given connection. + * + * @param emp + * Employee data + * @param conn + * Connection to be used to insert the employee data. + * @throws SQLException + */ + private void insertEmployee(Employee emp, Connection conn) + throws SQLException { + final String insertQuery = "INSERT INTO EMP_DATE_JDBC_SAMPLE VALUES(?,?,?,?,?)"; + try (PreparedStatement pstmt = conn.prepareStatement(insertQuery)) { + SQLType dataType = null; + + pstmt.setInt(1, emp.getId()); + pstmt.setDate(2, emp.getDateOfBirth()); + dataType = OracleType.TIMESTAMP_WITH_LOCAL_TIME_ZONE; + pstmt.setObject(3, emp.getJoiningDate(), dataType); + dataType = OracleType.TIMESTAMP_WITH_TIME_ZONE; + pstmt.setObject(4, emp.getResignationDate(), dataType); + pstmt.setTimestamp(5, emp.getDateOfLeaving()); + pstmt.executeUpdate(); + show("Employee record inserted successfully."); + } + } + + /** + * Fetches the employee data for given employee id. + * + * @param id + * Employee id. + * @param conn + * Connection to be used to fetch employee data. + * @return + * @throws SQLException + */ + private Employee getEmployeeDetails(int id, Connection conn) + throws SQLException { + final String selectQuery = "SELECT EMP_ID, DATE_OF_BIRTH, DATE_OF_JOINING, " + + "DATE_OF_RESIGNATION, DATE_OF_LEAVING FROM EMP_DATE_JDBC_SAMPLE WHERE EMP_ID = ?"; + try (PreparedStatement pstmt = conn.prepareStatement(selectQuery)) { + pstmt.setInt(1, id); + try (ResultSet rs = pstmt.executeQuery()) { + if (rs.next()) { + int employeeId = rs.getInt(1); + Date datOfBirth = rs.getDate(2); + LocalDateTime dateOfJoining = rs.getObject(3, LocalDateTime.class); + ZonedDateTime dateOfResignation = rs + .getObject(4, ZonedDateTime.class); + Timestamp dateOfLeaving = rs.getTimestamp(5); + return new Employee(employeeId, datOfBirth, dateOfJoining, + dateOfResignation, dateOfLeaving); + } else { + show("Employee record not found in the database."); + return null; + } + } + + } + } + + /** + * Updates the employee record for given employee id. + * + * @param id + * Employee id. + * @param conn + * Connection to be used to update employee data. + * @throws SQLException + */ + private void updateEmployee(int id, Connection conn) throws SQLException { + final String updateQuery = "UPDATE EMP_DATE_JDBC_SAMPLE SET DATE_OF_JOINING=? WHERE EMP_ID =?"; + try (PreparedStatement pstmt = conn.prepareStatement(updateQuery)) { + SQLType dataType = OracleType.TIMESTAMP_WITH_LOCAL_TIME_ZONE; + pstmt.setObject(1, + ZonedDateTime.parse("2015-12-09T22:22:22-08:00[PST8PDT]"), dataType); + pstmt.setInt(2, id); + int updateCount = pstmt.executeUpdate(); + show("Successfully updated employee details."); + } + } + + private void truncateTable(Connection conn) { + final String sql = "TRUNCATE TABLE EMP_DATE_JDBC_SAMPLE"; + try (Statement st = conn.createStatement()) { + st.executeQuery(sql); + show("Table truncated successfully."); + } catch (SQLException e) { + showError("Truncate table operation failed.", e); + } + } + + static Connection getConnection() throws SQLException { + OracleDataSource ods = new OracleDataSource(); + ods.setURL(url); + ods.setUser(user); + ods.setPassword(password); + Connection conn = ods.getConnection(); + return conn; + } + + private static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + // 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; + } + + /** + * Reads the password from console. + * + * @param prompt + * @throws Exception + */ + static void readPassword(String prompt) throws Exception { + if (System.console() != null) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } + + /** + * A simple class to represent the employee table structure. An instance of + * this class represents a row in employee table. + */ + static class Employee { + private int id; + private Date dateOfBirth; + private LocalDateTime joiningDate; + private ZonedDateTime dateOfResignation; + private Timestamp dateOfLeaving; + + Employee(int id, Date dateOfBirth, LocalDateTime joiningDate, + ZonedDateTime dateOfResignation, Timestamp dateOfLeaving) { + this.id = id; + this.dateOfBirth = dateOfBirth; + this.joiningDate = joiningDate; + this.dateOfResignation = dateOfResignation; + this.dateOfLeaving = dateOfLeaving; + } + + int getId() { + return id; + } + + Date getDateOfBirth() { + return this.dateOfBirth; + } + + LocalDateTime getJoiningDate() { + return this.joiningDate; + } + + ZonedDateTime getResignationDate() { + return this.dateOfResignation; + } + + Timestamp getDateOfLeaving() { + return this.dateOfLeaving; + } + + void print() { + show("/----------------------------------------------------------------/"); + show("ID : " + id); + show("Date Of Birth : " + dateOfBirth); + show("Joining Date : " + joiningDate); + show("Resignation Date : " + dateOfResignation); + show("Date of Leaving : " + dateOfLeaving); + show("/----------------------------------------------------------------/\n"); + } + } +} diff --git a/java/jdbc/BasicSamples/JDBCSampleData.sql b/java/jdbc/BasicSamples/JDBCSampleData.sql new file mode 100755 index 00000000..aed55ec4 --- /dev/null +++ b/java/jdbc/BasicSamples/JDBCSampleData.sql @@ -0,0 +1,116 @@ +Rem JDBCSampleData.sql +Rem +Rem Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. +Rem +Rem NAME +Rem JDBCSampleData.sql +Rem +Rem DESCRIPTION +Rem This SQL script is for creating a new database user and a sample schema +Rem that JDBC code samples use. +Rem +Rem MODIFIED (MM/DD/YY) +Rem nbsundar 04/06/18 - Created + +Rem Create a new user "jdbcuser" that will be used in all JDBC code samples +Rem Login as sysadmin before executing the script +CREATE USER jdbcuser IDENTIFIED BY jdbcuser123; + +Rem Grant connect and resource access to the new "jdbcuser" +Rem so that the user can connect and create objects +GRANT CONNECT, RESOURCE TO jdbcuser; + +Rem Grant required access to the new "jdbcuser" +GRANT UNLIMITED TABLESPACE TO jdbcuser; + +Rem Switch the current session to the new jdbcuser session +ALTER SESSION SET CURRENT_SCHEMA=jdbcuser; + +Rem Used in the SQLXMLSample.java code sample +CREATE TABLE SQLXML_JDBC_SAMPLE (DOCUMENT XMLTYPE, ID NUMBER); + +Rem Used in the PLSQLSample.java code sample +CREATE TABLE PLSQL_JDBC_SAMPLE + (NUM NUMBER(4) NOT NULL, + NAME VARCHAR2(20) NOT NULL, + INSERTEDBY VARCHAR2(20)); + +Rem Used in LOBBasic.java code sample +CREATE TABLE LOB_JDBC_SAMPLE + (LOB_ID INT NOT NULL, + BLOB_DATA BLOB, + CLOB_DATA CLOB, + NCLOB_DATA NCLOB); + +Rem Used in DateTimeStampSample.java code sample +CREATE TABLE EMP_DATE_JDBC_SAMPLE +(EMP_ID INTEGER PRIMARY KEY, + DATE_OF_BIRTH DATE, + DATE_OF_JOINING TIMESTAMP WITH LOCAL TIME ZONE, + DATE_OF_RESIGNATION TIMESTAMP WITH TIME ZONE, + DATE_OF_LEAVING TIMESTAMP); + +Rem Used in JSONBasicDemo.java code sample +CREATE TABLE JSON_EMP_JDBC_SAMPLE + (EMP_ID RAW(16) NOT NULL PRIMARY KEY, + DATE_LOADED TIMESTAMP WITH TIME ZONE, + EMPLOYEE_DOCUMENT CLOB CONSTRAINT + ENSURE_JSON CHECK (EMPLOYEE_DOCUMENT IS JSON)); + +Rem Used in JSONBasicDemo.java code sample +INSERT INTO JSON_EMP_JDBC_SAMPLE VALUES (SYS_GUID(), SYSTIMESTAMP, '{"employee_number": 1, "employee_name": "John Doe", "salary": 2000}'); +INSERT INTO JSON_EMP_JDBC_SAMPLE VALUES (SYS_GUID(), SYSTIMESTAMP, '{"employee_number": 2, "employee_name": "Jane Doe", "salary": 2010}'); +INSERT INTO JSON_EMP_JDBC_SAMPLE VALUES (SYS_GUID(), SYSTIMESTAMP, '{"employee_number": 3, "employee_name": "John Smith", "salary": 3000, "sons": [{"name": "Angie"}, {"name": "Linda"}]}'); +INSERT INTO JSON_EMP_JDBC_SAMPLE VALUES (SYS_GUID(), SYSTIMESTAMP, '{"employee_number": 3, "employee_name": "Jane Williams", "salary": 1000, "sons": [{"name": "Rosie"}]}'); + +Rem General DEPT table for other code samples +CREATE TABLE DEPT + (DEPTNO NUMBER(2) CONSTRAINT PK_DEPT PRIMARY KEY, + DNAME VARCHAR2(14) , + LOC VARCHAR2(13) ) ; + +Rem Populate the table DEPT with few records +INSERT INTO DEPT VALUES(10,'ACCOUNTING','NEW YORK'); +INSERT INTO DEPT VALUES(20,'RESEARCH','DALLAS'); +INSERT INTO DEPT VALUES(30,'SALES','CHICAGO'); +INSERT INTO DEPT VALUES(40,'OPERATIONS','BOSTON'); + +Rem General EMP table for other code samples +CREATE TABLE EMP + (EMPNO NUMBER(4) CONSTRAINT PK_EMP PRIMARY KEY, + ENAME VARCHAR2(10), + JOB VARCHAR2(9), + MGR NUMBER(4), + HIREDATE DATE, + SAL NUMBER(7,2), + COMM NUMBER(7,2), + DEPTNO NUMBER(2) CONSTRAINT FK_DEPTNO REFERENCES DEPT); + +Rem Populate the table EMP with few records +INSERT INTO EMP VALUES(7369,'SMITH','CLERK',7902,to_date('17-12-1980','dd-mm-yyyy'),800,NULL,20); +INSERT INTO EMP VALUES(7499,'ALLEN','SALESMAN',7698,to_date('20-2-1981','dd-mm-yyyy'),1600,300,30); +INSERT INTO EMP VALUES(7521,'WARD','SALESMAN',7698,to_date('22-2-1981','dd-mm-yyyy'),1250,500,30); +INSERT INTO EMP VALUES(7566,'JONES','MANAGER',7839,to_date('2-4-1981','dd-mm-yyyy'),2975,NULL,20); +INSERT INTO EMP VALUES(7654,'MARTIN','SALESMAN',7698,to_date('28-9-1981','dd-mm-yyyy'),1250,1400,30); +INSERT INTO EMP VALUES(7698,'BLAKE','MANAGER',7839,to_date('1-5-1981','dd-mm-yyyy'),2850,NULL,30); +INSERT INTO EMP VALUES(7782,'CLARK','MANAGER',7839,to_date('9-6-1981','dd-mm-yyyy'),2450,NULL,10); +INSERT INTO EMP VALUES(7788,'SCOTT','ANALYST',7566,to_date('13-JUL-87')-85,3000,NULL,20); +INSERT INTO EMP VALUES(7839,'KING','PRESIDENT',NULL,to_date('17-11-1981','dd-mm-yyyy'),5000,NULL,10); +INSERT INTO EMP VALUES(7844,'TURNER','SALESMAN',7698,to_date('8-9-1981','dd-mm-yyyy'),1500,0,30); +INSERT INTO EMP VALUES(7876,'ADAMS','CLERK',7788,to_date('13-JUL-87')-51,1100,NULL,20); +INSERT INTO EMP VALUES(7900,'JAMES','CLERK',7698,to_date('3-12-1981','dd-mm-yyyy'),950,NULL,30); +INSERT INTO EMP VALUES(7902,'FORD','ANALYST',7566,to_date('3-12-1981','dd-mm-yyyy'),3000,NULL,20); +INSERT INTO EMP VALUES(7934,'MILLER','CLERK',7782,to_date('23-1-1982','dd-mm-yyyy'),1300,NULL,10); + + +Rem commit the changes to the database +commit; + +Rem remove the tables for any clean up +Rem drop table SQLXML_JDBC_SAMPLE; +Rem drop table PLSQL_JDBC_SAMPLE; +Rem drop table LOB_JDBC_SAMPLE; +Rem drop table JSON_EMP_JDBC_SAMPLE; +Rem drop table EMP_DATE_JDBC_SAMPLE; +Rem drop table EMP; +Rem drop table DEPT; diff --git a/java/jdbc/BasicSamples/JDBCUrlSample.java b/java/jdbc/BasicSamples/JDBCUrlSample.java new file mode 100755 index 00000000..f9cc861f --- /dev/null +++ b/java/jdbc/BasicSamples/JDBCUrlSample.java @@ -0,0 +1,378 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/** + * DESCRIPTION + * + * This class demonstrates how to specify a URL to the Oracle JDBC Driver. + *
+ * The demo can be configured to use the following forms of URLs: + *
    + *
  1. Thin-Style
  2. + *
  3. Oracle Net Connect Descriptor
  4. + *
  5. TNS Alias
  6. + *
+ * + *

Thin-Style URL

+ * Thin-style is the simplest form of URL. It consists of a host, port, and a + * service name or system identifier (SID). To run the demo using a thin-style + * URL, provide command line arguments in either of the following forms: + *
+ * -t {host} {port} {sid} + *
+ * -t {host} {port} /{service_name} + *
+ * Note the '/' character is used to differentiate between an SID and service name. + * + *

Connect Descriptor URL

+ * Connect descriptors offer a syntax for advanced configuration of the + * network connection. To learn about the syntax, see the Oracle Net Database + * Net Services Guide linked to below. This demo will use a minimal + * configuration consisting of a host, port, and service name or SID. To run + * the demo using a connect descriptor URL, provide command line arguments in + * either of the following forms: + *
+ * -c {host} {port} {sid} + *
+ * -c {host} {port} /{service_name} + *
+ * Note the '/' character is used to differentiate between an SID and service name. + * + *

TNS Alias URL

+ * A TNS alias is a reference to an connect descriptor defined in a + * tnsnames.ora file. To learn more about tnsnames.ora, see the Oracle + * Database Net Services Reference linked to below. To run the demo using a + * TNS alias URL, provide command line arguments in either of the following + * forms: + *
+ * -a {alias} {tns_names_dir} + *
+ * Where tns_names_dir is the directory which holds tnsnames.ora. + * + *

Further Reading

+ * + */ + +import java.io.Console; +import java.sql.Connection; +import java.sql.SQLException; +import java.util.Arrays; +import java.util.Objects; +import java.util.Properties; + +import oracle.jdbc.pool.OracleDataSource; +import oracle.jdbc.OracleConnection; + +public class JDBCUrlSample { + + // Default credentials to use if a console is not available. If you are + // running this demo in an IDE like Eclipse, you may need to define these + // values. + private static final String DEFAULT_USER = ""; + private static final String DEFAULT_PASSWORD = ""; + + /** The URL this demo will use */ + private final String url; + + /** Connection properties this demo will use. */ + private final Properties connectionProperties; + + private JDBCUrlSample(String url){ + this(url, new Properties()); + } + + private JDBCUrlSample(String url, Properties connectionProperties) { + this.url = url; + this.connectionProperties = connectionProperties; + } + + /** + * Returns a new demo object initialized with a thin-style URL using a + * database service name. + *

+ * The URL syntax is: + * jdbc:oracle:thin:@{host_name}:{port_number}/{service_name} + *

+ * @param host The hostname of an Oracle Database. + * @param port The port number of an Oracle Database. + * @param service The service name of an Oracle Database. + * @return A newly instantiated demo object. + */ + public static JDBCUrlSample newThinStyleServiceNameDemo(String host, + int port, String service) { + Objects.requireNonNull(host, "Host cannot be null"); + Objects.requireNonNull(service, "Service name cannot be null"); + + String thinStyleURL = + "jdbc:oracle:thin:@" + host + ":" + port + "/" + service; + return new JDBCUrlSample(thinStyleURL); + } + + /** + * Returns a new demo object initialized with a thin-style URL using + * a database SID. + *

+ * The URL syntax is: + * jdbc:oracle:thin:@{host_name}:{port_number}:{sid} + *

+ * @param host The hostname of an Oracle Database. + * @param port The port number of an Oracle Database. + * @param sid The system identifier of an Oracle Database. + * @return A newly instantiated demo object. + */ + public static JDBCUrlSample newThinStyleSIDDemo(String host, int port, + String sid) { + Objects.requireNonNull(host, "Host cannot be null"); + Objects.requireNonNull(sid, "SID cannot be null"); + + String thinStyleURL = + "jdbc:oracle:thin:@" + host + ":" + port + ":" + sid; + return new JDBCUrlSample(thinStyleURL); + } + + /** + * Returns a new demo object initialized with a connect descriptor URL using + * a service name. + *

+ * The URL syntax is: + * jdbc:oracle:thin:@(DESCRIPTION= + * (ADDRESS=(PROTOCOL=tcp)(HOST={host_name})(PORT={port})) + * (CONNECT_DATA=(SERVICE_NAME={service_name}))) + *

+ * @param host The hostname of an Oracle Database. + * @param port The port number of an Oracle Database. + * @param service The service name of an Oracle Database. + * @return A newly instantiated demo object. + */ + public static JDBCUrlSample newConnectDescriptorServiceNameDemo(String host, + int port, String service) { + Objects.requireNonNull(host, "Host cannot be null"); + Objects.requireNonNull(service, "Service name cannot be null"); + + String connectDescriptorURL = + "jdbc:oracle:thin:@(DESCRIPTION=" + + "(ADDRESS=(PROTOCOL=tcp)(HOST=" + host + ")(PORT=" + port + "))" + + "(CONNECT_DATA=(SERVICE_NAME=" + service + ")))"; + + return new JDBCUrlSample(connectDescriptorURL); + } + + /** + * Returns a new demo object initialized with a connect descriptor URL using + * a database SID. + *

+ * The URL syntax is: + * jdbc:oracle:thin:@(DESCRIPTION= + * (ADDRESS=(PROTOCOL=tcp)(HOST={host_name})(PORT={port})) + * (CONNECT_DATA=(SID={sid}))) + *

+ * @param host The hostname of an Oracle Database. + * @param port The port number of an Oracle Database. + * @param sid The system identifier of an Oracle Database. + * @return A newly instantiated demo object. + */ + public static JDBCUrlSample newConnectDescriptorSIDDemo(String host, int port, + String sid) { + Objects.requireNonNull(host, "Host cannot be null"); + Objects.requireNonNull(sid, "SID cannot be null"); + + String connectDescriptorURL = + "jdbc:oracle:thin:@(DESCRIPTION=" + + "(ADDRESS=(PROTOCOL=tcp)(HOST=" + host + ")(PORT=" + port + "))" + + "(CONNECT_DATA=(SID=" + sid + ")))"; + + return new JDBCUrlSample(connectDescriptorURL); + } + + /** + * Returns a new demo object initialized with a TNS Alias URL. + * The syntax is: + *

+ * jdbc:oracle:thin:@{tns_alias} + *

+ * @param alias A tnsnames.ora alias. + * @param tnsAdmin The directory of a tnsnames.ora file. + * @return A newly instantiated demo object. + */ + public static JDBCUrlSample newTNSAliasDemo(String alias, String tnsAdmin) { + Objects.requireNonNull(alias, "Alias cannot be null"); + Objects.requireNonNull(tnsAdmin, "TNS Admin cannot be null"); + + String tnsAliasURL = "jdbc:oracle:thin:@" + alias; + + // The directory of tnsnames.ora is defined as a connection property. + Properties connectionProperties = new Properties(); + connectionProperties.setProperty( + OracleConnection.CONNECTION_PROPERTY_TNS_ADMIN, tnsAdmin); + + return new JDBCUrlSample(tnsAliasURL, connectionProperties); + } + + /** + * Use this demo's URL to establish a connection. + */ + public void connectWithURL() { + try { + + // oracle.jdbc.pool.OracleDataSource is a factory for Connection + // objects. + OracleDataSource dataSource = new OracleDataSource(); + + // The data source is configured with database user and password. + setCredentials(dataSource); + + // The data source is configured with connection properties. + dataSource.setConnectionProperties(connectionProperties); + + // The data source is configured with a database URL. + dataSource.setURL(url); + + // The data source is used to create a Connection object. + System.out.println("\nConnecting to: " + url); + Connection connection = dataSource.getConnection(); + System.out.println("Connection Established!"); + + // Close the connection when its no longer in use. This will free up + // resources in the Java client and the database host. + connection.close(); + } + catch (SQLException sqlE) { + // The getConnection() call throws a SQLException if a connection could + // not be established. + displayConnectionError(sqlE); + } + } + + private void setCredentials(OracleDataSource dataSource) { + String user; + char[] password; + Console console = System.console(); + + if(console == null) { + System.out.println( + "\nNo console available. Using default user and password."); + user = DEFAULT_USER; + password = DEFAULT_PASSWORD.toCharArray(); + } + else { + user = console.readLine("\nUser: "); + password = console.readPassword(user + "'s password: "); + } + + dataSource.setUser(user); + dataSource.setPassword(new String(password)); + Arrays.fill(password, ' '); + } + + private void displayConnectionError(SQLException sqlE) { + System.out.println( + "Connection establishment failed with the following error:"); + + Throwable cause = sqlE; + do { + System.out.println(cause.getMessage()); + cause = cause.getCause(); + } while(cause != null); + } + + // All code beyond this point is related to command line argument parsing. + private static final String THIN_STYLE_OPTION = "-t"; + private static final String DESCRIPTOR_OPTION = "-c"; + private static final String TNS_ALIAS_OPTION = "-a"; + private static final String USAGE_MESSAGE = + "Please provide command line arguments in one of the following forms:" + + "\n\nThin-Style URL:\n\t" + + THIN_STYLE_OPTION + " {host} {port} {sid}\n\t" + + THIN_STYLE_OPTION + " {host} {port} /{service_name}" + + "\n\nOracle Net Connect Descriptor:\n\t" + + DESCRIPTOR_OPTION + " {host} {port} {sid}\n\t" + + DESCRIPTOR_OPTION + " {host} {port} /{service_name}" + + "\n\nTNS Names Alias:\n\t" + + TNS_ALIAS_OPTION + " {alias} {tnsnames_directory}"; + + private static int ARG_POSITION_HOST = 1; + private static int ARG_POSITION_PORT = 2; + private static int ARG_POSITION_SERVICE = 3; + private static int THIN_STYLE_ARG_COUNT = 4; + private static int DESCRIPTOR_ARG_COUNT = 4; + + private static int ARG_POSITION_ALIAS = 1; + private static int ARG_POSITION_TNS_ADMIN = 2; + private static int TNS_ALIAS_ARG_COUNT = 3; + + public static void main(String[] args) { + + // Read the URL type argument and initialize a demo for it. + JDBCUrlSample demo = null; + String typeOption = args.length > 0 ? args[0] : ""; + switch(typeOption) { + + case THIN_STYLE_OPTION: + if(args.length == THIN_STYLE_ARG_COUNT) { + String host = args[ARG_POSITION_HOST]; + int port = Integer.valueOf(args[ARG_POSITION_PORT]); + String service = args[ARG_POSITION_SERVICE]; + demo = service.startsWith("/") + ? newThinStyleServiceNameDemo(host, port, + service.substring(1)) + : newThinStyleSIDDemo(host, port, service); + + } + break; + + case DESCRIPTOR_OPTION: + if(args.length == DESCRIPTOR_ARG_COUNT) { + String host = args[ARG_POSITION_HOST]; + int port = Integer.valueOf(args[ARG_POSITION_PORT]); + String service = args[ARG_POSITION_SERVICE]; + demo = service.startsWith("/") + ? newConnectDescriptorServiceNameDemo(host, port, + service.substring(1)) + : newConnectDescriptorSIDDemo(host, port, service); + } + break; + + case TNS_ALIAS_OPTION: + if(args.length == TNS_ALIAS_ARG_COUNT) { + String alias = args[ARG_POSITION_ALIAS]; + String tnsAdmin = args[ARG_POSITION_TNS_ADMIN]; + demo = newTNSAliasDemo(alias, tnsAdmin); + } + break; + + default: + demo = null; + } + + if(demo == null) { + System.out.println(USAGE_MESSAGE); + } + else { + demo.connectWithURL(); + } + } +} diff --git a/java/jdbc/BasicSamples/JSONBasicSample.java b/java/jdbc/BasicSamples/JSONBasicSample.java new file mode 100755 index 00000000..2b717e77 --- /dev/null +++ b/java/jdbc/BasicSamples/JSONBasicSample.java @@ -0,0 +1,261 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/** + * DESCRIPTION + * + * This code sample objective is to show how to use some of the + * enhancements in JavaScript Object Notation (JSON) support for + * Oracle Database 12c Release 2 (12.2). + * + * This release incorporates significant new features. In this sample + * we are going to expose the following: + * + *
    + *
  • Create tables and constraints on columns for JSON documents + * using ENSURE_JSON and IS JSON + * directives.
  • + *
  • Load tables validating those constraints.
  • + *
  • Use Simple Dot-Notation Access to JSON Data.
  • + *
  • Use Simple SQL/JSON Path Expressions using + * JSON_VALUE.
  • + *
  • Use Complex SQL/JSON Path Expressions using + * JSON_EXISTS.
  • + *
+ * + * It is required that applications have Oracle JDBC driver jar on + * the classpath. This sample is based on Oracle as the database + * backend. + * + * To run the sample, you must enter the DB user's password from the + * console, and optionally specify the DB user and/or connect URL on + * the command-line. You can also modify these values in this file + * and recompile the code. + * java JSONBasicSample -l -u + */ + +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; + +// From Oracle JDBC driver +import oracle.jdbc.pool.OracleDataSource; + +public class JSONBasicSample { + + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + public static void main(String args[]) throws Exception { + + // The program exits if any of the 3 fields still has default value. + getRealUserPasswordUrl(args); + + // Run sample. + JSONBasicSample sample = new JSONBasicSample(); + sample.run(); + } + + private OracleDataSource dataSource = null; + private Connection connection = null; + private Statement statement = null; + private PreparedStatement getSalaryStatement = null; + + private void run() throws Exception { + + // Set up test: open connection/statement to be used through the demo. + demoSetUp(); + + // Test the constraint with an incorrect JSON document. + // If the SQLException is not caught, show as an error. + try { + demoExecute("INSERT INTO JSON_EMP_JDBC_SAMPLE VALUES (SYS_GUID(), SYSTIMESTAMP, '{\"emp\"loyee_number\": 5, \"employee_name\": \"Jack Johnson\"}')"); + showError("Error!. SQLException was expected to be thrown because of bad formatted JSON.", new SQLException()); + } catch (SQLException sqlException) { + show("Good catch! SQLException was expected to be thrown because of bad formatted JSON."); + } + + // This is a Simple Dot Notation Query on a column with a JSON document. + // The return value for a dot-notation query is always a string (data type VARCHAR2) representing JSON data. + // The content of the string depends on the targeted JSON data, as follows: + // If a single JSON value is targeted, then that value is the string content, whether it is a JSON scalar, object, or array. + // If multiple JSON values are targeted, then the string content is a JSON array whose elements are those values. + demoExecuteAndShow("SELECT em.employee_document.employee_number, em.employee_document.salary FROM JSON_EMP_JDBC_SAMPLE em"); + + // This is a Simple Path Notation Query + // SQL/JSON path expressions are matched by SQL/JSON functions and conditions against JSON data, to select portions of it. + // Path expressions are analogous to XQuery and XPath expression. They can use wild-cards and array ranges. Matching is case-sensitive. + demoExecuteAndShow("SELECT JSON_VALUE(employee_document, '$.employee_number') FROM JSON_EMP_JDBC_SAMPLE where JSON_VALUE(employee_document, '$.salary') > 2000"); + + // This is a Complex Path Notation Query (employees with at least one son named 'Angie'). + // An absolute simple path expression begins with a dollar sign ($), which represents the path-expression context item. + // The dollar sign is followed by zero or more path steps. + // Each step can be an object step or an array step, depending on whether the context item represents a JSON object or a JSON array. + // The last step of a simple path expression can be a single, optional function step. + // In all cases, path-expression matching attempts to match each step of the path expression, in turn. + // If matching any step fails then no attempt is made to match the subsequent steps, and matching of the path expression fails. + // If matching each step succeeds then matching of the path expression succeeds. + demoExecuteAndShow("SELECT JSON_VALUE(employee_document, '$.employee_name') FROM JSON_EMP_JDBC_SAMPLE where JSON_EXISTS(employee_document, '$.sons[*]?(@.name == \"Angie\")')"); + + // Demo using getSalary for an existing number + show("Get salary for Jane Doe (employee number:2), " + + "2010 expected: " + getSalary(2)); + + // Demo using getSalary for a non existing number + show("Get salary for non existing (employee number:5), " + + "negative value expected: " + getSalary(5)); + + // Tear down test: close connections/statements that were used through the demo. + demoTearDown(); + } + + /** + * Return an employee's salary using the employee number. + * If the employee does not exist, a negative value is returned. + * Demo based on a Path Notation Query in a PreparedStatement. + * + * @param employee number. + * @return employee salary, negative value if not found. + */ + private double getSalary(long employeeNumber) throws SQLException { + + // Bind parameter (employee number) to the query. + getSalaryStatement.setLong(1, employeeNumber); + + // Return salary (negative value if not found). + ResultSet employees = getSalaryStatement.executeQuery(); + if (employees.next()) { + return employees.getDouble(1); + } else { + return -1d; + } + } + + private void demoSetUp() throws SQLException { + dataSource = new OracleDataSource(); + dataSource.setURL(url); + dataSource.setUser(user); + dataSource.setPassword(password); + connection = dataSource.getConnection(); + statement = connection.createStatement(); + + // PreparedStatement to return the salary from an employee using the + // employee number (with Path Notation Query over the document). + getSalaryStatement = connection.prepareStatement( + "SELECT JSON_VALUE(employee_document, '$.salary') " + + "FROM JSON_EMP_JDBC_SAMPLE where JSON_VALUE " + + "(employee_document, '$.employee_number') = ?"); + + } + + private ResultSet demoExecute(String sql) throws SQLException { + return statement.executeQuery(sql); + } + + private void demoExecuteAndShow(String sql) throws SQLException { + ResultSet resultSet = demoExecute(sql); + final int columnCount = resultSet.getMetaData().getColumnCount(); + while (resultSet.next()) { + StringBuffer output = new StringBuffer(); + for (int columnIndex = 1; columnIndex <= columnCount; columnIndex++) + output.append(resultSet.getString(columnIndex)).append("|"); + show(output.toString()); + } + } + + private void demoTearDown() throws SQLException { + statement.close(); + getSalaryStatement.close(); + connection.close(); + } + + private static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + // The program exits if any of the 3 fields still has default value. + static void getRealUserPasswordUrl(String args[]) throws Exception { + // URL can be modified in file, or taken from command-line + url = getOptionValue(args, "-l", DEFAULT_URL); + if (DEFAULT_URL.equals(url)) { + show("\nYou must provide a non-default, working connect URL. Exit."); + System.exit(1); + } + + // DB user can be modified in file, or taken from command-line + user = getOptionValue(args, "-u", DEFAULT_USER); + if (DEFAULT_USER.equals(user)) { + show("\nYou must provide a non-default, working DB user. Exit."); + System.exit(1); + } + + // DB user's password can be modified in file, or explicitly entered + readPassword(" Password for " + user + ": "); + if (DEFAULT_PASSWORD.equals(password)) { + show("\nYou must provide a non-default, working DB password. Exit."); + System.exit(1); + } + } + + // Get specified option value from command-line. + 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("")) { + show("No value specified for Option " + optionName); + argValue = defaultVal; + } + found = true; + } + } + + if (!found) { + show("No Option " + optionName + " specified"); + argValue = defaultVal; + } + } catch (Exception e) { + showError("getOptionValue", e); + } + + return argValue; + } + + static void readPassword(String prompt) throws Exception { + if (System.console() != null) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } +} diff --git a/java/jdbc/BasicSamples/LobBasicSample.java b/java/jdbc/BasicSamples/LobBasicSample.java new file mode 100755 index 00000000..3f6cc87e --- /dev/null +++ b/java/jdbc/BasicSamples/LobBasicSample.java @@ -0,0 +1,691 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + DESCRIPTION + + Various lob operations sample. + To run the sample, you must enter the DB user's password from the + console, and optionally specify the DB user and/or connect URL on + the command-line. You can also modify these values in this file + and recompile the code. + java LobBasicSample -l -u + + NOTES + Sample uses books.txt and books.png from current directory. + + */ + +import java.sql.Connection; +import java.sql.NClob; +import java.sql.Statement; +import java.sql.Types; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Blob; +import java.sql.Clob; +import java.io.BufferedReader; +import java.io.ByteArrayInputStream; +import java.io.File; +import java.io.FileInputStream; +import java.io.InputStream; +import java.io.InputStreamReader; +import java.io.OutputStream; +import java.io.Reader; +import java.io.Writer; +import java.text.NumberFormat; + +import oracle.jdbc.internal.OracleStatement; +import oracle.jdbc.pool.OracleDataSource; +import oracle.sql.CLOB; + +/** + * + * Shows dealing with the various LOB data types. Shows how to add a row to a + * table that has a LOB column. Shows the LOB 2 LONG code path with + * defineColumnType, LOB prefetch (tune the size). Shows how to create a temp + * lob. + * + * @author igarish + * + */ +public class LobBasicSample { + 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; + + // Table name used in this sample + // Sample truncates the table and show lob operations + private final String TABLE_NAME = "LOB_JDBC_SAMPLE"; + + // Lob read/write chunk buffer size + private final int CHUNK_BUFFER_SIZE = 1024; + + // Connection object for various lob operations. + // Sample uses only one connection for all lob + // operations in this demo program. + private Connection conn; + + /** + * Entry point of the sample. + * + * @param args + * Command line arguments. Supported command line options: -l + * -u + * @throws Exception + */ + public static void main(String args[]) throws Exception { + LobBasicSample lobBasic = new LobBasicSample(); + + getRealUserPasswordUrl(args); + + // Get connection and initialize schema. + lobBasic.setup(); + + // Shows clob operations + lobBasic.clobSample(); + + // Shows clob operations with an empty clob + lobBasic.clobSampleWithEmptyClob(); + + // Shows blob operations + lobBasic.blobSample(); + + // Shows blob operations with an empty blob + lobBasic.blobSampleWithEmptyBlob(); + + // Shows nclob operations + lobBasic.nclobSample(); + + // Shows temporary clob operations + lobBasic.temporaryClobSample(); + + // Fetch a CLOB as a LONG + lobBasic.clobAsLongSample(); + + // Shows how to specify lob prefetch size to fine tune + // clob performance. + lobBasic.clobSampleWithLobPrefetchSize(); + + // Drop table and disconnect from the database. + lobBasic.cleanup(); + } + + // Gets connection to the database and truncate the table + void setup() throws SQLException { + conn = getConnection(); + truncateTable(); + conn.setAutoCommit(false); + } + + // Truncates the table and disconnect from the database + void cleanup() throws SQLException { + if (conn != null) { + truncateTable(); + conn.close(); + conn = null; + } + } + + // Shows how to create a Clob, insert data in the Clob, + // retrieves data from the Clob. + void clobSample() throws Exception { + show("======== Clob Sample ========"); + try (PreparedStatement pstmt = conn.prepareStatement( + "INSERT INTO " + TABLE_NAME + " (LOB_ID, CLOB_DATA) VALUES (1, ?)")) { + // Creates and fill data in the clob + Clob clob = conn.createClob(); + clob.setString(1, "Book Title - Java for Dummies"); + + // Insert clob data in the column of a table. + pstmt.setClob(1, clob); + pstmt.execute(); + conn.commit(); + + // Get data from the clob column. + executeClobQuery(1); + } + } + + // Shows how to create an empty Clob, insert data in the Clob, + // retrieves data from the Clob. + void clobSampleWithEmptyClob() throws Exception { + show("======== Clob Sample with an empty clob ========"); + // Creates an empty clob in a table then update it with actual data. + try (PreparedStatement pstmt = conn.prepareStatement( + "INSERT INTO " + TABLE_NAME + " (LOB_ID, CLOB_DATA) VALUES (2, empty_clob())")) { + pstmt.execute(); + + try (ResultSet rset = pstmt.executeQuery( + "SELECT CLOB_DATA FROM " + TABLE_NAME + " WHERE LOB_ID=2 FOR UPDATE")) { + while (rset.next()) { + Clob c = rset.getClob(1); + + // Fill clob data from a file and update it in the table. + readFileAndUpdateClobData(c, "books.txt"); + } + } + + conn.commit(); + + // Get data from the clob column + executeClobQuery(2); + } + } + + // Shows how to insert binary stream data in the Blob, + // retrieves data from the Blob. + void blobSample() throws Exception { + show("======== Blob Sample ========"); + + try (PreparedStatement pstmt = conn.prepareStatement( + "INSERT INTO " + TABLE_NAME + " (LOB_ID, BLOB_DATA) VALUES (3, ?)")) { + byte[] data = { 1, 2, 3, 77, 80, 4, 5 }; + + // Insert binary input stream data in the Blob + pstmt.setBlob(1, new ByteArrayInputStream(data)); + pstmt.execute(); + conn.commit(); + + // Get data from the blob column. + executeBlobQuery(3); + } + } + + // Shows how to create an empty Blob, insert data in the Blob, + // retrieves data from the Blob. + void blobSampleWithEmptyBlob() throws Exception { + show("======== Blob Sample with an empty blob ========"); + + // Creates an empty blob in a table then update it with actual data. + try (PreparedStatement pstmt = conn.prepareStatement( + "INSERT INTO " + TABLE_NAME + " (LOB_ID, BLOB_DATA) VALUES (4, empty_blob())")) { + pstmt.execute(); + + try (ResultSet rset = pstmt.executeQuery( + "SELECT BLOB_DATA FROM " + TABLE_NAME + " WHERE LOB_ID=4 FOR UPDATE")) { + while (rset.next()) { + Blob b = rset.getBlob(1); + + // Fill blob data from a file and update it in the table. + readFileAndUpdateBlobData(b, "books.png"); + } + } + + conn.commit(); + + // Get data from the blob column + executeBlobQuery(4); + } + } + + // Shows how to create a NClob, insert data in the NClob, + // retrieves data from the NClob. + void nclobSample() throws Exception { + show("======== Nclob Sample ========"); + + try (PreparedStatement pstmt = conn.prepareStatement( + "INSERT INTO " + TABLE_NAME + " (LOB_ID, NCLOB_DATA) VALUES (5, ?)")) { + // Creates and fill data in the nclob + NClob nclob = conn.createNClob(); + nclob.setString(1, "Book Title - Oracle \u00A9 for Dummies "); + + // Insert nclob data in the column of a table. + pstmt.setNClob(1, nclob); + pstmt.execute(); + conn.commit(); + + // Get data from the nclob column. + executeNClobQuery(5); + } + } + + // You can use temporary LOBs to store transient data. The data is stored in + // temporary + // table space rather than regular table space. You should free temporary LOBs + // after you + // no longer need them. If you do not, then the space the LOB consumes in + // temporary + // table space will not be reclaimed. + // + // Shows how to create a temporary CLOB, fill data in the temporary CLOB, + // insert temporary CLOB data in the table. + void temporaryClobSample() throws Exception { + show("======== Temporary Clob Sample ========"); + + try (PreparedStatement pstmt = conn.prepareStatement( + "INSERT INTO " + TABLE_NAME + " (LOB_ID, CLOB_DATA) VALUES (6, ?)")) { + // Creates and fill data in a temporary clob + Clob tempClob = CLOB.createTemporary(conn, false, CLOB.DURATION_SESSION); + tempClob.setString(1, "Book Title - JDBC for Dummies"); + + // Insert temporary CLOB data in the column of a table. + pstmt.setClob(1, tempClob); + pstmt.execute(); + conn.commit(); + + // Check whether the CLOB is temporary or regular CLOB. + boolean isTempCLOB = CLOB.isTemporary((CLOB) tempClob); + show("CLOB.isTemporary: " + isTempCLOB); + + // Free temporary CLOB + CLOB.freeTemporary((CLOB) tempClob); + + // Get data from the clob column. + executeClobQuery(6); + } + } + + // Fetch a CLOB as a LONG + void clobAsLongSample() throws Exception { + show("======== Clob as Long Sample ========"); + + try (PreparedStatement pstmt = conn.prepareStatement( + "INSERT INTO " + TABLE_NAME + " (LOB_ID, CLOB_DATA) VALUES (7, ?)")) { + // Creates and fill data in the clob + Clob clob = conn.createClob(); + clob.setString(1, "Book Title - JNI for Dummies"); + + // Insert clob data in the column of a table. + pstmt.setClob(1, clob); + pstmt.execute(); + conn.commit(); + + // Get data from the clob column as if it's LONG type. + executeClobAsLongQuery(7); + } + } + + // Shows how to set lob prefetch size, + // while retrieving clob data to reduce round trips to the server. + void clobSampleWithLobPrefetchSize() throws Exception { + show("======== Clob Sample with LobPrefetchSize ========"); + + try (PreparedStatement pstmt = conn.prepareStatement( + "INSERT INTO " + TABLE_NAME + " (LOB_ID, CLOB_DATA) VALUES (8, ?)")) { + // Creates and fill data in the clob + Clob clob = conn.createClob(); + clob.setString(1, "Book Title - Linux for Dummies"); + + // Insert clob data in the column of a table. + pstmt.setClob(1, clob); + pstmt.execute(); + conn.commit(); + + // Sets lob preftech size and gets data from the clob column + executeClobQueryWithLobPrefetchSize(8); + } + } + + // Execute a query to get the clob column data. + // Iterate through the result. + private void executeClobQuery(int id) throws Exception { + try (PreparedStatement pstmt = conn + .prepareStatement("SELECT CLOB_DATA FROM " + TABLE_NAME + " WHERE LOB_ID=?")) { + + pstmt.setInt(1, id); + try (ResultSet rset = pstmt.executeQuery()) { + show("LOB_ID = " + id); + while (rset.next()) { + Clob c = rset.getClob(1); + + getAndDisplayClobData("CLOB_DATA = ", c); + } + } + } + + } + + // Get the clob data as a stream. + private void getAndDisplayClobData(String message, Clob clob) + throws Exception { + // Get a character stream of a clob + try (Reader clobStream = clob.getCharacterStream()) { + // Buffer to read chunk of data + char[] buffer = new char[CHUNK_BUFFER_SIZE]; + int length = 0; + + showln(message); + + // Loop for the reading of clob data in chunks. + while ((length = clobStream.read(buffer)) != -1) + showln(new String(buffer, 0, length)); + + show(""); + } + } + + // Read data from a text file and insert it in to the clob column + private void readFileAndUpdateClobData(Clob clob, String fileName) + throws Exception { + // File reader + File file = new File(fileName); + try (FileInputStream fileInputStream = new FileInputStream(file)) { + try (InputStreamReader inputStreamReader = new InputStreamReader( + fileInputStream)) { + try (BufferedReader bufferedReader = new BufferedReader( + inputStreamReader)) { + // Buffer to read/write chunk of data + char[] buffer = new char[CHUNK_BUFFER_SIZE]; + int charsRead = 0; + + // Get a clob writer + try (Writer writer = clob.setCharacterStream(1L)) { + // Loop for reading of chunk of data and then write into the clob. + while ((charsRead = bufferedReader.read(buffer)) != -1) { + writer.write(buffer, 0, charsRead); + } + } + } + } + } + } + + // Execute a query to get the blob column data. + // Iterate through the result. + private void executeBlobQuery(int id) throws Exception { + try (PreparedStatement pstmt = conn + .prepareStatement("SELECT BLOB_DATA FROM " + TABLE_NAME + " WHERE LOB_ID=?")) { + pstmt.setInt(1, id); + try (ResultSet rset = pstmt.executeQuery()) { + show("LOB_ID = " + id); + while (rset.next()) { + Blob b = rset.getBlob(1); + + getAndDisplayBlobData("BLOB_DATA = ", b); + } + } + } + } + + // Get the blob data as a stream. + private void getAndDisplayBlobData(String message, Blob blob) + throws Exception { + // Get a binary stream of a blob + try (InputStream blobStream = blob.getBinaryStream()) { + // Buffer to read chunk of data + byte[] buffer = new byte[CHUNK_BUFFER_SIZE]; + int length = 0; + long totalLength = 0; + + NumberFormat format = NumberFormat.getInstance(); + format.setMinimumIntegerDigits(2); + format.setGroupingUsed(false); + + // Loop for the reading of blob data in chunks. + while ((length = blobStream.read(buffer)) != -1) { + if (totalLength == 0 && length > 25) + show("First 25 bytes of a Blob column"); + + for (int i = 0; i < length; i++) { + int b = (int) buffer[i] & 0XFF; + if (totalLength == 0 && i < 25) + showln(format.format((long) b) + " "); + else + break; // We are not consuming more than 25 bytes for demo purpose. + } + + totalLength += length; + } + + show(""); + + if (totalLength > 25) + show("Total blob data length:" + totalLength); + } + } + + // Read data from a binary file and insert it in to the blob column + private void readFileAndUpdateBlobData(Blob blob, String fileName) + throws Exception { + // File reader + File file = new File(fileName); + try (FileInputStream fileInputStream = new FileInputStream(file)) { + // Buffer to read/write chunk of data + byte[] buffer = new byte[CHUNK_BUFFER_SIZE]; + int bytesRead = 0; + + // Get a blob output stream + try (OutputStream outstream = blob.setBinaryStream(1L)) { + // Loop for reading of chunk of data and then write into the blob. + while ((bytesRead = fileInputStream.read(buffer)) != -1) { + outstream.write(buffer, 0, bytesRead); + } + } + } + } + + // Execute a query to get the nclob column data. + // Iterate through the result. + private void executeNClobQuery(int id) throws Exception { + try (PreparedStatement pstmt = conn + .prepareStatement("SELECT NCLOB_DATA FROM " + TABLE_NAME + " WHERE LOB_ID=?")) { + pstmt.setInt(1, id); + try (ResultSet rset = pstmt.executeQuery()) { + show("LOB_ID = " + id); + while (rset.next()) { + NClob n = rset.getNClob(1); + + getAndDisplayNClobData("NCLOB_DATA = ", n); + } + } + } + } + + // Get the nclob data as a stream. + private void getAndDisplayNClobData(String message, NClob nclob) + throws Exception { + // Get a character stream of a nclob + try (Reader nclobStream = nclob.getCharacterStream()) { + // Buffer to read chunk of data + char[] buffer = new char[CHUNK_BUFFER_SIZE]; + int length = 0; + + showln(message); + + // Loop for the reading of nclob data in chunks. + while ((length = nclobStream.read(buffer)) != -1) + showln(new String(buffer, 0, length)); + + show(""); + } + } + + // Execute a query to get the clob column data. + // Iterate through the result as LONG type. + private void executeClobAsLongQuery(int id) throws Exception { + try (PreparedStatement pstmt = conn + .prepareStatement("SELECT CLOB_DATA FROM " + TABLE_NAME + " WHERE LOB_ID=?")) { + // Fetch LOB data as LONG. + // LOB data can be read using the same streaming mechanism as for LONG RAW + // and LONG data. + // This produces a direct stream on the data as if it were a LONG RAW or + // LONG column. + // This technique is limited to Oracle Database 10g release 1 (10.1) and + // later. + // The benefit of fetching a CLOB as a LONG (or a BLOB as a LONG_RAW) is + // that the data + // will be inlined in the data row that is fetched which may become handy + // when the locator + // is not needed and you just need to read the data into a stream. + // The downside of it is that you don't get the locator and the rows are + // fetched one by one. + // The LOB prefetch gives better benefits such as being able to fetch + // multiple rows in one single roundtrip, + // getting the length of the LOB immediately and getting the locator. + // Overall relying on LOB prefetch is always preferable compared to the + // LOB to LONG technique. + ((OracleStatement) pstmt).defineColumnType(2, Types.LONGVARBINARY); + + pstmt.setInt(1, id); + try (ResultSet rset = pstmt.executeQuery()) { + show("LOB_ID = " + id); + while (rset.next()) { + String c = rset.getString(1); + + show("CLOB_DATA as LONG = " + c); + } + } + } + } + + // If you select LOB columns into a result set, some or all of the data is + // prefetched to the client, when the locator is fetched. It saves the first + // roundtrip to + // retrieve data by deferring all preceding operations until fetching from the + // locator. + // + // The prefetch size is specified in bytes for BLOBs and in characters for + // CLOBs. It can be + // specified by setting the connection property + // oracle.jdbc.defaultLobPrefetchSize. + // The value of this property can be overridden at statement level by using, + // oracle.jdbc.OracleStatement.setLobPrefetchSize(int) method. + // + // The default prefetch size is 4000. + // + // Execute a query to get the clob column data. + // Iterate through the result. + private void executeClobQueryWithLobPrefetchSize(int id) throws Exception { + try (PreparedStatement pstmt = conn + .prepareStatement("SELECT CLOB_DATA FROM " + TABLE_NAME + " WHERE LOB_ID=?")) { + // Fine tune lob prefetch size to reduce number of round trips. + ((OracleStatement) pstmt).setLobPrefetchSize(5000); + + pstmt.setInt(1, id); + try (ResultSet rset = pstmt.executeQuery()) { + show("LOB_ID = " + id); + while (rset.next()) { + Clob c = rset.getClob(1); + + getAndDisplayClobData("CLOB_DATA = ", c); + } + } + } + } + + // ==============================Utility Methods============================== + + private void truncateTable() throws SQLException { + try (Statement stmt = conn.createStatement()) { + String sql = "TRUNCATE TABLE " + TABLE_NAME; + stmt.execute(sql); + } + } + + 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); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } +} + +/* + * ==================================== Expected Output + * ==================================== + * + * ======== Clob Sample ======== LOB_ID = 1 CLOB_DATA = Book Title - Java for Dummies + * ======== Clob Sample with an empty clob ======== LOB_ID = 2 CLOB_DATA = { "books": [ { + * "isbn": "9781593275846", "title": "Eloquent JavaScript, Second Edition", + * "subtitle": "A Modern Introduction to Programming", "author": + * "Marijn Haverbeke", "published": "2014-12-14T00:00:00.000Z", "publisher": + * "No Starch Press", "pages": 472, "description": + * "JavaScript lies at the heart of almost every modern web application, from social apps to the newest browser-based games. Though simple for beginners to pick up and play with, JavaScript is a flexible, complex language that you can use to build full-scale applications." + * , "website": "http://eloquentjavascript.net/" }, { "isbn": "9781449331818", + * "title": "Learning JavaScript Design Patterns", "subtitle": + * "A JavaScript and jQuery Developer's Guide", "author": "Addy Osmani", + * "published": "2012-07-01T00:00:00.000Z", "publisher": "O'Reilly Media", + * "pages": 254, "description": + * "With Learning JavaScript Design Patterns, you'll learn how to write beautiful, structured, and maintainable JavaScript by applying classical and modern design patterns to the language. If you want to keep your code efficient, more manageable, and up-to-date with the latest best practices, this book is for you." + * , "website": + * "http://www.addyosmani.com/resources/essentialjsdesignpatterns/book/" } ] } + * + * ======== Blob Sample ======== LOB_ID = 3 01 02 03 77 80 04 05 ======== Blob + * Sample with an empty blob ======== LOB_ID = 4 First 25 bytes of a Blob column 137 + * 80 78 71 13 10 26 10 00 00 00 13 73 72 68 82 00 00 00 200 00 00 00 198 08 + * Total blob data length:10422 ======== Nclob Sample ======== LOB_ID = 5 NCLOB_DATA = Book + * Title - Oracle ? for Dummies ======== Temporary Clob Sample ======== + * CLOB.isTemporary: true LOB_ID = 6 CLOB_DATA = Book Title - JDBC for Dummies ======== Clob + * as Long Sample ======== LOB_ID = 7 CLOB_DATA as LONG = Book Title - JNI for Dummies + * ======== Clob Sample with LobPrefetchSize ======== LOB_ID = 8 CLOB_DATA = Book Title - + * Linux for Dummies + * + */ diff --git a/java/jdbc/BasicSamples/PLSQLSample.java b/java/jdbc/BasicSamples/PLSQLSample.java new file mode 100755 index 00000000..17015b65 --- /dev/null +++ b/java/jdbc/BasicSamples/PLSQLSample.java @@ -0,0 +1,548 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This sample demonstrates the usage of PL/SQL Stored Procedures and Functions in JDBC. + * + * Each unit of this sample demonstrates the following: + * 1. creating a PL/SQL Stored Procedure/Function, + * 2. invoking the Stored Procedure/Function with IN, OUT, IN OUT parameters, + * 3. and the correspondence of IN/OUT parameter with get/set/register methods. + * + * It is required that applications have Oracle JDBC driver jar (ojdbc8.jar) in + * the class-path, and that the database back end supports SQL (this sample uses + * an Oracle Database). + * + * To run the sample, you must provide non-default and working values for ALL 3 + * of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java PLSQLSample -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.CallableStatement; +import java.sql.Connection; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; +import java.sql.Types; + +import oracle.jdbc.pool.OracleDataSource; + +public class PLSQLSample { + + private final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + private final static String DEFAULT_USER = "myuser"; + private final static String DEFAULT_PASSWORD = "mypassword"; + //You must provide non-default values for ALL 3 to execute the program + private static String url = DEFAULT_URL; + private static String user = DEFAULT_USER; + private static String password = DEFAULT_PASSWORD; + private static final String TABLE_NAME = "PLSQL_JDBC_SAMPLE"; + + public static void main(String args[]) throws Exception { + Util.getRealUserPasswordUrl(args); + + PLSQLSample sample = new PLSQLSample(); + sample.run(); + } + + private void run() { + try (Connection conn = getConnection()) { + + // Initialize the table + init(conn); + + // Demonstrate how a no arg PLSQL procedure can be invoked. + demoPlsqlProcedureNoParams(conn); + + // Demonstrate how a PLSQL procedure with IN parameters can be invoked. + demoPlsqlProcedureINParams(conn); + + // Demonstrate how a PLSQL procedure with OUT parameters can be invoked. + demoPlsqlProcedureOUTParams(conn); + + // Demonstrate how a PLSQL procedure with IN OUT parameters can be invoked. + demoPlsqlProcedureINOUTParams(conn); + + // Demonstrate how a no arg PLSQL function can be invoked. + demoPlsqlFunctionNoParams(conn); + + // Demonstrate how a PLSQL function with IN parameters can be invoked. + demoPlsqlFunctionINParams(conn); + + // Demonstrate how a PLSQL function with OUT parameters can be invoked. + demoPlsqlFunctionOUTParams(conn); + + // Demonstrate how a PLSQL function with IN OUT parameters can be invoked. + demoPlsqlFunctionINOUTParams(conn); + + // Cleanup the database after the demo. + truncateTable(conn); + } catch (SQLException sqlEx) { + Util.showError("run", sqlEx); + } + } + + private void init(Connection conn) throws SQLException { + + // Truncate the table. + truncateTable(conn); + + // Load the table with few rows. + loadTable(conn); + } + + private void loadTable(Connection conn) throws SQLException { + String insertDml = "INSERT INTO "+TABLE_NAME+" (NUM, NAME, INSERTEDBY) VALUES (?,?,?)"; + try (PreparedStatement prepStmt = conn.prepareStatement(insertDml)) { + prepStmt.setInt(1, 1); + prepStmt.setString(2, "ONE"); + prepStmt.setString(3, "default"); + prepStmt.addBatch(); + + prepStmt.setInt(1, 2); + prepStmt.setString(2, "TWO"); + prepStmt.setString(3, "default"); + prepStmt.addBatch(); + + prepStmt.setInt(1, 3); + prepStmt.setString(2, "THREE"); + prepStmt.setString(3, "default"); + prepStmt.addBatch(); + + prepStmt.setInt(1, 4); + prepStmt.setString(2, "FOUR"); + prepStmt.setString(3, "default"); + prepStmt.addBatch(); + + prepStmt.executeBatch(); + } + + // Display initial set of rows loaded into the table. + Util.show("Table '"+TABLE_NAME+"' is loaded with: "); + displayRows(conn, "default"); + } + + private void truncateTable(Connection conn) { + String sql = "TRUNCATE TABLE " + TABLE_NAME; + Util.show(sql); + Util.trySql(conn, sql); + } + + private void demoPlsqlProcedureNoParams(Connection conn) throws SQLException { + // Create a PLSQL stored procedure that takes no arguments. + final String PROC_NAME = "ProcNoParams"; + String sql = "CREATE OR REPLACE PROCEDURE "+PROC_NAME+" IS " + + "BEGIN " + + "INSERT INTO "+TABLE_NAME+" VALUES (5, 'FIVE', '"+PROC_NAME+"'); " + + "INSERT INTO "+TABLE_NAME+" VALUES (6, 'SIX', '"+PROC_NAME+"'); " + + "INSERT INTO "+TABLE_NAME+" VALUES (7, 'SEVEN', '"+PROC_NAME+"'); " + + "INSERT INTO "+TABLE_NAME+" VALUES (8, 'EIGHT', '"+PROC_NAME+"'); " + + "END; "; + Util.show(sql); + Util.doSql(conn, sql); + + // Invoke the stored procedure. + sql = "CALL "+PROC_NAME+"()"; + try (CallableStatement callStmt = conn.prepareCall(sql)) { + callStmt.execute(); + + // Display rows inserted by the above stored procedure call. + Util.show("Rows inserted by the stored procedure '"+PROC_NAME+"' are: "); + displayRows(conn, PROC_NAME); + } catch (SQLException sqlEx) { + Util.showError("demoPlsqlProcedureNoArgs", sqlEx); + } finally { + // Drop the procedure when done with it. + Util.doSql(conn, "DROP PROCEDURE "+PROC_NAME); + } + } + + private void demoPlsqlProcedureINParams(Connection conn) throws SQLException { + // Create a PLSQL stored procedure with IN parameters. + final String PROC_NAME = "ProcINParams"; + String sql = "CREATE OR REPLACE PROCEDURE "+PROC_NAME+"(num IN NUMBER, name IN VARCHAR2, insertedBy IN VARCHAR2) IS " + + "BEGIN " + + "INSERT INTO "+TABLE_NAME+" VALUES (num, name, insertedBy); " + + "END; "; + Util.show(sql); + Util.doSql(conn, sql); + + // Invoke the stored procedure. + sql = "CALL "+PROC_NAME+"(?,?,?)"; + try (CallableStatement callStmt = conn.prepareCall(sql)) { + callStmt.setInt(1, 9); + callStmt.setString(2, "NINE"); + callStmt.setString(3, PROC_NAME); + callStmt.addBatch(); + + callStmt.setInt(1, 10); + callStmt.setString(2, "TEN"); + callStmt.setString(3, PROC_NAME); + callStmt.addBatch(); + + callStmt.setInt(1, 11); + callStmt.setString(2, "ELEVEN"); + callStmt.setString(3, PROC_NAME); + callStmt.addBatch(); + + callStmt.setInt(1, 12); + callStmt.setString(2, "TWELVE"); + callStmt.setString(3, PROC_NAME); + callStmt.addBatch(); + + callStmt.executeBatch(); + + // Display rows inserted by the above stored procedure call. + Util.show("Rows inserted by the stored procedure '"+PROC_NAME+"' are: "); + displayRows(conn, PROC_NAME); + } catch (SQLException sqlEx) { + Util.showError("demoPlsqlProcedureINParams", sqlEx); + } finally { + // Drop the procedure when done with it. + Util.doSql(conn, "DROP PROCEDURE "+PROC_NAME); + } + } + + private void demoPlsqlProcedureOUTParams(Connection conn) throws SQLException { + // Create a PLSQL stored procedure with OUT parameters. + final String PROC_NAME = "ProcOUTParams"; + String sql = "CREATE OR REPLACE PROCEDURE "+PROC_NAME+"(num IN NUMBER, name IN VARCHAR2, insertedBy IN VARCHAR2, numInserted OUT NUMBER) IS " + + "BEGIN " + + "INSERT INTO "+TABLE_NAME+" VALUES (num, name, insertedBy); " + + "numInserted := num; " + + "END; "; + Util.show(sql); + Util.doSql(conn, sql); + + // Invoke the stored procedure. + sql = "CALL "+PROC_NAME+"(?,?,?,?)"; + try (CallableStatement callStmt = conn.prepareCall(sql)) { + callStmt.setInt(1, 13); + callStmt.setString(2, "THIRTEEN"); + callStmt.setString(3, PROC_NAME); + callStmt.registerOutParameter(4, Types.INTEGER); + callStmt.execute(); + + // Display rows inserted by the above stored procedure call. + Util.show("Rows inserted by the stored procedure '"+PROC_NAME+"' are: "); + displayRows(conn, PROC_NAME); + + // Show the value of OUT parameter after the stored procedure call. + Util.show("The out parameter value of stored procedure '"+PROC_NAME+"' returned "+callStmt.getInt(4)+"."); + + } catch (SQLException sqlEx) { + Util.showError("demoPlsqlProcedureOUTParams", sqlEx); + } finally { + // Drop the procedure when done with it. + Util.doSql(conn, "DROP PROCEDURE "+PROC_NAME); + } + } + + private void demoPlsqlProcedureINOUTParams(Connection conn) throws SQLException { + // Create a PLSQL stored procedure with IN OUT parameters. + final String PROC_NAME = "ProcINOUTParams"; + String sql = "CREATE OR REPLACE PROCEDURE "+PROC_NAME+"(num IN OUT NUMBER, name IN OUT VARCHAR2, insertedBy IN VARCHAR2) IS " + + "BEGIN " + + "INSERT INTO "+TABLE_NAME+" VALUES (num, name, insertedBy); " + + "num := 0; " + + "name := 'ZERO'; " + + "END; "; + Util.show(sql); + Util.doSql(conn, sql); + + // Invoke the stored procedure. + sql = "CALL "+PROC_NAME+"(?,?,?)"; + try (CallableStatement callStmt = conn.prepareCall(sql)) { + callStmt.setInt(1, 14); + callStmt.registerOutParameter(1, Types.INTEGER); + + callStmt.setString(2, "FOURTEEN"); + callStmt.registerOutParameter(2, Types.VARCHAR); + + callStmt.setString(3, PROC_NAME); + callStmt.execute(); + + // Display rows inserted by the above stored procedure call. + Util.show("Rows inserted by the stored procedure '"+PROC_NAME+"' are: "); + displayRows(conn, PROC_NAME); + + // Show the values of OUT parameters after the stored procedure call. + Util.show("Out parameter values of stored procedure '" + PROC_NAME + "': num = " + callStmt.getInt(1) + + ", name = " + callStmt.getString(2) + "."); + } catch (SQLException sqlEx) { + Util.showError("demoPlsqlProcedureINOUTParams", sqlEx); + } finally { + // Drop the procedure when done with it. + Util.doSql(conn, "DROP PROCEDURE "+PROC_NAME); + } + } + + private void demoPlsqlFunctionNoParams(Connection conn) throws SQLException { + // Create a PLSQL function that takes no arguments. + final String FUNC_NAME = "FuncNoParams"; + String sql = "CREATE OR REPLACE FUNCTION "+FUNC_NAME+" RETURN NUMBER IS " + + "BEGIN " + + "INSERT INTO "+TABLE_NAME+" VALUES (15, 'FIFTEEN', '"+FUNC_NAME+"'); " + + "INSERT INTO "+TABLE_NAME+" VALUES (16, 'SIXTEEN', '"+FUNC_NAME+"'); " + + "INSERT INTO "+TABLE_NAME+" VALUES (17, 'SEVENTEEN', '"+FUNC_NAME+"'); " + + "INSERT INTO "+TABLE_NAME+" VALUES (18, 'EIGHTEEN', '"+FUNC_NAME+"'); " + + "RETURN 4;" // Return number of row inserted into the table. + + "END; "; + Util.show(sql); + Util.doSql(conn, sql); + + // Invoke the PLSQL function. + sql = "BEGIN ? := "+FUNC_NAME+"; end;"; + try (CallableStatement callStmt = conn.prepareCall(sql)) { + callStmt.registerOutParameter (1, Types.INTEGER); + callStmt.execute(); + + // Display rows inserted by the above PLSQL function call. + Util.show("Rows inserted by the PLSQL function '"+FUNC_NAME+"' are: "); + displayRows(conn, FUNC_NAME); + + // Show the value returned by the PLSQL function. + Util.show("The value returned by the PLSQL function '"+FUNC_NAME+"' is "+callStmt.getInt(1)+"."); + } catch (SQLException sqlEx) { + Util.showError("demoPlsqlFunctionNoParams", sqlEx); + } finally { + // Drop the function when done with it. + Util.doSql(conn, "DROP FUNCTION "+FUNC_NAME); + } + } + + private void demoPlsqlFunctionINParams(Connection conn) throws SQLException { + // Create a PLSQL function with IN parameters. + final String FUNC_NAME = "FuncINParams"; + String sql = "CREATE OR REPLACE FUNCTION "+FUNC_NAME+"(num IN NUMBER, name IN VARCHAR2, insertedBy IN VARCHAR2) RETURN NUMBER IS " + + "BEGIN " + + "INSERT INTO "+TABLE_NAME+" VALUES (num, name, insertedBy); " + + "RETURN 1;" // Return number of row inserted into the table. + + "END; "; + Util.show(sql); + Util.doSql(conn, sql); + + // Invoke the PLSQL function. + sql = "BEGIN ? := "+FUNC_NAME+"(?,?,?); end;"; + try (CallableStatement callStmt = conn.prepareCall(sql)) { + callStmt.registerOutParameter (1, Types.INTEGER); + callStmt.setInt(2, 19); + callStmt.setString(3, "NINETEEN"); + callStmt.setString(4, FUNC_NAME); + callStmt.execute(); + + // Display rows inserted by the above PLSQL function call. + Util.show("Rows inserted by the PLSQL function '"+FUNC_NAME+"' are: "); + displayRows(conn, FUNC_NAME); + + // Show the value returned by the PLSQL function. + Util.show("The value returned by the PLSQL function '"+FUNC_NAME+"' is "+callStmt.getInt(1)+"."); + } catch (SQLException sqlEx) { + Util.showError("demoPlsqlFunctionINParams", sqlEx); + } finally { + // Drop the function when done with it. + Util.doSql(conn, "DROP FUNCTION "+FUNC_NAME); + } + } + + private void demoPlsqlFunctionOUTParams(Connection conn) throws SQLException { + // Create a PLSQL function with IN parameters. + final String FUNC_NAME = "FuncOUTParams"; + String sql = "CREATE OR REPLACE FUNCTION "+FUNC_NAME+"(num IN NUMBER, name IN VARCHAR2, insertedBy IN VARCHAR2, numInserted OUT NUMBER) RETURN NUMBER IS " + + "BEGIN " + + "INSERT INTO "+TABLE_NAME+" VALUES (num, name, insertedBy); " + + "numInserted := num; " + + "RETURN 1;" // Return number of row inserted into the table. + + "END; "; + Util.show(sql); + Util.doSql(conn, sql); + + // Invoke the PLSQL function. + sql = "BEGIN ? := "+FUNC_NAME+"(?,?,?,?); end;"; + try (CallableStatement callStmt = conn.prepareCall(sql)) { + callStmt.registerOutParameter (1, Types.INTEGER); + callStmt.setInt(2, 20); + callStmt.setString(3, "TWENTY"); + callStmt.setString(4, FUNC_NAME); + callStmt.registerOutParameter(5, Types.INTEGER); + callStmt.execute(); + + // Display rows inserted by the above PLSQL function call. + Util.show("Rows inserted by the PLSQL function '"+FUNC_NAME+"' are: "); + displayRows(conn, FUNC_NAME); + + // Show the value returned by the PLSQL function. + Util.show("The value returned by the PLSQL function '"+FUNC_NAME+"' is "+callStmt.getInt(1)+"."); + + // Show the values of OUT parameters after the PLSQL function call. + Util.show("Out parameter value of PLSQL function '" + FUNC_NAME + "': num = " + callStmt.getInt(5) + "."); + } catch (SQLException sqlEx) { + Util.showError("demoPlsqlFunctionOUTParams", sqlEx); + } finally { + // Drop the function when done with it. + Util.doSql(conn, "DROP FUNCTION "+FUNC_NAME); + } + } + + private void demoPlsqlFunctionINOUTParams(Connection conn) throws SQLException { + // Create a PLSQL function with IN OUT parameters. + final String FUNC_NAME = "FuncINOUTParams"; + String sql = "CREATE OR REPLACE FUNCTION "+FUNC_NAME+"(num IN OUT NUMBER, name IN OUT VARCHAR2, insertedBy IN VARCHAR2) RETURN NUMBER IS " + + "BEGIN " + + "INSERT INTO "+TABLE_NAME+" VALUES (num, name, insertedBy); " + + "num := 0; " + + "name := 'ZERO'; " + + "RETURN 1;" // Return number of row inserted into the table. + + "END; "; + Util.show(sql); + Util.doSql(conn, sql); + + // Invoke the PLSQL function. + sql = "BEGIN ? := "+FUNC_NAME+"(?,?,?); end;"; + try (CallableStatement callStmt = conn.prepareCall(sql)) { + callStmt.registerOutParameter (1, Types.INTEGER); + + callStmt.registerOutParameter (2, Types.INTEGER); + callStmt.setInt(2, 20); + + callStmt.registerOutParameter (3, Types.VARCHAR); + callStmt.setString(3, "TWENTY"); + + callStmt.setString(4, FUNC_NAME); + callStmt.execute(); + + // Display rows inserted by the above PLSQL function call. + Util.show("Rows inserted by the PLSQL function '"+FUNC_NAME+"' are: "); + displayRows(conn, FUNC_NAME); + + // Show the value returned by the PLSQL function. + Util.show("The value returned by the PLSQL function '"+FUNC_NAME+"' is "+callStmt.getInt(1)+"."); + + // Show the values of OUT parameters after the PLSQL function call. + Util.show("Out parameter values of PLSQL function '" + FUNC_NAME + "': num = " + callStmt.getInt(2) + + ", name = " + callStmt.getString(3) + "."); + } catch (SQLException sqlEx) { + Util.showError("demoPlsqlFunctionINOUTParams", sqlEx); + } finally { + // Drop the function when done with it. + Util.doSql(conn, "DROP FUNCTION "+FUNC_NAME); + } + } + + private void displayRows(Connection conn, String insertedByBind) throws SQLException { + + String sql = "SELECT * FROM "+TABLE_NAME+" WHERE insertedBy = ?"; + try (PreparedStatement prepStmt = conn.prepareStatement(sql)) { + prepStmt.setString(1, insertedByBind); + + ResultSet rs = prepStmt.executeQuery(); + while (rs.next()) { + Util.show(rs.getInt(1)+"\t"+rs.getString(2)+"\t"+rs.getString(3)); + } + } + } + + // Get a connection using the driver data source. + private Connection getConnection() throws SQLException { + OracleDataSource ods = new OracleDataSource(); + ods.setURL(url); + ods.setUser(user); + ods.setPassword(password); + + // Creates a physical connection to the database. + return ods.getConnection(); + } + + // Utility methods. + private static class Util { + + 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 + ": "); + } + + public static void show(String msg) { + System.out.println(msg); + } + + public static void showError(String msg, Throwable exc) { + System.err.println(msg + " hit error: " + exc.getMessage()); + } + + // Get specified option value from command-line. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } + + public static void trySql(Connection conn, String sql) { + try (Statement stmt = conn.createStatement()) { + stmt.execute(sql); + } catch (SQLException e) { + // Ignore the exception. + } + } + + public static void doSql(Connection conn, String sql) throws SQLException { + try (Statement stmt = conn.createStatement()) { + stmt.execute(sql); + } + } + + } + +} + diff --git a/java/jdbc/BasicSamples/PreparedStatementBindingsSample.java b/java/jdbc/BasicSamples/PreparedStatementBindingsSample.java new file mode 100755 index 00000000..ef95c538 --- /dev/null +++ b/java/jdbc/BasicSamples/PreparedStatementBindingsSample.java @@ -0,0 +1,417 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/** + * DESCRIPTION + * + * A simple illustration of CRUD operation using the PreparedStatement with named bindings. + */ + +import java.io.BufferedReader; +import java.io.IOException; +import java.io.InputStreamReader; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; +import java.time.LocalDate; +import java.time.format.DateTimeParseException; +import java.util.Scanner; + +import oracle.jdbc.OracleConnection; +import oracle.jdbc.OraclePreparedStatement; +import oracle.jdbc.pool.OracleDataSource; + + +public class PreparedStatementBindingsSample { + private static final int USER_OPTION_SELECTALL = 1; + private static final int USER_OPTION_SELECTONE = 2; + private static final int USER_OPTION_INSERT = 3; + private static final int USER_OPTION_UPDATE = 4; + private static final int USER_OPTION_DELETE = 5; + private static final int USER_OPTION_EXIT = 0; + + + private static final String DEFAULT_USER = "myuser"; + private static final String DEFAULT_URL + = "jdbc:oracle:thin:@//myhost:1521/myservice"; + + private final String user; + private final String password; + private final String url; + + private static final String SQL_INSERT = "INSERT INTO EMP (EMPNO, ENAME, JOB, HIREDATE, SAL) VALUES(:empid, :empname, " + + ":desgn, :joiningdate, :salary)"; + private static final String SQL_UPDATE = "UPDATE EMP SET ENAME = :empname, " + + "JOB = :desgn, HIREDATE = :joiningdate, " + + "SAL = :salary WHERE EMPNO = :empid"; + private static final String SQL_DELETE = "DELETE FROM EMP WHERE EMPNO = :empid"; + private static final String SQL_SELECT_ALL = "SELECT * FROM EMP"; + private static final String SQL_SELECT_ONE = "SELECT * FROM EMP WHERE EMPNO = :empid"; + + + /** + * Creates an PreparedStatementDemo instance with the given details. + * @param user + * @param pwd + * @param url + */ + private PreparedStatementBindingsSample(String user, String pwd, String url) { + this.user = user; + this.password = pwd; + this.url = url; + } + + /** + * Get a connection from the Oracle Database. + * and performs CRUD operation based on the user input. + * @throws SQLException + */ + private void startDemo() throws SQLException { + OracleConnection connection = getConnection(); + try { + while (true) { + int userOption = getOption(); + switch(userOption) { + case USER_OPTION_SELECTONE : + selectOne(connection); + break; + case USER_OPTION_SELECTALL : + selectAll(connection); + break; + case USER_OPTION_INSERT : + insert(connection); + break; + case USER_OPTION_UPDATE : + update(connection); + break; + case USER_OPTION_DELETE : + delete(connection); + break; + case USER_OPTION_EXIT : + show("Bye !!"); + return; + default : + show("Invalid option : " + userOption); + } + } + } + finally { + connection.close(); + } + } + + + /** + * Creates an OracleConnection instance and return it. + * @return oracleConnection + * @throws SQLException + */ + private OracleConnection getConnection() throws SQLException { + OracleDataSource ods = new OracleDataSource(); + ods.setUser(user); + ods.setPassword(password); + ods.setURL(url); + return (OracleConnection)ods.getConnection(); + } + + /** + * Gets employee details from the user and insert into + * the Employee table. + * @param connection + */ + private void insert(OracleConnection connection) { + try(OraclePreparedStatement pstmt = + (OraclePreparedStatement)connection.prepareStatement(SQL_INSERT)) { + Employee employee = getEmployeeFromConsole(); + if(employee == null) { + showError("Unable to get employee details."); + return; + } + pstmt.setIntAtName("empid", employee.getId()); + pstmt.setStringAtName("empname", employee.getName()); + pstmt.setStringAtName("desgn", employee.getDesignation()); + pstmt.setObjectAtName("joiningdate", employee.getJoiningDate()); + pstmt.setDoubleAtName("salary", employee.getSalary()); + pstmt.execute(); + show("Insert successfull !!"); + } + catch(SQLException sqle) { + sqle.printStackTrace(); + } + } + + /** + * Gets employee details from the user and update row in + * the Employee table with the new details. + * @param connection + */ + private void update(OracleConnection connection) { + try(OraclePreparedStatement pstmt = + (OraclePreparedStatement)connection.prepareStatement(SQL_UPDATE)) { + Employee employee = getEmployeeFromConsole(); + if(employee == null) { + showError("Unable to get employee details."); + return; + } + pstmt.setIntAtName("empid", employee.getId()); + pstmt.setStringAtName("empname", employee.getName()); + pstmt.setStringAtName("desgn", employee.getDesignation()); + pstmt.setObjectAtName("joiningdate", employee.getJoiningDate()); + pstmt.setDoubleAtName("salary", employee.getSalary()); + final int numberOfRecordUpdated = pstmt.executeUpdate(); + show("Number of records updated : " + numberOfRecordUpdated); + } + catch(SQLException sqle) { + sqle.printStackTrace(); + } + } + + /** + * Gets the employee id from the user and deletes the employee + * row from the employee table. + * @param connection + */ + private void delete(OracleConnection connection) { + try(OraclePreparedStatement pstmt = + (OraclePreparedStatement)connection.prepareStatement(SQL_DELETE)) { + int employeeId = getEmployeeIDFromConsole(); + pstmt.setIntAtName("empid", employeeId); + final int numberOfRecordDeleted = pstmt.executeUpdate(); + show("Number of records deleted : " + numberOfRecordDeleted); + } + catch(SQLException sqle) { + sqle.printStackTrace(); + } + } + + /** + * Gets the employee id from the user and retrieve the specific + * employee details from the employee table. + * @param connection + */ + private void selectOne(OracleConnection connection) { + int empId = getEmployeeIDFromConsole(); + try(OraclePreparedStatement pstmt = + (OraclePreparedStatement)connection.prepareStatement(SQL_SELECT_ONE)) { + pstmt.setIntAtName("empid", empId); + ResultSet rs = pstmt.executeQuery(); + if(rs.next()) { + Employee emp = new Employee(rs.getInt("EMPNO"), + rs.getString("ENAME"), rs.getString("JOB"), + LocalDate.parse(rs.getString("HIREDATE").substring(0, 10)), rs.getDouble("SAL")); + emp.print(); + } + else { + show("No records found for the employee id : " + empId); + } + } + catch(SQLException sqle) { + sqle.printStackTrace(); + } + } + + /** + * Selects all the rows from the employee table. + * @param connection + */ + private void selectAll(OracleConnection connection) { + try(OraclePreparedStatement pstmt = + (OraclePreparedStatement)connection.prepareStatement(SQL_SELECT_ALL)) { + ResultSet rs = pstmt.executeQuery(); + while(rs.next()) { + Employee emp = new Employee(rs.getInt("EMPNO"), + rs.getString("ENAME"), rs.getString("JOB"), + LocalDate.parse(rs.getString("HIREDATE").substring(0, 10)), rs.getDouble("SAL")); + emp.print(); + } + } + catch(SQLException sqle) { + sqle.printStackTrace(); + } + } + + // Start the main with the command "java PreparedStatementDemo -u "" -l "" + public static void main(String args[]) throws SQLException, IOException { + // Gets the URL and USER value from command line arguments + String url = getCmdOptionValue(args, "-l", DEFAULT_URL); + String user = getCmdOptionValue(args, "-u", DEFAULT_USER); + + // DB user's Password must be entered + String pwd = readPassword(" Password for " + user + ": "); + + PreparedStatementBindingsSample demo = new PreparedStatementBindingsSample(user, pwd, url); + demo.startDemo(); + } + + private static String readPassword(String prompt) throws IOException { + if (System.console() == null) { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + System.out.print(prompt); + return r.readLine(); + } + else { + return new String(System.console().readPassword(prompt)); + } + } + + // Get specified option value from command-line, or use default value + private static String getCmdOptionValue(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("")) { + show("No value for Option " + optionName + ", use default."); + argValue = defaultVal; + } + found = true; + } + } + + if (!found) { + show("No Option " + optionName + " specified, use default."); + argValue = defaultVal; + } + } + catch (Exception e) { + showError("getOptionValue" + e.getMessage()); + } + return argValue; + } + + /** + * Get the user option to perform the table operation. + * + * @return + */ + private static int getOption() { + int userOption = -1; + try { + Scanner scanner = new Scanner(System.in); + System.out.println("1 - Select All, 2 - Select One, 3 - Insert, 4 - Update, 5 - Delete, 0 - Exit"); + System.out.println("Enter Option :"); + userOption = Integer.parseInt(scanner.nextLine()); + } + catch(Exception e) { + /* Ignore exception */ + } + return userOption; + } + + /** + * An utility method to get the employee details from the user. + * + * @return employeeObj + */ + private static Employee getEmployeeFromConsole() { + Employee empObj = null;; + try { + Scanner scanner = new Scanner(System.in); + System.out.println("Enter Employee Details"); + System.out.println("ID : "); + int id = Integer.parseInt(scanner.nextLine()); + System.out.println("Name : "); + String name = scanner.nextLine(); + System.out.println("Designation : "); + String designation = scanner.nextLine(); + System.out.println("Joining Date(yyyy-mm-dd) : "); + LocalDate joiningDate = LocalDate.parse(scanner.nextLine()); + System.out.println("Salary : "); + double salary = Double.parseDouble(scanner.nextLine()); + empObj = new Employee(id, name, designation, joiningDate, salary); + } + catch(DateTimeParseException dte) { + showError("Invalid Date format !!"); + } + catch(Exception e) { + /* Ignore exception */ + e.printStackTrace(); + } + return empObj; + } + + /** + * An utility method to get the employee id from the user. + * + * @return employeeID + */ + private static int getEmployeeIDFromConsole() { + int empId = -1; + try { + Scanner scanner = new Scanner(System.in); + System.out.println("Enter Employee ID :"); + empId = Integer.parseInt(scanner.nextLine()); + } + catch(Exception e) { + /* Ignore exception */ + } + return empId; + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg) { + System.out.println("Error : " + msg); + } + + /** + * A simple class to represent the employee table structure + * An instance of this represents a row in employee table. + */ + static class Employee { + private int id; + private String name; + private String designation; + private LocalDate joiningDate; + private double salary; + + Employee(int id, String name, String designation, LocalDate joiningDate, + double salary) { + super(); + this.id = id; + this.name = name; + this.designation = designation; + this.joiningDate = joiningDate; + this.salary = salary; + } + + int getId() { + return id; + } + + String getName() { + return name; + } + + String getDesignation() { + return designation; + } + + LocalDate getJoiningDate() { + return joiningDate; + } + + double getSalary() { + return salary; + } + + void print() { + show("/----------------------------------------------------------------/"); + show("ID : " + id); + show("NAME : " + name); + show("Designation : " + designation); + show("Joining Date: " + joiningDate); + show("Salary : " + salary); + show("/----------------------------------------------------------------/"); + } + + } +} diff --git a/java/jdbc/BasicSamples/PreparedStatementSample.java b/java/jdbc/BasicSamples/PreparedStatementSample.java new file mode 100755 index 00000000..005bbd08 --- /dev/null +++ b/java/jdbc/BasicSamples/PreparedStatementSample.java @@ -0,0 +1,410 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/** + * DESCRIPTION + * + * A simple illustration of CRUD operation using the PreparedStatement object. + */ + +import java.io.BufferedReader; +import java.io.IOException; +import java.io.InputStreamReader; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; +import java.time.LocalDate; +import java.time.format.DateTimeParseException; +import java.util.Scanner; + +import oracle.jdbc.OracleConnection; +import oracle.jdbc.pool.OracleDataSource; + + +public class PreparedStatementSample { + private static final int USER_OPTION_SELECTALL = 1; + private static final int USER_OPTION_SELECTONE = 2; + private static final int USER_OPTION_INSERT = 3; + private static final int USER_OPTION_UPDATE = 4; + private static final int USER_OPTION_DELETE = 5; + private static final int USER_OPTION_EXIT = 0; + + private static final String DEFAULT_USER = "myuser"; + private static final String DEFAULT_URL + = "jdbc:oracle:thin:@//myhost:1521/myservice"; + + private final String user; + private final String password; + private final String url; + + private static final String SQL_INSERT = "INSERT INTO EMP (EMPNO, ENAME, JOB, HIREDATE, SAL) VALUES(?, ?, ?, ?, ?)"; + private static final String SQL_UPDATE = "UPDATE EMP SET ENAME = ?, JOB = ?, HIREDATE = ?, SAL = ? WHERE EMPNO = ?"; + private static final String SQL_DELETE = "DELETE FROM EMP WHERE EMPNO = ?"; + private static final String SQL_SELECT_ALL = "SELECT * FROM EMP"; + private static final String SQL_SELECT_ONE = "SELECT * FROM EMP WHERE EMPNO = ?"; + + + /** + * Creates an PreparedStatementDemo instance with the given details. + * @param user + * @param pwd + * @param url + */ + private PreparedStatementSample(String user, String pwd, String url) { + this.user = user; + this.password = pwd; + this.url = url; + } + + /** + * Get a connection from the Oracle Database. + * and performs CRUD operation based on the user input. + * @throws SQLException + */ + private void startDemo() throws SQLException { + OracleConnection connection = getConnection(); + try { + while (true) { + int userOption = getOption(); + switch(userOption) { + case USER_OPTION_SELECTONE : + selectOne(connection); + break; + case USER_OPTION_SELECTALL : + selectAll(connection); + break; + case USER_OPTION_INSERT : + insert(connection); + break; + case USER_OPTION_UPDATE : + update(connection); + break; + case USER_OPTION_DELETE : + delete(connection); + break; + case USER_OPTION_EXIT : + show("Bye !!"); + return; + default : + show("Invalid option : " + userOption); + } + } + } + finally { + connection.close(); + } + } + + + /** + * Creates an OracleConnection instance and return it. + * @return oracleConnection + * @throws SQLException + */ + private OracleConnection getConnection() throws SQLException { + OracleDataSource ods = new OracleDataSource(); + ods.setUser(user); + ods.setPassword(password); + ods.setURL(url); + return (OracleConnection)ods.getConnection(); + } + + /** + * Gets employee details from the user and insert into + * the Employee table. + * @param connection + */ + private void insert(OracleConnection connection) { + try(PreparedStatement pstmt = connection.prepareStatement(SQL_INSERT)) { + Employee employee = getEmployeeFromConsole(); + if(employee == null) { + showError("Unable to get employee details."); + return; + } + pstmt.setInt(1, employee.getId()); + pstmt.setString(2, employee.getName()); + pstmt.setString(3, employee.getDesignation()); + pstmt.setObject(4, employee.getJoiningDate()); + pstmt.setDouble(5, employee.getSalary()); + pstmt.execute(); + show("Insert successfull !!"); + } + catch(SQLException sqle) { + //sqle.printStackTrace(); + } + } + + /** + * Gets employee details from the user and update row in + * the Employee table with the new details. + * @param connection + */ + private void update(OracleConnection connection) { + try(PreparedStatement pstmt = connection.prepareStatement(SQL_UPDATE)) { + Employee employee = getEmployeeFromConsole(); + if(employee == null) { + showError("Unable to get employee details."); + return; + } + pstmt.setString(1, employee.getName()); + pstmt.setString(2, employee.getDesignation()); + pstmt.setObject(3, employee.getJoiningDate()); + pstmt.setDouble(4, employee.getSalary()); + pstmt.setInt(5, employee.getId()); + final int numberOfRecordUpdated = pstmt.executeUpdate(); + show("Number of records updated : " + numberOfRecordUpdated); + } + catch(SQLException sqle) { + sqle.printStackTrace(); + } + } + + /** + * Gets the employee id from the user and deletes the employee + * row from the employee table. + * @param connection + */ + private void delete(OracleConnection connection) { + try(PreparedStatement pstmt = connection.prepareStatement(SQL_DELETE)) { + int employeeId = getEmployeeIDFromConsole(); + pstmt.setInt(1, employeeId); + final int numberOfRecordDeleted = pstmt.executeUpdate(); + show("Number of records deleted : " + numberOfRecordDeleted); + } + catch(SQLException sqle) { + //sqle.printStackTrace(); + } + } + + /** + * Gets the employee id from the user and retrieve the specific + * employee details from the employee table. + * @param connection + */ + private void selectOne(OracleConnection connection) { + int empId = getEmployeeIDFromConsole(); + try(PreparedStatement pstmt = connection.prepareStatement(SQL_SELECT_ONE)) { + pstmt.setInt(1, empId); + ResultSet rs = pstmt.executeQuery(); + if(rs.next()) { + Employee emp = new Employee(rs.getInt("EMPNO"), + rs.getString("ENAME"), rs.getString("JOB"), + LocalDate.parse(rs.getString("HIREDATE").substring(0, 10)), rs.getDouble("SAL")); + emp.print(); + } + else { + show("No records found for the employee id : " + empId); + } + } + catch(SQLException sqle) { + //sqle.printStackTrace(); + } + } + + /** + * Selects all the rows from the employee table. + * @param connection + */ + private void selectAll(OracleConnection connection) { + try(PreparedStatement pstmt = connection.prepareStatement(SQL_SELECT_ALL)) { + ResultSet rs = pstmt.executeQuery(); + while(rs.next()) { + Employee emp = new Employee(rs.getInt("EMPNO"), + rs.getString("ENAME"), rs.getString("JOB"), + LocalDate.parse(rs.getString("HIREDATE").substring(0, 10)), rs.getDouble("SAL")); + emp.print(); + } + } + catch(SQLException sqle) { + //sqle.printStackTrace(); + } + } + + // Start the main with the command "java PreparedStatementDemo -u "" -l "" + public static void main(String args[]) throws SQLException, IOException { + // Gets the URL and USER value from command line arguments + String url = getCmdOptionValue(args, "-l", DEFAULT_URL); + String user = getCmdOptionValue(args, "-u", DEFAULT_USER); + + // DB user's Password must be entered + String pwd = readPassword(" Password for " + user + ": "); + + PreparedStatementSample demo = new PreparedStatementSample(user, pwd, url); + demo.startDemo(); + } + + private static String readPassword(String prompt) throws IOException { + if (System.console() == null) { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + System.out.print(prompt); + return r.readLine(); + } + else { + return new String(System.console().readPassword(prompt)); + } + } + + // Get specified option value from command-line, or use default value + private static String getCmdOptionValue(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("")) { + show("No value for Option " + optionName + ", use default."); + argValue = defaultVal; + } + found = true; + } + } + + if (!found) { + show("No Option " + optionName + " specified, use default."); + argValue = defaultVal; + } + } + catch (Exception e) { + showError("getOptionValue" + e.getMessage()); + } + return argValue; + } + + /** + * Get the user option to perform the table operation. + * + * @return + */ + private static int getOption() { + int userOption = -1; + try { + Scanner scanner = new Scanner(System.in); + System.out.println("1 - Select All, 2 - Select One, 3 - Insert, 4 - Update, 5 - Delete, 0 - Exit"); + System.out.println("Enter Option :"); + userOption = Integer.parseInt(scanner.nextLine()); + } + catch(Exception e) { + /* Ignore exception */ + } + return userOption; + } + + /** + * An utility method to get the employee details from the user. + * + * @return employeeObj + */ + private static Employee getEmployeeFromConsole() { + Employee empObj = null;; + try { + Scanner scanner = new Scanner(System.in); + System.out.println("Enter Employee Details"); + System.out.println("ID : "); + int id = Integer.parseInt(scanner.nextLine()); + System.out.println("Name : "); + String name = scanner.nextLine(); + System.out.println("Designation : "); + String designation = scanner.nextLine(); + System.out.println("Joining Date(yyyy-mm-dd) : "); + LocalDate joiningDate = LocalDate.parse(scanner.nextLine()); + System.out.println("Salary : "); + double salary = Double.parseDouble(scanner.nextLine()); + empObj = new Employee(id, name, designation, joiningDate, salary); + } + catch(DateTimeParseException dte) { + showError("Invalid Date format !!"); + } + catch(Exception e) { + /* Ignore exception */ + e.printStackTrace(); + } + return empObj; + } + + /** + * An utility method to get the employee id from the user. + * + * @return employeeID + */ + private static int getEmployeeIDFromConsole() { + int empId = -1; + try { + Scanner scanner = new Scanner(System.in); + System.out.println("Enter Employee ID :"); + empId = Integer.parseInt(scanner.nextLine()); + } + catch(Exception e) { + /* Ignore exception */ + } + return empId; + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg) { + System.out.println("Error : " + msg); + } + + /** + * A simple class to represent the employee table structure + * An instance of this represents a row in employee table. + */ + static class Employee { + private int id; + private String name; + private String designation; + private LocalDate joiningDate; + private double salary; + + Employee(int id, String name, String designation, LocalDate joiningDate, + double salary) { + super(); + this.id = id; + this.name = name; + this.designation = designation; + this.joiningDate = joiningDate; + this.salary = salary; + } + + int getId() { + return id; + } + + String getName() { + return name; + } + + String getDesignation() { + return designation; + } + + LocalDate getJoiningDate() { + return joiningDate; + } + + double getSalary() { + return salary; + } + + void print() { + show("/----------------------------------------------------------------/"); + show("ID : " + id); + show("NAME : " + name); + show("Designation : " + designation); + show("Joining Date: " + joiningDate); + show("Salary : " + salary); + show("/----------------------------------------------------------------/"); + } + + } + + +} diff --git a/java/jdbc/BasicSamples/Readme.md b/java/jdbc/BasicSamples/Readme.md new file mode 100644 index 00000000..2cc4bd1c --- /dev/null +++ b/java/jdbc/BasicSamples/Readme.md @@ -0,0 +1,54 @@ + +# Basic Samples in JDBC + +"Basic Samples" is the first set of code samples aimed to showcase some +of the basic operations and using some datatypes (LOB, SQLXML, DATE etc.,) +The samples also contain Universal Connection Pool (UCP) functionalities to show +how to harvest connections, label connections, how to use different timeouts, and +how to configure MBean to monitor UCP statistics etc., + +# Creating DB User and Sample Data +Before you run the code samples, we want you to create a new DB user and the necessary tables. + +Download [SQLDeveloper](http://www.oracle.com/technetwork/developer-tools/sql-developer/downloads/sqldev-downloads-42-3802334.html) or you can use SQLPLUS. Connect to your database and login as SYSADMIN. +Execute the script [JDBCSampleData.sql](https://github.com/oracle/oracle-db-examples/blob/basicsamples/java/jdbc/BasicSamples/JDBCSampleData.sql) that will create the new database user (jdbcuser) and the +tables necessary for the code samples. + +# Running Code Samples + +(a) Download the [latest 12.2.0.1 ojdbc8.jar and ucp.jar](http://www.oracle.com/technetwork/database/features/jdbc/jdbc-ucp-122-3110062.html) and add these jars to the classpath. + +(b) Run each sample by passing the database URL and database user as the command-line +options. The password is read from console or standard input. + +```java UCPMultiUsers -l -u ``` + +(b) Optionally, each sample has DEFAULT_URL, DEFAULT_USER, and DEFAULT_PASSWORD +in the file. You can choose to update these values with your database credentials +and run the program. If you don't update the defaults, then the program proceeds with the defaults +but, will hit error when connecting as these are dummy values. + +```java UCPMultiUsers``` + +# Description of Code Samples + +* **DateTimeStampSample.java**:Shows the usage of Oracle column data types such as DATE, TIMESTAMP, TIMESTAMP WITH TIME ZONE and TIMESTAMP WITH LOCAL TIME ZONE. +* **JDBCUrlSample.java**: Shows how to use the easy connection URL, connection URL with connection descriptors, and using TNS alias to connect to the Oracle database. +* **JSONBasicSample.java**: Shows how to use some of the enhancements in JavaScript Object Notation (JSON) support for Oracle Database 12c Release 2 (12.2). +* **LobBasicSample.java**: Shows how to use different types of LOBs (Large Objects), such as BLOB, CLOB, and NLOB as datatypes. +* **PLSQLSample.java**: Demonstrates the usage of PL/SQL Stored Procedures and Functions in JDBC. +* **PreparedStatementBindingsSample.java**: Shows CRUD operations using the ```PreparedStatement``` with named bindings. +* **PreparedStatementSample.java**:Shows CRUD operations using the ```PreparedStatement``` object. +* **SQLXMLSample.java**: Shows how to create, insert, and query ``SQLXML`` values. +* **StatementSample.java**: Shows CRUD operations using the Statement object. +* **UCPBasic.java**: Shows simple steps of how JDBC applications use the Oracle Universal Connection Pool (UCP). +* **UCPHarvesting.java**: Shows how applications use the connection harvesting feature of UCP. +* **UCPLabeling.java**: Shows how applications use the connection labeling feature of UCP. +* **UCPManager.java**: Shows how applications use UCP manager's administration functions. +* **UCPManagerMBean.java**: Shows how applications use UCP manager MBean's administration functions. +* **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. + + + diff --git a/java/jdbc/BasicSamples/SQLXMLSample.java b/java/jdbc/BasicSamples/SQLXMLSample.java new file mode 100755 index 00000000..462469da --- /dev/null +++ b/java/jdbc/BasicSamples/SQLXMLSample.java @@ -0,0 +1,280 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/** + * DESCRIPTION + * + * This is a simple example of how to create, insert, and query SQLXML values. For + * more info see {@link https://docs.oracle.com/javase/tutorial/jdbc/basics/sqlxml.html}, + * and {@link https://docs.oracle.com/en/database/oracle/oracle-database/12.2/adxdb/intro-to-XML-DB.html}. + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java SQLXMLSample -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.IOException; +import java.io.InputStream; +import java.io.InputStreamReader; +import java.io.OutputStream; +import java.io.OutputStreamWriter; +import java.io.Writer; +import java.sql.Connection; +import java.sql.DriverManager; +import java.sql.JDBCType; +import java.sql.PreparedStatement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.SQLXML; +import java.sql.Statement; +import javax.xml.parsers.DocumentBuilder; +import javax.xml.parsers.DocumentBuilderFactory; +import javax.xml.parsers.ParserConfigurationException; +import javax.xml.transform.OutputKeys; +import javax.xml.transform.Transformer; +import javax.xml.transform.TransformerException; +import javax.xml.transform.TransformerFactory; +import javax.xml.transform.dom.DOMSource; +import javax.xml.transform.stream.StreamResult; + +import org.w3c.dom.Document; +import org.xml.sax.ContentHandler; +import org.xml.sax.SAXException; +import org.xml.sax.helpers.DefaultHandler; + + +public class SQLXMLSample { + 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; + + /** + * Create an instance, get the database user password, and run the sample code. + * + * @param args command line args + * @throws Exception if an error occurs + */ + public static void main(String args[]) throws Exception { + SQLXMLSample sample = new SQLXMLSample(); + + getRealUserPasswordUrl(args); + sample.run(); + } + + /** + * Demonstrate the sample code. + *
    + *
  1. drop the sample table to insure the table can be created properly
  2. + *
  3. create the sample table
  4. + *
  5. insert SQLXML values into the table
  6. + *
  7. read the SQLXML values from the table
  8. + *
  9. clean up
  10. + *
+ * + * @throws Exception + */ + private void run() throws Exception { + try (Connection conn = DriverManager.getConnection(url, user, password)) { + truncateTable(conn); + loadTable(conn); + queryTable(conn); + truncateTable(conn); + } + } + + /** + * Clear the sample table with two columns. + * + * @param conn a database Connection + * @throws SQLException + */ + private void truncateTable(Connection conn) throws SQLException { + String sql = "TRUNCATE TABLE SQLXML_JDBC_SAMPLE"; + show(sql); + doSql(conn, sql); + } + + /** + * Create SQLXML values and insert them into the sample table. Demonstrates + * two possible ways to create a SQLXML value. There are others. Uses the + * generic setObject(int, Object, SQLType) method to set the parameters. + * + * @param conn + * @throws SQLException + */ + private void loadTable(Connection conn) throws SQLException { + String insertDml = "INSERT INTO SQLXML_JDBC_SAMPLE (DOCUMENT, ID) VALUES (?, ?)"; + try (PreparedStatement prepStmt = conn.prepareStatement(insertDml)) { + + SQLXML xml = conn.createSQLXML(); + xml.setString("\n" + + " \n" + + " 221\n" + + " John\n" + + " "); + + prepStmt.setObject(1, xml, JDBCType.SQLXML); + prepStmt.setObject(2, 221, JDBCType.NUMERIC); + prepStmt.executeUpdate(); + + xml = conn.createSQLXML(); + Writer w = xml.setCharacterStream(); + w.write("\n"); + w.write(" \n"); + w.write(" 222\n"); + w.write(" Mary\n"); + w.write(" \n"); + w.close(); + + prepStmt.setObject(1, xml, JDBCType.SQLXML); + prepStmt.setObject(2, 222, JDBCType.NUMERIC); + prepStmt.executeUpdate(); + + } + catch (IOException ex) { + throw new SQLException(ex); + } + } + + /** + * Query the sample table, retrive the SQLXML values and print their contents + * to stdout. Uses the generic getObject(int, Class) method. + * + * @param conn + * @throws SQLException + */ + private void queryTable(Connection conn) throws SQLException { + String query = "SELECT DOCUMENT, ID FROM SQLXML_JDBC_SAMPLE ORDER BY ID"; + try (PreparedStatement pstmt = conn.prepareStatement(query)) { + ResultSet rs = pstmt.executeQuery(); + while (rs.next()) { + SQLXML sqlxml = rs.getObject(1, SQLXML.class); + InputStream binaryStream = sqlxml.getBinaryStream(); + DocumentBuilder parser + = DocumentBuilderFactory.newInstance().newDocumentBuilder(); + Document result = parser.parse(binaryStream); + printDocument(result, System.out); + System.out.println(); + } + } + catch (IOException | TransformerException | SAXException | ParserConfigurationException ex) { + throw new SQLException(ex); + } + } + + + // + // Utility methods + // + + /** + * Simple code to print an XML Documint to an OutputStream. + * + * @param doc an XML document to print + * @param the stream to print to + * @throws IOException if an error occurs is writing the output + * @throws TransformerException if an error occurs in generating the output + */ + static void printDocument(Document doc, OutputStream out) + throws IOException, TransformerException { + TransformerFactory factory = TransformerFactory.newInstance(); + Transformer transformer = factory.newTransformer(); + transformer.setOutputProperty(OutputKeys.ENCODING, "UTF-8"); + transformer.setOutputProperty(OutputKeys.METHOD, "xml"); + transformer.setOutputProperty(OutputKeys.OMIT_XML_DECLARATION, "no"); + transformer.setOutputProperty(OutputKeys.INDENT, "yes"); + transformer.setOutputProperty("{http://xml.apache.org/xslt}indent-amount", "4"); + + transformer.transform(new DOMSource(doc), + new StreamResult(new OutputStreamWriter(out, "UTF-8"))); + } + + static void doSql(Connection conn, String sql) throws SQLException { + try (Statement stmt = conn.createStatement()) { + stmt.execute(sql); + } + } + + static void trySql(Connection conn, String sql) { + try { + doSql(conn, sql); + } + catch (SQLException ex) { + // ignore + } + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.err.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } +} diff --git a/java/jdbc/BasicSamples/StatementSample.java b/java/jdbc/BasicSamples/StatementSample.java new file mode 100755 index 00000000..444bebf8 --- /dev/null +++ b/java/jdbc/BasicSamples/StatementSample.java @@ -0,0 +1,409 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/** + * DESCRIPTION + * + * A simple illustration of CRUD operation using the Statement object. + */ +import java.io.BufferedReader; +import java.io.IOException; +import java.io.InputStreamReader; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; +import java.util.Scanner; + +import oracle.jdbc.OracleConnection; +import oracle.jdbc.pool.OracleDataSource; + + +public class StatementSample { + + private static final int USER_OPTION_SELECTALL = 1; + private static final int USER_OPTION_SELECTONE = 2; + private static final int USER_OPTION_INSERT = 3; + private static final int USER_OPTION_UPDATE = 4; + private static final int USER_OPTION_DELETE = 5; + private static final int USER_OPTION_EXIT = 0; + + private static final String SQL_INSERT = "INSERT INTO EMP (EMPNO, ENAME, JOB, HIREDATE, SAL) VALUES(%d, '%s', '%s', TO_DATE('%s', 'yyyy/mm/dd'), %f)"; + + private static final String SQL_UPDATE + = "UPDATE EMP SET ENAME = '%s', JOB = '%s', HIREDATE = " + + "TO_DATE('%s', 'yyyy/mm/dd'), SAL = %f WHERE EMPNO = %d"; + + private static final String SQL_DELETE = "DELETE FROM EMP WHERE EMPNO = %d"; + private static final String SQL_SELECT_ALL = "SELECT * FROM EMP"; + private static final String SQL_SELECT_ONE = "SELECT * FROM EMP WHERE EMPNO = %d"; + + + + + private static final String DEFAULT_USER = "myuser"; + private static final String DEFAULT_URL + = "jdbc:oracle:thin:@//myhost:1521/myservice"; + + private final String user; + private final String password; + private final String url; + + /** + * Creates an StatementDemo instance with the given details. + * @param user + * @param pwd + * @param url + */ + private StatementSample(String user, String pwd, String url) { + this.user = user; + this.password = pwd; + this.url = url; + } + + /** + * Get a connection from the Oracle Database. + * and performs CRUD operation based on the user input. + * @throws SQLException + */ + private void startDemo() throws SQLException { + OracleConnection connection = getConnection(); + try { + // loops forever until the user choose to exit. + while (true) { + int userOption = getUserOption(); + switch(userOption) { + case USER_OPTION_SELECTONE : + selectOne(connection); + break; + case USER_OPTION_SELECTALL : + selectAll(connection); + break; + case USER_OPTION_INSERT : + insert(connection); + break; + case USER_OPTION_UPDATE : + update(connection); + break; + case USER_OPTION_DELETE : + delete(connection); + break; + case USER_OPTION_EXIT : + show("Bye !!"); + return; + default : + show("Invalid option : " + userOption); + } + } + } + finally { + connection.close(); + } + } + + /** + * Creates an OracleConnection instance and return it. + * @return oracleConnection + * @throws SQLException + */ + private OracleConnection getConnection() throws SQLException { + OracleDataSource ods = new OracleDataSource(); + ods.setUser(user); + ods.setPassword(password); + ods.setURL(url); + return (OracleConnection)ods.getConnection(); + } + + /** + * Gets employee details from the user and insert into + * the Employee table. + * @param connection + */ + private void insert(OracleConnection connection) { + try(Statement stmt = connection.createStatement()) { + Employee employee = getEmployeeFromConsole(); + if(employee == null) { + showError("Unable to get employee details."); + return; + } + String insertSQL = String.format(SQL_INSERT, employee.getId(), + employee.getName(), employee.getDesignation(), + employee.getJoiningDate(), employee.getSalary()); + boolean status = stmt.execute(insertSQL); + show("Insert successfull !!"); + } + catch(SQLException sqle) { + showError(sqle.getMessage()); + } + } + + /** + * Gets employee details from the user and update row in + * the Employee table with the new details. + * @param connection + */ + private void update(OracleConnection connection) { + try(Statement stmt = connection.createStatement()) { + Employee employee = getEmployeeFromConsole(); + if(employee == null) { + showError("Unable to get employee details."); + return; + } + String updateSQL = String.format(SQL_UPDATE, + employee.getName(), employee.getDesignation(), + employee.getJoiningDate(), employee.getSalary(), + employee.getId()); + int noOfRecordsUpdated = stmt.executeUpdate(updateSQL); + show("Number of records updated : " + noOfRecordsUpdated); + } + catch(SQLException sqle) { + showError(sqle.getMessage()); + } + } + + /** + * Gets the employee id from the user and deletes the employee + * row from the employee table. + * @param connection + */ + private void delete(OracleConnection connection) { + try(Statement stmt = connection.createStatement()) { + int employeeID = getEmployeeIDFromConsole(); + String deleteSQL = String.format(SQL_DELETE,employeeID); + int noOfRecordsDeleted = stmt.executeUpdate(deleteSQL); + show("Number of records deleted : " + noOfRecordsDeleted); + } + catch(SQLException sqle) { + showError(sqle.getMessage()); + } + } + + /** + * Gets the employee id from the user and retrieve the specific + * employee details from the employee table. + * @param connection + */ + private void selectOne(OracleConnection connection) { + int empId = getEmployeeIDFromConsole(); + try(Statement stmt = connection.createStatement()) { + final String selectSQL = String.format(SQL_SELECT_ONE, empId); + ResultSet rs = stmt.executeQuery(selectSQL); + if(rs.next()) { + Employee emp = new Employee(rs.getInt("EMPNO"), + rs.getString("ENAME"), rs.getString("JOB"), + rs.getString("HIREDATE"), rs.getDouble("SAL")); + emp.print(); + } + else { + show("No records found for the employee id : " + empId); + } + } + catch(SQLException sqle) { + showError(sqle.getMessage()); + } + } + + /** + * Selects all the rows from the employee table. + * @param connection + */ + private void selectAll(OracleConnection connection) { + try(Statement stmt = connection.createStatement()) { + ResultSet rs = stmt.executeQuery(SQL_SELECT_ALL); + while(rs.next()) { + Employee emp = new Employee(rs.getInt("EMPNO"), + rs.getString("ENAME"), rs.getString("JOB"), + rs.getString("HIREDATE"), rs.getDouble("SAL")); + emp.print(); + } + } + catch(SQLException sqle) { + showError(sqle.getMessage()); + } + } + + // Start the main with the command "java StatementDemo -u "" -l "" + public static void main(String args[]) throws SQLException, IOException { + // Gets the URL and USER value from command line arguments + String url = getCmdOptionValue(args, "-l", DEFAULT_URL); + String user = getCmdOptionValue(args, "-u", DEFAULT_USER); + + // DB user's Password must be entered + String pwd = readPassword(" Password for " + user + ": "); + + StatementSample demo = new StatementSample(user, pwd, url); + demo.startDemo(); + } + + private static String readPassword(String prompt) throws IOException { + if (System.console() == null) { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + System.out.print(prompt); + return r.readLine(); + } + else { + return new String(System.console().readPassword(prompt)); + } + } + + // Get specified option value from command-line, or use default value + private static String getCmdOptionValue(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("")) { + show("No value for Option " + optionName + ", use default."); + argValue = defaultVal; + } + found = true; + } + } + + if (!found) { + show("No Option " + optionName + " specified, use default."); + argValue = defaultVal; + } + } + catch (Exception e) { + showError("getOptionValue" + e.getMessage()); + } + return argValue; + } + + /** + * Get the user option to perform the table operation. + * + * @return + */ + private static int getUserOption() { + int userOption = -1; + try { + Scanner scanner = new Scanner(System.in); + System.out.println( + "1 - Select All, 2 - Select One, 3 - Insert, 4 - Update, 5 - Delete, 0 - Exit"); + System.out.println("Enter Option :"); + userOption = Integer.parseInt(scanner.nextLine()); + } + catch (Exception e) { + /* Ignore exception */ + } + return userOption; + } + + /** + * An utility method to get the employee details from the user. + * + * @return employeeObj + */ + private static Employee getEmployeeFromConsole() { + Employee empObj = null; + ; + try { + Scanner scanner = new Scanner(System.in); + System.out.println("Enter Employee Details"); + System.out.println("ID : "); + int id = Integer.parseInt(scanner.nextLine()); + System.out.println("Name : "); + String name = scanner.nextLine(); + System.out.println("Designation : "); + String designation = scanner.nextLine(); + System.out.println("Joining Date(yyyy/mm/dd) : "); + String joiningDate = scanner.nextLine(); + System.out.println("Salary : "); + double salary = Double.parseDouble(scanner.nextLine()); + empObj = new Employee(id, name, designation, joiningDate, salary); + } + catch (Exception e) { + /* Ignore exception */ + } + return empObj; + } + + /** + * An utility method to get the employee id from the user. + * + * @return employeeID + */ + private static int getEmployeeIDFromConsole() { + int empId = -1; + try { + Scanner scanner = new Scanner(System.in); + System.out.println("Enter Employee ID :"); + empId = Integer.parseInt(scanner.nextLine()); + } + catch (Exception e) { + /* Ignore exception */ + } + return empId; + } + + private static void show(String msg) { + System.out.println(msg); + } + + private static void showError(String msg) { + System.out.println("Error : " + msg); + } + + /** + * A simple class to represent the employee table structure + * An instance of this represents a row in employee table. + */ + private static class Employee { + private int id; + private String name; + private String designation; + private String joiningDate; + private double salary; + + Employee(int id, String name, String designation, String joiningDate, + double salary) { + super(); + this.id = id; + this.name = name; + this.designation = designation; + this.joiningDate = joiningDate; + this.salary = salary; + } + + int getId() { + return id; + } + + String getName() { + return name; + } + + String getDesignation() { + return designation; + } + + String getJoiningDate() { + return joiningDate; + } + + double getSalary() { + return salary; + } + + void print() { + show( + "/----------------------------------------------------------------/"); + show("ID : " + id); + show("NAME : " + name); + show("Designation : " + designation); + show("Joining Date: " + joiningDate); + show("Salary : " + salary); + show( + "/----------------------------------------------------------------/"); + } + + } + +} diff --git a/java/jdbc/BasicSamples/UCPBasic.java b/java/jdbc/BasicSamples/UCPBasic.java new file mode 100755 index 00000000..9c388c2e --- /dev/null +++ b/java/jdbc/BasicSamples/UCPBasic.java @@ -0,0 +1,257 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This code sample illustrates the simple steps of how JDBC applications + * use the Oracle Universal Connection Pool (UCP). + * + * JDBC applications typically interact with UCP via a pool-enabled + * data source. The embedded connection pool is implicitly created + * at the first connection borrow (or checkout) from the pool. + * + * The basic steps include first creating a pool-enabled data source, + * configuring properties essential to establishing JDBC connections, + * and then invoking JDBC APIs to get connections from the data source + * and the embedded connection pool. + * + * For comparison, this sample also illustrates how applications do + * regular JDBC connect using a JDBC driver data source. It is very + * simple to migrate JDBC applications to using UCP. + * + * It is required that applications have both ucp.jar and Oracle JDBC + * driver jar(s) (such as ojdbc8.jar or ojdbc7.jar) on the classpath, + * and that the database backend supports SQL (this sample uses an + * Oracle Database). + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java UCPBasic -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.SQLException; +import java.sql.Statement; + +// From Oracle JDBC driver +import oracle.jdbc.pool.OracleDataSource; + +import oracle.ucp.jdbc.PoolDataSourceFactory; +import oracle.ucp.jdbc.PoolDataSource; + + +public class UCPBasic { + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + public static void main(String args[]) throws Exception { + UCPBasic sample = new UCPBasic(); + + getRealUserPasswordUrl(args); + sample.run(); + } + + private void run() throws Exception { + demoRegularJDBCConnect(); + demoUCPConnect(); + } + + // Illustrates how to get a connection using a driver data source. + private void demoRegularJDBCConnect() { + show("\ndemoRegularJDBCConnect starts"); + + try { + OracleDataSource ods = new OracleDataSource(); + ods.setURL(url); + ods.setUser(user); + ods.setPassword(password); + + // This creates a physical connection to the database. + Connection conn = ods.getConnection(); + show("Created a physical connection: " + conn); + + // This closes the physical connection. + conn.close(); + show("Closed physical connection: " + conn); + } catch (Throwable e) { + showError("demoRegularJDBCConnect", e); + } + + show("demoRegularJDBCConnect completes"); + } + + // Illustrates how to use a UCP-enabled data source. + private void demoUCPConnect() { + show("\nUCPBasic starts"); + + try { + /* + * Step 1 - creates a pool-enabled data source instance + */ + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + + /* + * Step 2 - configures pool properties for establishing connections. + * These include required and optional properties. + */ + + /* Required pool properties */ + + // UCP uses a connection factory to create physical connections. + // This is typically a JDBC driver javax.sql.DataSource or + // java.sql.Driver implementation class. + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS); + pds.setURL(url); + pds.setUser(user); + pds.setPassword(password); + + /* Optional pool properties */ + + // Pool name should be unique within the same JVM instance. + // It is useful for administrative tasks, such as starting, + // stopping, refreshing a pool. Setting a pool name is optional + // but recommended. If user does not set a pool name, UCP will + // automatically generate one. + pds.setConnectionPoolName("UCPBasic_pool"); + + // The default is 0. + pds.setInitialPoolSize(5); + + // The default is 0. + pds.setMinPoolSize(5); + + // The default is Integer.MAX_VALUE. + pds.setMaxPoolSize(10); + + show("Connection pool configured"); + + /* + * Step 3 - borrow connections from and return connections to + * the connection pool. + */ + + // Borrow a connection from UCP. The connection object is a proxy + // of a physical connection. The physical connection is returned + // to the pool when Connection.close() is called on the proxy. + try (Connection conn1 = pds.getConnection()) { + showPoolStatistics("After checkout", pds); + + makeJDBCCalls(conn1); + } catch (SQLException exc) { + showError("1st checkout", exc); + } + + showPoolStatistics("After checkin", pds); + + // Another round of borrow/return. + try (Connection conn2 = pds.getConnection()) { + showPoolStatistics("After 2nd checkout", pds); + + makeJDBCCalls(conn2); + } catch (SQLException exc) { + showError("2nd checkout", exc); + } + + showPoolStatistics("After 2nd checkin", pds); + } catch (Throwable e) { + showError("demoUCPConnect", e); + } + + show("UCPBasic completes"); + } + + // Simple query + private void makeJDBCCalls(Connection conn) { + try (Statement statement = conn.createStatement()) { + statement.execute("SELECT 1 FROM DUAL"); + } catch (SQLException exc) { + showError("JDBC operation", exc); + } + } + + private void showPoolStatistics(String prompt, PoolDataSource pds) + throws SQLException { + show(prompt + " -"); + show(" Available connections: " + pds.getAvailableConnectionsCount()); + show(" Borrowed connections: " + pds.getBorrowedConnectionsCount()); + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.err.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } +} + diff --git a/java/jdbc/BasicSamples/UCPHarvesting.java b/java/jdbc/BasicSamples/UCPHarvesting.java new file mode 100755 index 00000000..c2d557d4 --- /dev/null +++ b/java/jdbc/BasicSamples/UCPHarvesting.java @@ -0,0 +1,369 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This code sample illustrates how applications use the connection harvesting + * feature of Oracle Universal Connection Pool (UCP). + * + * Connection Harvesting allows a specified number of borrowed connections + * to be reclaimed when the connection pool reaches a specified number of + * available connections. Least recently used connections are harvested first. + * + * This feature helps to ensure that a certain number of connections are + * always available in the pool to maximize performance. + * + * UCP gives applications control over which borrowed connections can be + * harvested. By default, all connections are harvestable. Applications + * can use the HarvestableConnection interface to explicitly specify + * whether a connection is harvestable. + * + * For harvestable connections, UCP also provides ConnectionHarvestingCallback + * that allows applications to perform customized cleanup tasks when + * connections are harvested by the pool. + * + * It is required that applications have both ucp.jar and Oracle JDBC + * driver jar(s) (such as ojdbc8.jar or ojdbc7.jar) on the classpath, + * and that the database backend supports SQL (this sample uses an + * Oracle Database and the default HR schema). + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java UCPHarvesting -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.SQLException; +import java.sql.Statement; + +import oracle.ucp.ConnectionHarvestingCallback; +import oracle.ucp.admin.UniversalConnectionPoolManagerImpl; +import oracle.ucp.jdbc.HarvestableConnection; +import oracle.ucp.jdbc.PoolDataSource; +import oracle.ucp.jdbc.PoolDataSourceFactory; + + +public class UCPHarvesting { + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + public static void main(String args[]) throws Exception { + UCPHarvesting sample = new UCPHarvesting(); + + getRealUserPasswordUrl(args); + sample.run(); + } + + void run() throws Exception { + runDefaultAllConnectionsHarvestable(); + runWithNonHarvestableConnections(); + } + + void runDefaultAllConnectionsHarvestable() throws Exception { + show("\n*** Run with default: all connections are harvestable ***"); + + try { + int INITIAL_POOL_SIZE = 10; + final String POOL_NAME = "UCPHarvesting_pool1"; + Connection conns[] = new Connection[INITIAL_POOL_SIZE]; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + /* + * ConnectionHarvestTriggerCount specifies the available connections + * threshold that triggers connection harvesting. For example, if the + * connection harvest trigger count is set to 5, connection harvesting + * is triggered when the number of available connections in the pool + * drops to 5. + * + * A value of Integer.MAX_VALUE disables connection harvesting. + * By default, connection harvesting is disabled. + */ + pds.setConnectionHarvestTriggerCount(5); + /* + * ConnectionHarvestMaxumCount specifies the maximum number of + * borrowed connections that can be returned to the pool, once + * connection harvesting is triggered. The default is 1. + */ + pds.setConnectionHarvestMaxCount(2); + + show("Connection pool " + POOL_NAME + " configured"); + show("Initial pool size: " + pds.getInitialPoolSize()); + + show("\nBorrowing 4 connections, conns[0] and conns[1] are LRU"); + + TestHarvestingCallback[] cbks = new TestHarvestingCallback[5]; + for (int i = 0; i < 4; i++) { + conns[i] = pds.getConnection(); + // Register harvesting callbacks to cleanup reclaimed connections. + cbks[i] = new TestHarvestingCallback(conns[i]); + ((HarvestableConnection) conns[i]).registerConnectionHarvestingCallback(cbks[i]); + makeJDBCCalls(conns[i]); + } + + showPoolStatistics("\nAfter borrowing 4 connections", pds); + + // Borrowing the 5th connection to trigger harvesting + show("\nBorrowing 5th connection to trigger harvesting ..."); + conns[4] = pds.getConnection(); + cbks[4] = new TestHarvestingCallback(conns[4]); + ((HarvestableConnection) conns[4]).registerConnectionHarvestingCallback(cbks[4]); + + // Harvesting should happen + Thread.sleep(15000); + + // After harvesting, there will be 7 available connections and + // 3 borrowed connections in the pool. + showPoolStatistics("\nAfter harvesting", pds); + + // conns[0] and [1]'s physical connections should be "harvested" + // by the pool and these two logical connections should be closed + show("\nChecking on the 5 borrowed connections ..."); + show(" conns[0] should be closed -- " + conns[0].isClosed()); + show(" conns[1] should be closed -- " + conns[1].isClosed()); + show(" conns[2] should be open -- " + !conns[2].isClosed()); + show(" conns[3] should be open -- " + !conns[3].isClosed()); + show(" conns[4] should be open -- " + !conns[4].isClosed()); + + // Returning all connections to pool. + for (int i = 2; i < 5; i++) + conns[i].close(); + + destroyConnectionPool(POOL_NAME); + } catch (Throwable e) { + showError("runDefaultAllConnectionsHarvestable", e); + } + + show("\n*** Run with default completes ***"); + } + + void runWithNonHarvestableConnections() throws Exception { + show("\n*** Run with non-harvestable connections ***"); + + try { + int INITIAL_POOL_SIZE = 10; + final String POOL_NAME = "UCPHarvesting_pool2"; + Connection conns[] = new Connection[INITIAL_POOL_SIZE]; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + /* + * ConnectionHarvestTriggerCount specifies the available connections + * threshold that triggers connection harvesting. For example, if the + * connection harvest trigger count is set to 5, connection harvesting + * is triggered when the number of available connections in the pool + * drops to 5. + * + * A value of Integer.MAX_VALUE disables connection harvesting. + * By default, connection harvesting is disabled. + */ + pds.setConnectionHarvestTriggerCount(5); + /* + * ConnectionHarvestMaxumCount specifies the maximum number of + * borrowed connections that can be returned to the pool, once + * connection harvesting is triggered. The default is 1. + */ + pds.setConnectionHarvestMaxCount(2); + + show("Connection pool " + POOL_NAME + " configured"); + show("Initial pool size: " + pds.getInitialPoolSize()); + + show("\nBorrowing 4 connections, conns[0] and conns[1] are LRU"); + + TestHarvestingCallback[] cbks = new TestHarvestingCallback[5]; + for (int i = 0; i < 4; i++) { + conns[i] = pds.getConnection(); + // Register harvesting callbacks to cleanup reclaimed connections. + cbks[i] = new TestHarvestingCallback(conns[i]); + ((HarvestableConnection) conns[i]).registerConnectionHarvestingCallback(cbks[i]); + makeJDBCCalls(conns[i]); + } + + show("\nMarking conns[0] and conns[1] as non-harvestable"); + // Assuming application is doing critical work on conns[0] and [1] + // and doesn't want those 2 connections to be "harvested". + // Mark conns[0] and [1] as non-harvestable connections. + ((HarvestableConnection) conns[0]).setConnectionHarvestable(false); + ((HarvestableConnection) conns[1]).setConnectionHarvestable(false); + + showPoolStatistics("\nAfter borrowing 4 connections", pds); + + // Borrowing the 5th connection to trigger harvesting + show("\nBorrowing 5th connection to trigger harvesting ..."); + conns[4] = pds.getConnection(); + cbks[4] = new TestHarvestingCallback(conns[4]); + ((HarvestableConnection) conns[4]).registerConnectionHarvestingCallback(cbks[4]); + + // Harvesting should happen + Thread.sleep(15000); + + // After harvesting, there will be 7 available connections and + // 3 borrowed connections in the pool. + showPoolStatistics("\nAfter harvesting", pds); + + // conns[2] and [3]'s physical connections should be "harvested" + // by the pool and these two logical connections should be closed. + // conns[0] and [1]'s physical connections will not be "harvested". + show("\nChecking on the 5 borrowed connections ..."); + show(" conns[0] should be open -- " + !conns[0].isClosed()); + show(" conns[1] should be open -- " + !conns[1].isClosed()); + show(" conns[2] should be closed -- " + conns[2].isClosed()); + show(" conns[3] should be closed -- " + conns[3].isClosed()); + show(" conns[4] should be open -- " + !conns[4].isClosed()); + + // Returning all connections to pool. + conns[0].close(); + conns[1].close(); + conns[4].close(); + + destroyConnectionPool(POOL_NAME); + } catch (Throwable e) { + showError("runWithNonHarvestableConnections", e); + } + + show("\n*** Run with non-harvestable connections completes ***"); + } + + // See sample UCPBasic.java for basic steps to set up a connection pool. + PoolDataSource createPoolDataSource(String poolName) throws Exception { + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS); + pds.setURL(url); + pds.setUser(user); + pds.setPassword(password); + pds.setConnectionPoolName(poolName); + pds.setInitialPoolSize(10); + pds.setMaxPoolSize(10); + pds.setTimeoutCheckInterval(5); + + return pds; + } + + void destroyConnectionPool(String poolName) { + try { + UniversalConnectionPoolManagerImpl.getUniversalConnectionPoolManager() + .destroyConnectionPool(poolName); + show("\nConnection pool " + poolName + " destroyed"); + } catch (Throwable e) { + showError("destroyConnectinoPool", e); + } + } + + void showPoolStatistics(String prompt, PoolDataSource pds) + throws SQLException { + show(prompt + " -"); + show(" Available connections: " + pds.getAvailableConnectionsCount()); + show(" Borrowed connections: " + pds.getBorrowedConnectionsCount()); + } + + // Simple query + void makeJDBCCalls(Connection conn) { + try (Statement statement = conn.createStatement()) { + statement.execute("SELECT 1 FROM DUAL"); + } catch (SQLException exc) { + showError("makeJDBCCalls", exc); + } + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } + + /* + * Sample connection harvesting callback implementation. + */ + class TestHarvestingCallback implements ConnectionHarvestingCallback { + private Object objForCleanup = null; + + public TestHarvestingCallback(Object objForCleanup) { + this.objForCleanup = objForCleanup; + } + + public boolean cleanup() { + try { + doCleanup(objForCleanup); + } catch (Exception exc) { + return false; + } + + return true; + } + + private void doCleanup(Object obj) throws Exception { + ((Connection) obj).close(); + } + } +} + diff --git a/java/jdbc/BasicSamples/UCPLabeling.java b/java/jdbc/BasicSamples/UCPLabeling.java new file mode 100755 index 00000000..f1808724 --- /dev/null +++ b/java/jdbc/BasicSamples/UCPLabeling.java @@ -0,0 +1,318 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This code sample illustrates how applications use the connection labeling + * feature of Oracle Universal Connection Pool (UCP). + * + * Connection Labeling allows applications to request pre-configured + * connections identified by labels, in order to minimize connection + * reinitialization cost. + * + * Connection Labeling does not impose any meaning on user-defined keys + * or values; the meaning of user-defined keys and values is defined + * solely by the application. + * + * Connection labeling is application-driven and requires the use of + * two interfaces: + * + * (1) The oracle.ucp.jdbc.LabelableConnection interface is used to + * apply and remove connection labels, as well as retrieving labels + * that have been set on a connection. + * + * (2) The oracle.ucp.ConnectionLabelingCallback interface is used to + * create a labeling callback that determines whether or not + * a connection with a requested label already exists. If no connections + * exist, the interface allows current connections to be configured + * as required. + * + * It is required that applications have both ucp.jar and Oracle JDBC + * driver jar(s) (such as ojdbc8.jar or ojdbc7.jar) on the classpath, + * and that the database backend supports SQL (this sample uses an + * Oracle Database and the default HR schema). + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java UCPLabeling -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.SQLException; +import java.sql.Statement; +import java.util.Map; +import java.util.Properties; +import java.util.Set; + +import oracle.ucp.ConnectionLabelingCallback; +import oracle.ucp.admin.UniversalConnectionPoolManagerImpl; +import oracle.ucp.jdbc.LabelableConnection; +import oracle.ucp.jdbc.PoolDataSource; +import oracle.ucp.jdbc.PoolDataSourceFactory; + + +public class UCPLabeling { + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + public static void main(String args[]) throws Exception { + UCPLabeling sample = new UCPLabeling(); + + getRealUserPasswordUrl(args); + sample.run(); + } + + void run() throws Exception { + show("\n*** Demo Connection Labeling ***"); + + try { + final String POOL_NAME = "UCPLabeling_pool1"; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + pds.setInitialPoolSize(2); + show("\nConnection pool " + POOL_NAME + " configured"); + show("Initial pool size: " + pds.getInitialPoolSize()); + + // Register connection labeling callback + ExampleLabelingCallback cbk = new ExampleLabelingCallback(); + pds.registerConnectionLabelingCallback(cbk); + show("\nLabeling callback registered on the pool"); + + // All initial connections in the pool do not have labels + show("\nBorrowing a regular connection 1 (without labels) from pool ..."); + Connection conn1 = pds.getConnection(); + showPoolStatistics("After borrowing regular connection 1", pds); + + // Change session state and apply corresponding connection label, + // using the LabelableConnection interface method. + conn1.setTransactionIsolation(Connection.TRANSACTION_SERIALIZABLE); + ((LabelableConnection) conn1).applyConnectionLabel("TRANSACTION_ISOLATION", "8"); + show("\nApplied new label on connection 1"); + + show("\nReturning labeled connection 1 to pool ..."); + conn1.close(); + showPoolStatistics("After returning labeled connection 1", pds); + + // Preferred connection label + Properties label = new Properties(); + label.setProperty("TRANSACTION_ISOLATION", "8"); + + // Specify preferred label(s) with the getConnection call + show("\nBorrowing connection 2 with preferred label ..."); + Connection conn2 = pds.getConnection(label); + showPoolStatistics("After borrowing labeled connection 2", pds); + + show("\nReturning labeled connection 2 to pool ..."); + conn2.close(); + showPoolStatistics("After returning labeled connection 2", pds); + + // Different preferred connection label + Properties label2 = new Properties(); + // Connection.TRANSACTION_READ_COMMITTED == 2 + label2.setProperty("TRANSACTION_ISOLATION", "2"); + + // Specify preferred label(s) with the getConnection call + show("\nBorrowing connection 3 with different preferred label ..."); + Connection conn3 = pds.getConnection(label2); + showPoolStatistics("After borrowing labeled connection 3", pds); + + show("\nReturning labeled connection 3 to pool ..."); + conn3.close(); + showPoolStatistics("After returning labeled connection 3", pds); + + destroyConnectionPool(POOL_NAME); + + } catch (Throwable e) { + showError("UCPLabeling", e); + } + + show("\n*** Demo Connection Labeling completes ***"); + } + + // See sample UCPBasic.java for basic steps to set up a connection pool. + PoolDataSource createPoolDataSource(String poolName) throws Exception { + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS); + pds.setURL(url); + pds.setUser(user); + pds.setPassword(password); + pds.setConnectionPoolName(poolName); + + return pds; + } + + void destroyConnectionPool(String poolName) { + try { + UniversalConnectionPoolManagerImpl.getUniversalConnectionPoolManager() + .destroyConnectionPool(poolName); + show("\nConnection pool " + poolName + " destroyed"); + } catch (Throwable e) { + showError("destroyConnectinoPool", e); + } + } + + void showPoolStatistics(String prompt, PoolDataSource pds) + throws SQLException { + show(prompt + " -"); + show(" Available connections: " + pds.getAvailableConnectionsCount()); + show(" Borrowed connections: " + pds.getBorrowedConnectionsCount()); + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } + + class ExampleLabelingCallback implements ConnectionLabelingCallback { + private boolean printed1 = false; + private boolean printed2 = false; + private boolean printed3 = false; + + public ExampleLabelingCallback() {} + + // The pool uses this method to select a connection with the least + // reconfiguration cost. 0 means a perfect match; any positive integer + // value indicates mismatch. It is up to the callback implementor + // to decide how to assign the cost values. + public int cost(Properties reqLabels, Properties currentLabels) { + // Case 1: exact match + if (reqLabels.equals(currentLabels)) { + if (!printed1) { + printed1 = true; + show(" FROM callback cost(): ## Exact match found ##"); + } + return 0; + } + + // Case 2: partial match + String iso1 = (String) reqLabels.get("TRANSACTION_ISOLATION"); + String iso2 = (String) currentLabels.get("TRANSACTION_ISOLATION"); + boolean match = + (iso1 != null && iso2 != null && iso1.equalsIgnoreCase(iso2)); + Set rKeys = reqLabels.keySet(); + Set cKeys = currentLabels.keySet(); + if (match && rKeys.containsAll(cKeys)) { + if (!printed2) { + printed2 = true; + show(" FROM callback cost(): ## Partial match found ##"); + } + return 10; + } + + // Case 3: no label matches application's preference. + // Picking this connection incurs the highest reinitialization cost. + if (!printed3) { + printed3 = true; + show(" FROM callback cost(): ## No match found ##"); + } + return Integer.MAX_VALUE; + } + + // In case a connection does not fully match the requested labels + // (and corresponding session state), configures the connection + // to establish the desired labels and state. This is done before + // the connection is returned to applications for a borrow request. + public boolean configure(Properties reqLabels, Object conn) { + try { + show(" Callback configure() is called to reinitialize connection"); + + String isoStr = (String) reqLabels.get("TRANSACTION_ISOLATION"); + // Map label value to isolation level constants on Connection. + ((Connection)conn).setTransactionIsolation(Integer.valueOf(isoStr)); + + LabelableConnection lconn = (LabelableConnection) conn; + + // Find the unmatched labels on this connection + Properties unmatchedLabels = + lconn.getUnmatchedConnectionLabels(reqLabels); + + // Apply each label in unmatchedLabels to connection. + // A real callback should also apply the corresponding state change. + for (Map.Entry label : unmatchedLabels.entrySet()) { + String key = (String) label.getKey(); + String value = (String) label.getValue(); + + lconn.applyConnectionLabel(key, value); + } + } catch (Exception exc) { + return false; + } + + return true; + } + } +} + diff --git a/java/jdbc/BasicSamples/UCPManager.java b/java/jdbc/BasicSamples/UCPManager.java new file mode 100755 index 00000000..a1eefe6b --- /dev/null +++ b/java/jdbc/BasicSamples/UCPManager.java @@ -0,0 +1,358 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This code sample illustrates how applications use UCP manager's + * administration functions. These include: + * + * 1) createConnectionPool + * 2) stopConnectionPool + * 3) startConnectionPool + * 4) refreshConnectionPool + * 5) recycleConnectionPool + * 6) purgeConnectionPool + * 7) getConnectionPool + * 8) getConnectionPoolNames + * 9) destoryConnectionPool + * + * It is required that applications have both ucp.jar and Oracle JDBC + * driver jar(s) (such as ojdbc8.jar or ojdbc7.jar) on the classpath, + * and that the database backend supports SQL (this sample uses an + * Oracle Database and the default HR schema). + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java UCPManager -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.SQLException; + +import oracle.ucp.UniversalConnectionPool; +import oracle.ucp.UniversalConnectionPoolException; +import oracle.ucp.admin.UniversalConnectionPoolManager; +import oracle.ucp.admin.UniversalConnectionPoolManagerImpl; +import oracle.ucp.jdbc.PoolDataSource; +import oracle.ucp.jdbc.PoolDataSourceFactory; +import oracle.ucp.jdbc.PoolDataSourceImpl; + + +public class UCPManager { + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + // Shared by all methods + private PoolDataSource pds = null; + + // Shared by all methods + private static UniversalConnectionPoolManager mgr = null; + + final static String POOL_NAME = "UCPManager_pool"; + + public static void main(String args[]) throws Exception { + UCPManager sample = new UCPManager(); + + getRealUserPasswordUrl(args); + sample.run(); + } + + void run() throws Exception { + mgr = UniversalConnectionPoolManagerImpl.getUniversalConnectionPoolManager(); + pds = createPoolDataSource(POOL_NAME); + + demoCreateConnectionPool(); + demoStartConnectionPool(); + demoStopConnectionPool(); + demoRefreshConnectionPool(); + demoRecycleConnectionPool(); + demoPurgeConnectionPool(); + demoGetConnectionPool(); + demoGetConnectionPoolNames(); + demoDestroyConnectionPool(); + } + + private void demoCreateConnectionPool() { + try { + show("\n-- demoCreateConnectionPool -- "); + + // Creates the embedded connection pool instance in the data source. + mgr.createConnectionPool((PoolDataSourceImpl) pds); + + show("\nConnection pool " + POOL_NAME + " is created from manager"); + } catch (Exception e) { + showError("demoCreateConnectionPool", e); + } + } + + private void demoStartConnectionPool() { + try { + show("\n-- demoStartConnectionPool -- "); + + // Starts the embedded connection pool instance. + mgr.startConnectionPool(POOL_NAME); + + show("\nConnection pool " + POOL_NAME + " is started from manager"); + showPoolStatistics("After pool start", pds); + } catch(Exception e) { + showError("demoStartConnectionPool", e); + } + } + + private void demoStopConnectionPool() { + try { + show("\n-- demoStopConnectionPool -- "); + + // Stops the embedded connection pool instance. + mgr.stopConnectionPool(POOL_NAME); + + show("\nConnection pool " + POOL_NAME + " is stopped from manager"); + showPoolStatistics("After pool stop", pds); + } catch (Exception e) { + showError("demoStopConnectionPool", e); + } + } + + // Refreshing a connection pool replaces every connection in the pool + // with a new connection. Any borrowed connection is marked for removal + // only, and will be refreshed after the connection is returned to the pool. + private void demoRefreshConnectionPool() { + try { + show("\n-- demoRefreshConnectionPool -- "); + + show("\nSets the initial pool size to 10"); + pds.setInitialPoolSize(10); + + show("\nBorrow a connection from the pool"); + Connection con = pds.getConnection(); + // There will be 9 available connections and 1 borrowed connection. + showPoolStatistics("After borrow and before pool refresh", pds); + + // Refreshes the embedded connection pool instance. + mgr.refreshConnectionPool(POOL_NAME); + show("\nConnection pool " + POOL_NAME + " is refreshed from manager"); + + // Only available connections are immediately refreshed, so there + // will still be 9 available connections and 1 borrowed connection. + showPoolStatistics("After pool refresh", pds); + + // This last connection will be refreshed after returned to pool. + show("\nReturn the borrowed connection to the pool"); + con.close(); + // Wait for pool to asynchronously replace connection. + Thread.sleep(20000); + showPoolStatistics("After last return", pds); + } catch (Exception e) { + showError("demoRefreshConnectionPool", e); + } + } + + // Recycling a connection pool replaces only invalid connections in the pool + // with new connections and does not replace borrowed connections. + private void demoRecycleConnectionPool() { + try { + show("\n-- demoRecycleConnectionPool -- "); + + showPoolStatistics("Before any action", pds); + + show("\nBorrow a connection from the pool"); + Connection con = pds.getConnection(); + // There will be 9 available connections and 1 borrowed connection. + showPoolStatistics("After borrow and before pool recycle", pds); + + // Recycles the embedded connection pool instance. + mgr.recycleConnectionPool(POOL_NAME); + show("\nConnection pool " + POOL_NAME + " is recycled from manager"); + + // Only invalid connections are recycled, so there will still be + // 9 available connections and 1 borrowed connection. + showPoolStatistics("After pool recycle", pds); + + // Return last borrowed connection to the pool. + con.close(); + // Wait for pool to asynchronously validate returned connection. + Thread.sleep(20000); + } catch (Exception e) { + showError("demoRecycleConnectionPool", e); + } + } + + // Purging a connection pool removes every connection (available and + // borrowed) from the connection pool and leaves the pool empty. + private void demoPurgeConnectionPool() { + try { + show("\n-- demoPurgeConnectionPool -- "); + + showPoolStatistics("Before any action", pds); + + show("\nBorrow a connection from the pool"); + Connection con = pds.getConnection(); + // There will be 9 available connections and 1 borrowed connection. + showPoolStatistics("After borrow and before pool purge", pds); + + // Purges the embedded connection pool instance. + mgr.purgeConnectionPool(POOL_NAME); + show("\nConnection pool " + POOL_NAME + " is purged from manager"); + + // All connections are removed, so 0 for both available and borrowed. + showPoolStatistics("After pool purge", pds); + } catch (Exception e) { + showError("demoPurgeConnectionPool", e); + } + } + + private void demoGetConnectionPool() { + try { + show("\n-- demoGetConnectionPool -- "); + + UniversalConnectionPool pool = mgr.getConnectionPool(POOL_NAME); + + show("\nObtained UCP pool object for " + POOL_NAME + + ": " + pool); + } catch (Exception e) { + showError("demoGetConnectionPool", e); + } + } + + private void demoGetConnectionPoolNames() { + try { + show("\n-- demoGetConnectionPoolNames -- "); + + String names[] = mgr.getConnectionPoolNames(); + + show("\nObtained all pool names in this UCP manager:"); + for (int i = 0; i < names.length; i++) { + show("Pool [" +i +"] : " + names[i]); + } + } catch (Exception e) { + showError("demoGetConnectionPoolNames", e); + } + } + + private void demoDestroyConnectionPool() { + try { + show("\n-- demoDestroyConnectionPool -- "); + + showPoolStatistics("Before any action", pds); + + show("\nBorrow a connection from the pool"); + Connection con = pds.getConnection(); + showPoolStatistics("After borrow", pds); + + show("\nReturn the connection to pool"); + con.close(); + showPoolStatistics("After return and before pool destroy", pds); + + // Destroys the embedded connection pool instance. + mgr.destroyConnectionPool(POOL_NAME); + show("\nConnection pool " + POOL_NAME + " is destroyed from manager"); + + try { + show("\nTry to borrow another connection from the pool "); + pds.getConnection(); + } catch (Exception e) { + show("\nGot expected error, cannot borrow since pool is destroyed"); + } + } catch (Exception e) { + showError("demoDestroyConnectionPool", e); + } + } + + // See sample UCPBasic.java for basic steps to set up a connection pool. + PoolDataSource createPoolDataSource(String poolName) throws Exception { + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS); + pds.setURL(url); + pds.setUser(user); + pds.setPassword(password); + pds.setConnectionPoolName(poolName); + + return pds; + } + + void showPoolStatistics(String prompt, PoolDataSource pds) + throws SQLException { + show(prompt + " -"); + show(" Available connections: " + pds.getAvailableConnectionsCount()); + show(" Borrowed connections: " + pds.getBorrowedConnectionsCount()); + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } +} + diff --git a/java/jdbc/BasicSamples/UCPManagerMBean.java b/java/jdbc/BasicSamples/UCPManagerMBean.java new file mode 100755 index 00000000..c1d2a88c --- /dev/null +++ b/java/jdbc/BasicSamples/UCPManagerMBean.java @@ -0,0 +1,377 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This code sample illustrates how applications use UCP manager MBean's + * administration functions. These include: + * + * 1) createConnectionPool + * 2) stopConnectionPool + * 3) startConnectionPool + * 4) refreshConnectionPool + * 5) recycleConnectionPool + * 6) purgeConnectionPool + * 7) destoryConnectionPool + * + * It is required that applications have both ucp.jar and Oracle JDBC + * driver jar(s) (such as ojdbc8.jar or ojdbc7.jar) on the classpath, + * and that the database backend supports SQL (this sample uses an + * Oracle Database and the default HR schema). + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java UCPManagerMBean -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.SQLException; + +import javax.management.MBeanServer; +import javax.management.MBeanServerFactory; +import javax.management.ObjectName; + +import oracle.ucp.admin.UniversalConnectionPoolManagerMBean; +import oracle.ucp.admin.UniversalConnectionPoolManagerMBeanImpl; +import oracle.ucp.jdbc.PoolDataSource; +import oracle.ucp.jdbc.PoolDataSourceFactory; + + +public class UCPManagerMBean { + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + final static String POOL_NAME = "UCPManagerMBean_pool"; + + // Shared by all methods + private PoolDataSource pds = null; + + private static MBeanServer mbs = null; + + // Shared by all methods + private UniversalConnectionPoolManagerMBean mgrMBean = null; + + // Shared by all methods + private String OBJECT_NAME = null; + + + public static void main(String args[]) throws Exception { + UCPManagerMBean sample = new UCPManagerMBean(); + + getRealUserPasswordUrl(args); + sample.run(); + } + + void run() throws Exception { + // Get the UniversalConnectionPoolManagerMBean instance. + mgrMBean = UniversalConnectionPoolManagerMBeanImpl + .getUniversalConnectionPoolManagerMBean(); + + // Find an existing MBean Server + mbs = (MBeanServer) MBeanServerFactory.findMBeanServer(null).iterator().next(); + pds = createPoolDataSource(POOL_NAME); + + OBJECT_NAME = + "oracle.ucp.admin:name=UniversalConnectionPoolManagerMBean("+ + UniversalConnectionPoolManagerMBeanImpl.class.hashCode()+")"; + + demoCreateConnectionPool(); + demoStartConnectionPool(); + demoStopConnectionPool(); + demoRefreshConnectionPool(); + demoRecycleConnectionPool(); + demoPurgeConnectionPool(); + demoDestroyConnectionPool(); + } + + private void demoCreateConnectionPool() { + try { + show("\n-- demoCreateConnectionPool -- "); + + // Build required parameters to invoke MBean operation. + ObjectName objName = new ObjectName(OBJECT_NAME); + Object[] params = { pds }; + String[] signature = {"oracle.ucp.UniversalConnectionPoolAdapter"}; + + // Create the pool using Manager MBean. + mbs.invoke(objName, "createConnectionPool", params, signature); + + show("\nConnection pool " + POOL_NAME + " is created from MBean"); + } catch (Exception e) { + showError("demoCreateConnectionPool", e); + } + } + + private void demoStartConnectionPool() { + try { + show("\n-- demoStartConnectionPool -- "); + + // Build required parameters to invoke MBean operation. + ObjectName objName = new ObjectName(OBJECT_NAME); + Object[] params = { POOL_NAME }; + String[] signature = { "java.lang.String" }; + + // Start the pool using Manager MBean. + mbs.invoke(objName, "startConnectionPool", params, signature); + + show("\nConnection pool " + POOL_NAME + " is started from MBean"); + showPoolStatistics("After pool start", pds); + } catch(Exception e) { + showError("demoStartConnectionPool", e); + } + } + + private void demoStopConnectionPool() { + try { + show("\n-- demoStopConnectionPool -- "); + + // Build required parameters to invoke MBean operation. + ObjectName objName = new ObjectName(OBJECT_NAME); + Object[] params = { POOL_NAME }; + String[] signature = { "java.lang.String" }; + + // Stop the pool using Manager MBean. + mbs.invoke(objName, "stopConnectionPool", params, signature); + + show("\nConnection pool " + POOL_NAME + " is stopped from MBean"); + showPoolStatistics("After pool stop", pds); + } catch (Exception e) { + showError("demoStopConnectionPool", e); + } + } + + // Refreshing a connection pool replaces every connection in the pool + // with a new connection. Any borrowed connection is marked for removal + // only, and will be refreshed after the connection is returned to the pool. + private void demoRefreshConnectionPool() { + try { + show("\n-- demoRefreshConnectionPool -- "); + + show("\nSets the initial pool size to 10"); + pds.setInitialPoolSize(10); + + show("\nBorrow a connection from the pool"); + Connection con = pds.getConnection(); + // There will be 9 available connections and 1 borrowed connection. + showPoolStatistics("After borrow and before pool refresh", pds); + + // Build required parameters to invoke MBean operation. + ObjectName objName = new ObjectName(OBJECT_NAME); + Object[] params = { POOL_NAME }; + String[] signature = { "java.lang.String" }; + + // Refresh the connection pool using Manager MBean. + mbs.invoke(objName, "refreshConnectionPool", params, signature); + show("\nConnection pool " + POOL_NAME + " is refreshed from MBean"); + + // Only available connections are immediately refreshed, so there + // will still be 9 available connections and 1 borrowed connection. + showPoolStatistics("After pool refresh", pds); + + // This last connection will be refreshed after returned to pool. + show("\nReturn the borrowed connection to the pool"); + con.close(); + // Wait for pool to asynchronously replace connection. + Thread.sleep(20000); + showPoolStatistics("After last return", pds); + } catch (Exception e) { + showError("demoRefreshConnectionPool", e); + } + } + + // Recycling a connection pool replaces only invalid connections in the pool + // with new connections and does not replace borrowed connections. + private void demoRecycleConnectionPool() { + try { + show("\n-- demoRecycleConnectionPool -- "); + + showPoolStatistics("Before any action", pds); + + show("\nBorrow a connection from the pool"); + Connection con = pds.getConnection(); + // There will be 9 available connections and 1 borrowed connection. + showPoolStatistics("After borrow and before pool recycle", pds); + + // Build required parameters to invoke MBean operation. + ObjectName objName = new ObjectName(OBJECT_NAME); + Object[] params = { POOL_NAME }; + String[] signature = { "java.lang.String" }; + + // Recycle the pool using Manager MBean. + mbs.invoke(objName, "recycleConnectionPool", params, signature); + show("\nConnection pool " + POOL_NAME + " is recycled from MBean"); + + // Only invalid connections are recycled, so there will still be + // 9 available connections and 1 borrowed connection. + showPoolStatistics("After pool recycle", pds); + + // Return last borrowed connection to the pool. + con.close(); + // Wait for pool to asynchronously validate returned connection. + Thread.sleep(20000); + } catch (Exception e) { + showError("demoRecycleConnectionPool", e); + } + } + + // Purging a connection pool removes every connection (available and + // borrowed) from the connection pool and leaves the pool empty. + private void demoPurgeConnectionPool() { + try { + show("\n-- demoPurgeConnectionPool -- "); + + showPoolStatistics("Before any action", pds); + + show("\nBorrow a connection from the pool"); + Connection con = pds.getConnection(); + // There will be 9 available connections and 1 borrowed connection. + showPoolStatistics("After borrow and before pool purge", pds); + + // Build required parameters to invoke MBean operation. + ObjectName objName = new ObjectName(OBJECT_NAME); + Object[] params = { POOL_NAME }; + String[] signature = { "java.lang.String" }; + + // Purge the pool using Manager MBean. + mbs.invoke(objName, "purgeConnectionPool", params, signature); + show("\nConnection pool " + POOL_NAME + " is purged from MBean"); + + // All connections are removed, so 0 for both available and borrowed. + showPoolStatistics("After pool purge", pds); + } catch (Exception e) { + showError("demoPurgeConnectionPool", e); + } + } + + private void demoDestroyConnectionPool() { + try { + show("\n-- demoDestroyConnectionPool -- "); + + showPoolStatistics("Before any action", pds); + + show("\nBorrow a connection from the pool"); + Connection con = pds.getConnection(); + showPoolStatistics("After borrow", pds); + + show("\nReturn the connection to pool"); + con.close(); + showPoolStatistics("After return and before pool destroy", pds); + + // Build required parameters to invoke MBean operation. + ObjectName objName = new ObjectName(OBJECT_NAME); + Object[] params = { POOL_NAME }; + String[] signature = { "java.lang.String" }; + + // Destroy the pool using Manager MBean. + mbs.invoke(objName, "destroyConnectionPool", params, signature); + show("\nConnection pool " + POOL_NAME + " is destroyed from MBean"); + + try { + show("\nTry to borrow another connection from the pool "); + pds.getConnection(); + } catch (Exception e) { + show("\nGot expected error, cannot borrow since pool is destroyed"); + } + } catch (Exception e) { + showError("demoDestroyConnectionPool", e); + } + } + + // See sample UCPBasic.java for basic steps to set up a connection pool. + PoolDataSource createPoolDataSource(String poolName) throws Exception { + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS); + pds.setURL(url); + pds.setUser(user); + pds.setPassword(password); + pds.setConnectionPoolName(poolName); + + return pds; + } + + void showPoolStatistics(String prompt, PoolDataSource pds) + throws SQLException { + show(prompt + " -"); + show(" Available connections: " + pds.getAvailableConnectionsCount()); + show(" Borrowed connections: " + pds.getBorrowedConnectionsCount()); + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } +} + diff --git a/java/jdbc/BasicSamples/UCPMaxConnReuse.java b/java/jdbc/BasicSamples/UCPMaxConnReuse.java new file mode 100755 index 00000000..faf95c2b --- /dev/null +++ b/java/jdbc/BasicSamples/UCPMaxConnReuse.java @@ -0,0 +1,317 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This code sample illustrates how applications use the MaxConnectionReuseTime + * and MaxConnectionReuseCount features of Oracle Universal Connection Pool + * (UCP). + * + * The maximum connection reuse time allows connections to be gracefully + * closed and removed from the pool after a connection has been in use for + * a specific amount of time. The timer for this property starts when a + * connection is physically created. Borrowed connections are closed only + * after they are returned to the pool and the reuse time is exceeded. + * + * This feature is typically used when a firewall exists between the pool tier + * and the database tier and is setup to block connections based on time + * restrictions. The blocked connections remain in the pool even though + * they are unusable. In such scenarios, the connection reuse time can be + * set to a smaller value than the firewall timeout policy. + * + * The time is measured in seconds. 0 disables the feature, which is + * the default. + * + * The maximum connection reuse count works similarly, allowing a connection + * to be closed and removed from the pool after it has been borrowed + * a specific number of times. + * + * Value 0 disables the feature, which is the default. + * + * It is required that applications have both ucp.jar and Oracle JDBC + * driver jar(s) (such as ojdbc8.jar or ojdbc7.jar) on the classpath, + * and that the database backend supports SQL (this sample uses an + * Oracle Database and the default HR schema). + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java UCPMaxConnReuse -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.SQLException; + +import oracle.ucp.admin.UniversalConnectionPoolManagerImpl; +import oracle.ucp.jdbc.PoolDataSource; +import oracle.ucp.jdbc.PoolDataSourceFactory; + + +public class UCPMaxConnReuse { + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + public static void main(String args[]) throws Exception { + UCPMaxConnReuse sample = new UCPMaxConnReuse(); + + getRealUserPasswordUrl(args); + sample.run(); + } + + void run() throws Exception { + demoMaxConnectionReuseTime(); + demoMaxConnectionReuseCount(); + } + + public void demoMaxConnectionReuseTime() throws Exception { + show("\n*** Demo MaxConnectionReuseTime ***"); + + try { + final String POOL_NAME = "UCPMaxConnReuse_pool1"; + Connection[] conns = new Connection[3]; + String[] connStrs = new String[3]; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + + // Each connection in the pool will be reusable for 25 seconds after + // its creation. Then it will be gracefully closed and removed on + // its next return to the pool. + pds.setMaxConnectionReuseTime(25); + + show("Connection pool " + POOL_NAME + " configured"); + + show("\nBorrow conns[0] from pool."); + conns[0] = pds.getConnection(); + connStrs[0] = ((Object)conns[0]).toString(); + + showPoolStatistics("After conns[0] is borrowed", pds); + + show("\nReturn conns[0] to pool."); + conns[0].close(); + + showPoolStatistics("After conns[0] is returned", pds); + + show("\nBorrow conns[1] from pool."); + conns[1] = pds.getConnection(); + connStrs[1] = ((Object)conns[1]).toString(); + + show("conns[0] and conns[1] should be equal : " + + connStrs[0].equals(connStrs[1])); + + show("\nSleep for 30 seconds that exceeds MaxConnnectionReuseTime."); + Thread.sleep(30000); + + show("\nconns[1] is not closed, since it's still borrowed."); + showPoolStatistics("Just before conns[1] is returned to pool", pds); + + show("\nReturn conns[1] to pool."); + show("This will close the physical connection in the pool."); + // Close the second connection. Since this connection has exceeded + // MaxConnectionReuseTime, it will be closed and removed from the pool. + conns[1].close(); + + showPoolStatistics("\nAfter conns[1] is returned", pds); + + // Get the third connection. This should be a new physical connection + // from conns[1]. + show("\nBorrow conns[2] from pool."); + conns[2] = pds.getConnection(); + connStrs[2] = ((Object)conns[2]).toString(); + + show("conns[0] and conns[2] should not be equal : " + + !connStrs[0].equals(connStrs[2])); + + show("conns[1] and conns[2] should not be equal : " + + !connStrs[1].equals(connStrs[2])); + + show("\nReturn conns[2] to pool."); + conns[2].close(); + + destroyConnectionPool(POOL_NAME); + + } catch (Throwable e) { + showError("demoMaxConnectionReuseTime", e); + } + + show("\n*** Demo MaxConnectionReuseTime completes ***"); + } + + public void demoMaxConnectionReuseCount() throws Exception { + show("\n*** Demo MaxConnectionReuseCount ***"); + + try { + final String POOL_NAME = "UCPMaxConnReuse_pool2"; + Connection[] conns = new Connection[3]; + String[] connStrs = new String[3]; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + + // Each connection in the pool will be reusable for 2 borrow's + // after its creation. Then it will be gracefully closed and + // removed on its next (i.e., 2nd) return to the pool. + pds.setMaxConnectionReuseCount(2); + + show("Connection pool " + POOL_NAME + " configured"); + + show("\nBorrow conns[0] from pool."); + conns[0] = pds.getConnection(); + connStrs[0] = ((Object)conns[0]).toString(); + + showPoolStatistics("After conns[0] is borrowed", pds); + + show("\nReturn conns[0] to pool."); + conns[0].close(); + + showPoolStatistics("After conns[0] is returned", pds); + + show("\nBorrow conns[1] from pool."); + conns[1] = pds.getConnection(); + connStrs[1] = ((Object)conns[1]).toString(); + + show("conns[0] and conns[1] should be equal : " + + connStrs[0].equals(connStrs[1])); + + show("\nconns[1]'s physical connection has reached MaxConnnectionReuseCount."); + + show("It is not closed right away, since it's still borrowed."); + showPoolStatistics("\nJust before conns[1] is returned to pool", pds); + + show("\nReturn conns[1] to pool."); + show("This will close the physical connection in the pool."); + // Close the second connection. Since this connection has exceeded + // MaxConnectionReuseCount, it will be closed and removed from the pool. + conns[1].close(); + + showPoolStatistics("\nAfter conns[1] is returned", pds); + + // Get the third connection. This should be a new physical connection + // from conns[1]. + show("\nBorrow conns[2] from pool."); + conns[2] = pds.getConnection(); + connStrs[2] = ((Object)conns[2]).toString(); + + show("conns[0] and conns[2] should not be equal : " + + !connStrs[0].equals(connStrs[2])); + + show("conns[1] and conns[2] should not be equal : " + + !connStrs[1].equals(connStrs[2])); + + show("\nReturn conns[2] to pool."); + conns[2].close(); + + destroyConnectionPool(POOL_NAME); + + } catch (Throwable e) { + showError("demoMaxConnectionReuseCount", e); + } + + show("\n*** Demo MaxConnectionReuseCount completes ***"); + } + + // See sample UCPBasic.java for basic steps to set up a connection pool. + PoolDataSource createPoolDataSource(String poolName) throws Exception { + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS); + pds.setURL(url); + pds.setUser(user); + pds.setPassword(password); + pds.setConnectionPoolName(poolName); + + return pds; + } + + void destroyConnectionPool(String poolName) { + try { + UniversalConnectionPoolManagerImpl.getUniversalConnectionPoolManager() + .destroyConnectionPool(poolName); + show("\nConnection pool " + poolName + " destroyed"); + } catch (Throwable e) { + showError("destroyConnectinoPool", e); + } + } + + void showPoolStatistics(String prompt, PoolDataSource pds) + throws SQLException { + show(prompt + " -"); + show(" Available connections: " + pds.getAvailableConnectionsCount()); + show(" Borrowed connections: " + pds.getBorrowedConnectionsCount()); + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } +} + diff --git a/java/jdbc/BasicSamples/UCPMultiUsers.java b/java/jdbc/BasicSamples/UCPMultiUsers.java new file mode 100755 index 00000000..c4f72443 --- /dev/null +++ b/java/jdbc/BasicSamples/UCPMultiUsers.java @@ -0,0 +1,172 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This code sample illustrates how JDBC applications use the Oracle + * Universal Connection Pool (UCP) to pool connections for different + * users. + * + * It is required that applications have both ucp.jar and Oracle JDBC + * driver jar(s) (such as ojdbc8.jar or ojdbc7.jar) on the classpath, + * and that the database backend supports SQL (this sample uses an + * Oracle Database and the default HR schema). + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java UCPMultiUsers -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.SQLException; +import java.sql.Statement; + +import oracle.ucp.jdbc.PoolDataSourceFactory; +import oracle.ucp.jdbc.PoolDataSource; + + +public class UCPMultiUsers { + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + // Modify these if user "scott" is locked in DB. + final static String USER2 = "scott"; + final static String PASSWORD2 = "tiger"; + + public static void main(String args[]) throws Exception { + getRealUserPasswordUrl(args); + + show("\nUCPMultiUsers starts"); + + // See sample UCPBasic for basic steps to set up a pool. + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS); + pds.setURL(url); + pds.setUser(user); + pds.setPassword(password); + pds.setConnectionPoolName("UCPMultiUsers_pool"); + + show("Connection pool configured"); + + try (Connection conn1 = pds.getConnection()) { + showPoolStatistics("\nAfter checkout for "+user, pds); + + makeJDBCCalls(conn1); + } catch (SQLException exc) { + showError("Checkout with "+user, exc); + } + + showPoolStatistics("\nAfter checkin for "+user, pds); + + // Use this version of getConnection with different users. + try (Connection conn2 = pds.getConnection(USER2, PASSWORD2)) { + showPoolStatistics("\nAfter checkout for "+USER2, pds); + + makeJDBCCalls(conn2); + } catch (SQLException exc) { + showError("Checkout with "+USER2, exc); + } + + showPoolStatistics("\nAfter checkin for "+USER2, pds); + + show("\nUCPMultiUsers completes"); + } + + // Simple query + static void makeJDBCCalls(Connection conn) { + try (Statement statement = conn.createStatement()) { + try (java.sql.ResultSet rset = statement.executeQuery("SELECT USER FROM DUAL")) { + rset.next(); + show("\n Current user: " + rset.getString(1)); + } + } catch (SQLException exc) { + showError("JDBC operation", exc); + } + } + + static void showPoolStatistics(String prompt, PoolDataSource pds) + throws SQLException { + show(prompt + " -"); + show(" Available connections: " + pds.getAvailableConnectionsCount()); + show(" Borrowed connections: " + pds.getBorrowedConnectionsCount()); + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.err.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } +} + diff --git a/java/ucp/ConnectionManagementSamples/UCPSample.java b/java/jdbc/BasicSamples/UCPSample.java similarity index 100% rename from java/ucp/ConnectionManagementSamples/UCPSample.java rename to java/jdbc/BasicSamples/UCPSample.java diff --git a/java/jdbc/BasicSamples/UCPTimeouts.java b/java/jdbc/BasicSamples/UCPTimeouts.java new file mode 100755 index 00000000..5bc1cc14 --- /dev/null +++ b/java/jdbc/BasicSamples/UCPTimeouts.java @@ -0,0 +1,412 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved.*/ + +/* + * DESCRIPTION + * + * This code sample illustrates key connection timeout features of the + * Oracle Universal Connection Pool (UCP). These include: + * 1) ConnectionWaitTimeout + * 2) InactiveConnectionTimeout + * 3) TimeToLiveConnectionTimeout + * 4) AbandonedConnectionTimeout + * + * It is required that applications have both ucp.jar and Oracle JDBC + * driver jar(s) (such as ojdbc8.jar or ojdbc7.jar) on the classpath, + * and that the database backend supports SQL (this sample uses an + * Oracle Database and the default HR schema). + * + * To run the sample, you must provide non-default and working values + * for ALL 3 of user, password, and URL. This can be done by either updating + * this file directly or supplying the 3 values as command-line options + * and user input. The password is read from console or standard input. + * java UCPTimeouts -l -u + * If you do not update all the defaults, the program proceeds but + * will hit error when connecting. + */ + +import java.io.BufferedReader; +import java.io.InputStreamReader; +import java.sql.Connection; +import java.sql.SQLException; +import java.sql.Statement; +import java.util.Timer; +import java.util.TimerTask; + +import oracle.ucp.admin.UniversalConnectionPoolManagerImpl; +import oracle.ucp.jdbc.PoolDataSourceFactory; +import oracle.ucp.jdbc.PoolDataSource; + + +public class UCPTimeouts { + final static String DEFAULT_URL = "jdbc:oracle:thin:@//myhost:myport/myservice"; + final static String DEFAULT_USER = "myuser"; + final static String DEFAULT_PASSWORD = "mypassword"; + final static String CONN_FACTORY_CLASS = "oracle.jdbc.pool.OracleDataSource"; + + // 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; + + public static void main(String args[]) throws Exception { + UCPTimeouts sample = new UCPTimeouts(); + + getRealUserPasswordUrl(args); + sample.run(); + } + + void run() throws Exception { + demoConnectionWaitTimeout(); + demoInactiveConnectionTimeout(); + demoTimeToLiveConnectionTimeout(); + demoAbandonedConnectionTimeout(); + } + + /* + * The connection wait timeout specifies how long, in seconds, application + * requests wait to obtain a connection, if there are no available + * connections inside the pool. The application receives an SQLException + * if the timeout is reached. + * + * A value of 0 disables this feature. The default is 3 seconds. + */ + private void demoConnectionWaitTimeout() { + show("\n*** Demo ConnectionWaitTimeout ***"); + + try { + final int MAX_POOL_SIZE = 5; + final String POOL_NAME = "UCPTimeouts_pool1"; + Connection conns[] = new Connection[MAX_POOL_SIZE]; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + pds.setMaxPoolSize(MAX_POOL_SIZE); + // Set ConnectionWaitTimeout to 8 seconds + pds.setConnectionWaitTimeout(8); + pds.setTimeoutCheckInterval(5); + + show("Connection pool " + POOL_NAME + " configured"); + show("Max pool size: " + pds.getMaxPoolSize()); + + show("\nBorrow connections to reach max pool size."); + + for (int i = 0; i < MAX_POOL_SIZE; i++) { + conns[i] = pds.getConnection(); + } + + showPoolStatistics("After all connections are borrowed", pds); + + try { + show("\nNow trying to borrow another connection from pool ..."); + + // This request is expected to fail after ConnectionWaitTimeout. + Connection conn = pds.getConnection(); + } catch (Exception e) { + show("\nGetting expected error after ConnectionWaitTimeout"); + } + + show("\nReturn all borrowed connections to pool"); + // Return all borrowed connections to pool. + for (int i = 0; i < MAX_POOL_SIZE; i++) { + conns[i].close(); + conns[i] = null; + } + + destroyConnectionPool(POOL_NAME); + + } catch (Throwable e) { + showError("demoConnectionWaitTimeout", e); + } + + show("\n*** Demo ConnectionWaitTimeout completes ***"); + } + + /* + * The inactive connection timeout specifies how long, in seconds, + * an available connection can remain idle inside the pool, before + * it is closed and removed from the pool. This timeout property is + * only applicable to available connections and does not affect borrowed + * connections. + * + * A value 0 disables this feature. By default, this timeout is disabled. + */ + private void demoInactiveConnectionTimeout() { + show("\n*** Demo InactiveConnectionTimeout ***"); + + try { + final int MIN_POOL_SIZE = 5; + final int MAX_POOL_SIZE = 10; + final String POOL_NAME = "UCPTimeouts_pool2"; + Connection conns[] = new Connection[MAX_POOL_SIZE]; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + pds.setMinPoolSize(MIN_POOL_SIZE); + pds.setMaxPoolSize(MAX_POOL_SIZE); + // Set InactiveConnectionTimeout to 10 seconds + pds.setInactiveConnectionTimeout(10); + pds.setTimeoutCheckInterval(5); + + show("Connection pool " + POOL_NAME + " configured"); + show("Min pool size: " + pds.getMinPoolSize()); + show("Max pool size: " + pds.getMaxPoolSize()); + + show("\nBorrow connections to reach min pool size."); + + // First borrow all connections in the pool + for (int i = 0; i < MAX_POOL_SIZE; i++) { + conns[i] = pds.getConnection(); + } + + // Return all connections beyond MinPoolSize to pool + for (int i = MIN_POOL_SIZE; i < MAX_POOL_SIZE; i++) { + conns[i].close(); + } + + showPoolStatistics("After borrowing connections", pds); + + show("\nSleep for 15 seconds to trigger InactiveConnectionTimeout."); + show("Available connections beyond MinPoolSize are expected to close"); + + try { + Thread.sleep(15000); + } catch (InterruptedException e) {} + + showPoolStatistics("\nAfter InactiveConnectionTimeout", pds); + + show("\nReturn all borrowed connections to pool"); + // Return all borrowed connections to pool. + for (int i = 0; i < MIN_POOL_SIZE; i++) { + conns[i].close(); + conns[i] = null; + } + + destroyConnectionPool(POOL_NAME); + + } catch (Throwable e) { + showError("demoInactiveConnectionTimeout", e); + } + + show("\n*** Demo InactiveConnectionTimeout completes ***"); + } + + /* + * The time-to-live connection timeout enables borrowed connections to + * remain borrowed for a specific amount of time before the connection + * is reclaimed by the pool. The timeout is in seconds. + * + * A value 0 disables this feature. By default, this timeout is disabled. + */ + private void demoTimeToLiveConnectionTimeout() { + show("\n*** Demo TimeToLiveConnectionTimeout ***"); + + try { + final int MAX_POOL_SIZE = 5; + final String POOL_NAME = "UCPTimeouts_pool3"; + Connection conns[] = new Connection[MAX_POOL_SIZE]; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + pds.setMaxPoolSize(MAX_POOL_SIZE); + // Set TimeToLiveConnectionTimeout to 10 seconds + pds.setTimeToLiveConnectionTimeout(10); + pds.setTimeoutCheckInterval(5); + + show("Connection pool " + POOL_NAME + " configured"); + show("Max pool size: " + pds.getMaxPoolSize()); + + show("\nBorrow connections to reach max pool size."); + + for (int i = 0; i < MAX_POOL_SIZE; i++) { + conns[i] = pds.getConnection(); + } + + showPoolStatistics("After all connections are borrowed", pds); + + show("\nSleep for 15 seconds to trigger TimeToLiveConnectionTimeout."); + show("All borrowed connections are expected to be returned to pool."); + + try { + Thread.sleep(15000); + } catch (InterruptedException e) {} + + showPoolStatistics("\nAfter TimeToLiveConnectionTimeout", pds); + + destroyConnectionPool(POOL_NAME); + + } catch (Throwable e) { + showError("demoTimeToLiveConnectionTimeout", e); + } + + show("\n*** Demo TimeToLiveConnectionTimeout completes ***"); + } + + /* + * The abandoned connection timeout (ACT) enables a borrowed connection + * to be reclaimed back into the connection pool, after that borrowed + * connection has not been used for a specific amount of time. + * The timeout is in seconds. + * + * A value 0 disables this feature. By default, this timeout is disabled. + */ + private void demoAbandonedConnectionTimeout() { + show("\n*** Demo AbandonedConnectionTimeout ***"); + + try { + final int MAX_POOL_SIZE = 10; + final String POOL_NAME = "UCPTimeouts_pool4"; + Connection conns[] = new Connection[MAX_POOL_SIZE]; + + PoolDataSource pds = createPoolDataSource(POOL_NAME); + pds.setMaxPoolSize(MAX_POOL_SIZE); + // Set AbandonedConnectionTimeout to 10 seconds + pds.setAbandonedConnectionTimeout(10); + pds.setTimeoutCheckInterval(5); + + show("Connection pool " + POOL_NAME + " configured"); + show("Max pool size: " + pds.getMaxPoolSize()); + + show("\nBorrow connections to reach max pool size."); + + for (int i = 0; i < MAX_POOL_SIZE; i++) { + conns[i] = pds.getConnection(); + } + + showPoolStatistics("After all connections are borrowed", pds); + + Timer tm = new Timer(true); + + show("\nDo some work periodically only on 3 borrowed connections ..."); + + for (int i = 0; i < 3; i++) { + tm.schedule(new TestACTTimerTask(conns[i]), 1000, 1000); + } + + show("\nSleep for 15 seconds to trigger AbandonedConnectionTimeout."); + show("All borrowed connections other than the 3 are expected to be returned to pool."); + + try { + Thread.sleep(15000); + } catch (InterruptedException e) {} + + showPoolStatistics("\nAfter AbandonedConnectionTimeout", pds); + + // Cancel all timer tasks on the 3 borrowed connections + tm.cancel(); + + destroyConnectionPool(POOL_NAME); + + } catch (Throwable e) { + showError("demoAbandonedConnectionTimeout", e); + } + + show("\n*** Demo AbandonedConnectionTimeout completes ***"); + } + + // See sample UCPBasic.java for basic steps to set up a connection pool. + PoolDataSource createPoolDataSource(String poolName) throws Exception { + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS); + pds.setURL(url); + pds.setUser(user); + pds.setPassword(password); + pds.setConnectionPoolName(poolName); + + return pds; + } + + void destroyConnectionPool(String poolName) { + try { + UniversalConnectionPoolManagerImpl.getUniversalConnectionPoolManager() + .destroyConnectionPool(poolName); + show("\nConnection pool " + poolName + " destroyed"); + } catch (Throwable e) { + showError("destroyConnectinoPool", e); + } + } + + void showPoolStatistics(String prompt, PoolDataSource pds) + throws SQLException { + show(prompt + " -"); + show(" Available connections: " + pds.getAvailableConnectionsCount()); + show(" Borrowed connections: " + pds.getBorrowedConnectionsCount()); + } + + static void show(String msg) { + System.out.println(msg); + } + + static void showError(String msg, Throwable exc) { + System.out.println(msg + " hit error: " + exc.getMessage()); + } + + 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. + 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) { + char[] pchars = System.console().readPassword("\n[%s]", prompt); + if (pchars != null) { + password = new String(pchars); + java.util.Arrays.fill(pchars, ' '); + } + } else { + BufferedReader r = new BufferedReader(new InputStreamReader(System.in)); + show(prompt); + password = r.readLine(); + } + } + + // Used for AbandonedConnectionTimeout only + class TestACTTimerTask extends TimerTask { + Connection conn = null; + + public TestACTTimerTask(Connection con) { + conn = con; + } + + public void run() { + try (Statement statement = conn.createStatement()) { + statement.execute("select 1 from dual"); + } catch (Exception ucpException) {} + } + } +} + diff --git a/java/jdbc/BasicSamples/books.png b/java/jdbc/BasicSamples/books.png new file mode 100755 index 00000000..1db18441 Binary files /dev/null and b/java/jdbc/BasicSamples/books.png differ diff --git a/java/jdbc/ConnectionManagementSamples/DRCPSample.java b/java/jdbc/ConnectionSamples/DRCPSample.java similarity index 100% rename from java/jdbc/ConnectionManagementSamples/DRCPSample.java rename to java/jdbc/ConnectionSamples/DRCPSample.java diff --git a/java/jdbc/ConnectionSamples/DataSourceForJKS.java b/java/jdbc/ConnectionSamples/DataSourceForJKS.java new file mode 100644 index 00000000..b60c8e5d --- /dev/null +++ b/java/jdbc/ConnectionSamples/DataSourceForJKS.java @@ -0,0 +1,98 @@ +/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ +/* + DESCRIPTION + The code sample shows how to use the DataSource API to establish a + SSL connection to the Database using Java Key Store (JKS) files. + You can specify JKS related properties as connection properties. + Fully managed Oracle database services mandates SSL connection using JKS. + Note that an instance of oracle.jdbc.pool.OracleDataSource doesn't provide + any connection pooling. It's just a connection factory. A connection pool, + such as Universal Connection Pool (UCP), can be configured to use an + instance of oracle.jdbc.pool.OracleDataSource to create connections and + then cache them. + + Step 1: Enter the Database details in this file. + DB_USER, DB_PASSWORD and DB_URL are required + Step 2: Run the sample with "ant DataSourceForJKS" + + NOTES + Use JDK 1.7 and above + MODIFIED (MM/DD/YY) + nbsundar 02/17/15 - Creation + */ + +import java.io.IOException; +import java.io.InputStream; +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; +import java.util.Properties; + +import oracle.jdbc.pool.OracleDataSource; +import oracle.jdbc.OracleConnection; +import java.sql.DatabaseMetaData; + +public class DataSourceForJKS { + // Connection string has a "dbaccess" as TNS alias for the connection + // present in tnsnames.ora. Set the TNS_ADMIN property + // to point to the location of tnsnames.ora + final static String DB_URL= "jdbc:oracle:thin:@dbaccess"; + final static String DB_USER = "myuser"; + final static String DB_PASSWORD = "mypassword"; + + /* + * The method gets a database connection using + * oracle.jdbc.pool.OracleDataSource. It sets JKS related connection + * level properties as shown here. Refer to + * the OracleConnection interface to find more. + */ + public static void main(String args[]) throws SQLException { + Properties info = new Properties(); + info.put(OracleConnection.CONNECTION_PROPERTY_USER_NAME, DB_USER); + info.put(OracleConnection.CONNECTION_PROPERTY_PASSWORD, DB_PASSWORD); + // Set the SSL related connection properties + info.put(OracleConnection.CONNECTION_PROPERTY_THIN_SSL_SERVER_DN_MATCH,"true"); + info.put(OracleConnection.CONNECTION_PROPERTY_TNS_ADMIN,"/home/user/cloud"); + info.put(OracleConnection.CONNECTION_PROPERTY_THIN_SSL_VERSION,"1.2"); + // Set the JKS related connection properties + info.put(OracleConnection.CONNECTION_PROPERTY_THIN_JAVAX_NET_SSL_KEYSTORE, + "/home/user/cloud/keystore.jks"); + info.put(OracleConnection.CONNECTION_PROPERTY_THIN_JAVAX_NET_SSL_KEYSTOREPASSWORD,"Welcome1"); + info.put(OracleConnection.CONNECTION_PROPERTY_THIN_JAVAX_NET_SSL_TRUSTSTORE, + "/home/user/cloud/truststore.jks"); + info.put(OracleConnection.CONNECTION_PROPERTY_THIN_JAVAX_NET_SSL_TRUSTSTOREPASSWORD,"Welcome1"); + OracleDataSource ods = new OracleDataSource(); + ods.setURL(DB_URL); + ods.setConnectionProperties(info); + + // With AutoCloseable, the connection is closed automatically. + try (OracleConnection connection = (OracleConnection) ods.getConnection()) { + // Get the JDBC driver name and version + DatabaseMetaData dbmd = connection.getMetaData(); + System.out.println("Driver Name: " + dbmd.getDriverName()); + System.out.println("Driver Version: " + dbmd.getDriverVersion()); + // Print some connection properties + System.out.println("Default Row Prefetch Value is: " + + connection.getDefaultRowPrefetch()); + System.out.println("Database Username is: " + connection.getUserName()); + System.out.println(); + // Perform a database operation + printEmployees(connection); + } + } + /* + * Displays first_name and last_name from the employees table. + */ + public static void printEmployees(Connection connection) throws SQLException { + // Statement and ResultSet are AutoCloseable and closed automatically. + try (Statement statement = connection.createStatement()) { + try (ResultSet resultSet = statement + .executeQuery("select sysdate from dual")) { + while (resultSet.next()) + System.out.println("Today's date is " + resultSet.getString(1)); + + } + } + } +} diff --git a/java/jdbc/ConnectionManagementSamples/DataSourceSample.java b/java/jdbc/ConnectionSamples/DataSourceSample.java similarity index 100% rename from java/jdbc/ConnectionManagementSamples/DataSourceSample.java rename to java/jdbc/ConnectionSamples/DataSourceSample.java diff --git a/java/jdbc/ConnectionManagementSamples/InternalT2Driver.java b/java/jdbc/ConnectionSamples/InternalT2Driver.java similarity index 100% rename from java/jdbc/ConnectionManagementSamples/InternalT2Driver.java rename to java/jdbc/ConnectionSamples/InternalT2Driver.java diff --git a/java/jdbc/ConnectionManagementSamples/InternalT2Driver.sql b/java/jdbc/ConnectionSamples/InternalT2Driver.sql similarity index 100% rename from java/jdbc/ConnectionManagementSamples/InternalT2Driver.sql rename to java/jdbc/ConnectionSamples/InternalT2Driver.sql diff --git a/java/jdbc/ConnectionManagementSamples/InternalT4Driver.java b/java/jdbc/ConnectionSamples/InternalT4Driver.java similarity index 100% rename from java/jdbc/ConnectionManagementSamples/InternalT4Driver.java rename to java/jdbc/ConnectionSamples/InternalT4Driver.java diff --git a/java/jdbc/ConnectionManagementSamples/InternalT4Driver.sql b/java/jdbc/ConnectionSamples/InternalT4Driver.sql similarity index 100% rename from java/jdbc/ConnectionManagementSamples/InternalT4Driver.sql rename to java/jdbc/ConnectionSamples/InternalT4Driver.sql diff --git a/java/jdbc/ConnectionManagementSamples/ProxySessionSample.java b/java/jdbc/ConnectionSamples/ProxySessionSample.java similarity index 100% rename from java/jdbc/ConnectionManagementSamples/ProxySessionSample.java rename to java/jdbc/ConnectionSamples/ProxySessionSample.java diff --git a/java/jdbc/ConnectionManagementSamples/ProxySessionSample.sql b/java/jdbc/ConnectionSamples/ProxySessionSample.sql similarity index 100% rename from java/jdbc/ConnectionManagementSamples/ProxySessionSample.sql rename to java/jdbc/ConnectionSamples/ProxySessionSample.sql diff --git a/java/jdbc/ConnectionManagementSamples/Readme.md b/java/jdbc/ConnectionSamples/Readme.md similarity index 66% rename from java/jdbc/ConnectionManagementSamples/Readme.md rename to java/jdbc/ConnectionSamples/Readme.md index 87b69f77..d34682fe 100644 --- a/java/jdbc/ConnectionManagementSamples/Readme.md +++ b/java/jdbc/ConnectionSamples/Readme.md @@ -55,5 +55,28 @@ client side pool. Note that, when UCP is used, it takes care of attaching and releasing server connections. There is no need to explicitly call `attachServerConnection()`/`detachServerConnection()` with UCP. +## UCPSample.java: +Universal Connection Pool (UCP) is a client side connection pool. UCP +furnishes a rich set of features to support scalability in single database +instance as well as built-in features to support high-availability and +scalability in RAC and Active Data Guard environments. UCP along with RAC, +RAC One and ADG is a tested and certified combination for handling database +failovers. Refer to this sample for using UCP and setting UCP properties +such as `minPoolSize`, `maxPoolSize`, etc. + +## UCPWithDRCPSample.java: + +Database Resident Connection Pool (DRCP) is the server side connection pool. +DRCP should be used in a scenario when there are a number of middle tiers but +the number of active connections is fairly less than the number of open +connections. DRCP when used along with and Universal Connection Pool(UCP) as the client +side connection pool improves the performance. The sample shows UCP with DRCP +in action. The purpose of the client-side pooling mechanism is to maintain the +connections to Connection Broker. Client-side connection pools must attach and +detach connections to the connection broker through `attachServerConnection()` +and `detachServerConnection()`. DRCP should be used in a scenario when there are +a number of middle tiers but the number of active connections is fairly less +than th number of open connections. + ---- diff --git a/java/jdbc/ConnectionSamples/UCPSample.java b/java/jdbc/ConnectionSamples/UCPSample.java new file mode 100644 index 00000000..ff0a7f33 --- /dev/null +++ b/java/jdbc/ConnectionSamples/UCPSample.java @@ -0,0 +1,141 @@ +/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ + +/* + DESCRIPTION + The code sample demonstrates Universal Connection Pool (UCP) as a client + side connection pool and does the following. + (a)Set the connection factory class name to + oracle.jdbc.pool.OracleDataSource before getting a connection. + (b)Set the driver connection properties(e.g.,defaultNChar,includeSynonyms). + (c)Set the connection pool properties(e.g.,minPoolSize, maxPoolSize). + (d)Get the connection and perform some database operations. + + Step 1: Enter the Database details in DBConfig.properties file. + USER, PASSWORD, UCP_CONNFACTORY and URL are required. + Step 2: Run the sample with "ant UCPSample" + + NOTES + Use JDK 1.7 and above + + MODIFIED (MM/DD/YY) + nbsundar 02/13/15 - Creation (Contributor - tzhou) + */ +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; +import java.util.Properties; + +import oracle.ucp.jdbc.PoolDataSourceFactory; +import oracle.ucp.jdbc.PoolDataSource; + +public class UCPSample { + final static String DB_URL="jdbc:oracle:thin:@myhost:1521/orclservicename"; + final static String DB_USER = "hr"; + final static String DB_PASSWORD = "hr"; + final static String CONN_FACTORY_CLASS_NAME="oracle.jdbc.pool.OracleDataSource"; + + /* + * The sample demonstrates UCP as client side connection pool. + */ + public static void main(String args[]) throws Exception { + // Get the PoolDataSource for UCP + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + + // Set the connection factory first before all other properties + pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS_NAME); + pds.setURL(DB_URL); + pds.setUser(DB_USER); + pds.setPassword(DB_PASSWORD); + pds.setConnectionPoolName("JDBC_UCP_POOL"); + + // Default is 0. Set the initial number of connections to be created + // when UCP is started. + pds.setInitialPoolSize(5); + + // Default is 0. Set the minimum number of connections + // that is maintained by UCP at runtime. + pds.setMinPoolSize(5); + + // Default is Integer.MAX_VALUE (2147483647). Set the maximum number of + // connections allowed on the connection pool. + pds.setMaxPoolSize(20); + + // Default is 30secs. Set the frequency ineconds to enforce the timeout + // properties. Applies to inactiveConnectionTimeout(int secs), + // AbandonedConnectionTimeout(secs)& TimeToLiveConnectionTimeout(int secs). + // Range of valid values is 0 to Integer.MAX_VALUE. . + pds.setTimeoutCheckInterval(5); + + // Default is 0. Set the maximum time, in seconds, that a + // connection remains available in the connection pool. + pds.setInactiveConnectionTimeout(10); + + // Get the database connection from UCP. + try (Connection conn = pds.getConnection()) { + System.out.println("Available connections after checkout: " + + pds.getAvailableConnectionsCount()); + System.out.println("Borrowed connections after checkout: " + + pds.getBorrowedConnectionsCount()); + // Perform a database operation + doSQLWork(conn); + } + catch (SQLException e) { + System.out.println("UCPSample - " + "SQLException occurred : " + + e.getMessage()); + } + System.out.println("Available connections after checkin: " + + pds.getAvailableConnectionsCount()); + System.out.println("Borrowed connections after checkin: " + + pds.getBorrowedConnectionsCount()); + } + + /* + * Creates an EMP table and does an insert, update and select operations on + * the new table created. + */ + public static void doSQLWork(Connection conn) { + try { + conn.setAutoCommit(false); + // Prepare a statement to execute the SQL Queries. + Statement statement = conn.createStatement(); + // Create table EMP + statement.executeUpdate("create table EMP(EMPLOYEEID NUMBER," + + "EMPLOYEENAME VARCHAR2 (20))"); + System.out.println("New table EMP is created"); + // Insert some records into the table EMP + statement.executeUpdate("insert into EMP values(1, 'Jennifer Jones')"); + statement.executeUpdate("insert into EMP values(2, 'Alex Debouir')"); + System.out.println("Two records are inserted."); + + // Update a record on EMP table. + statement.executeUpdate("update EMP set EMPLOYEENAME='Alex Deborie'" + + " where EMPLOYEEID=2"); + System.out.println("One record is updated."); + + // Verify the table EMP + ResultSet resultSet = statement.executeQuery("select * from EMP"); + System.out.println("\nNew table EMP contains:"); + System.out.println("EMPLOYEEID" + " " + "EMPLOYEENAME"); + System.out.println("--------------------------"); + while (resultSet.next()) { + System.out.println(resultSet.getInt(1) + " " + resultSet.getString(2)); + } + System.out.println("\nSuccessfully tested a connection from UCP"); + } + catch (SQLException e) { + System.out.println("UCPSample - " + + "doSQLWork()- SQLException occurred : " + e.getMessage()); + } + finally { + // Clean-up after everything + try (Statement statement = conn.createStatement()) { + statement.execute("drop table EMP"); + } + catch (SQLException e) { + System.out.println("UCPSample - " + + "doSQLWork()- SQLException occurred : " + e.getMessage()); + } + } + } +} diff --git a/java/ucp/ConnectionManagementSamples/UCPWithDRCPSample.java b/java/jdbc/ConnectionSamples/UCPWithDRCPSample.java similarity index 100% rename from java/ucp/ConnectionManagementSamples/UCPWithDRCPSample.java rename to java/jdbc/ConnectionSamples/UCPWithDRCPSample.java diff --git a/java/jdbc/ConnectionManagementSamples/build.xml b/java/jdbc/ConnectionSamples/build.xml similarity index 100% rename from java/jdbc/ConnectionManagementSamples/build.xml rename to java/jdbc/ConnectionSamples/build.xml diff --git a/java/ucp/ConnectionManagementSamples/Readme.md b/java/ucp/ConnectionManagementSamples/Readme.md deleted file mode 100644 index f0aee486..00000000 --- a/java/ucp/ConnectionManagementSamples/Readme.md +++ /dev/null @@ -1,77 +0,0 @@ -# Connection Management Samples in JDBC using UCP, Universal Connection Pool - -Brief descriptions of connection management related code samples. - -|Author | Date | -|-------|------| -|nirmala.sundarappa|06/14/16| - - -============================================================================== -Creating a connection is an expensive database operation which -involves several background operations such as network communication, reading -connection strings, authentication, transaction enlistment, foreground process -creation and memory allocation. Each of these processes contributes to the -amount of time and resources taken to create a connection object. Repeated -connection creation and destruction will significantly impact Java application -scalability. - -"Connection Management" code samples explain various ways of connecting to an -Oracle Database and explain use-cases to be considered while choosing the -connection management strategy. The section below provides more details on -specific connection management strategy. - -============================================================================ -## UCPSample.java: -Universal Connection Pool (UCP) is a client side connection pool. UCP -furnishes a rich set of features to support scalability in single database -instance as well as built-in features to support high-availability and -scalability in RAC and Active Data Guard environments. UCP along with RAC, -RAC One and ADG is a tested and certified combination for handling database -failovers. Refer to this sample for using UCP and setting UCP properties -such as `minPoolSize`, `maxPoolSize`, etc. - -## UCPWithTimeoutProperties.java: -UCP furnishes a set of TimeOut properties which can be used to tune -performance. The sample demonstrates using some of UCP's important Timeout -properties, such as `InactivityTimeout`, `AbandonedConnectionTimeout`, -`TimeToLiveTimeout`, and `connectionWaitTimeout`. Each one of the UCP timeout -property can be run independently. Refer to the sample for more details. - -## UCPWebSessionAffinitySample.java: -Web-Session Affinity is a scalability feature of UCP in RAC and Active Data -Guard environment which attempts to allocate connections from the same RAC -instance during the life of a Web application. UCP tries to do a best try -effort, but, there is no guarantee to get a connection to the same instance. -UCP Web-Session Affinity is used in applications which expect short lived -connections to any database instance. - -## UCPConnectionLabelingSample.java: -Connection Labelling allows applications to set custom states ("labels") -then retrieve connections based on these pre-set states thereby avoiding the -cost of resetting these states. The sample uses applyConnectionLabel() to -apply a connection label and retrieves a connection using getConnection(label) -by specifying the created label. - -## UCPConnectionHarvestingSample.java: -UCP's Connection Harvesting allows UCP to pro-actively reclaim borrowed -connections based on pool requirements at run-time, while still giving -applications control over which borrowed connections should not be reclaimed. -The sample uses registerConnectionHarvestingCallback to register a connection -harvesting callback. - -## UCPWithDRCPSample.java: -Database Resident Connection Pool (DRCP) is the server side connection pool. -DRCP should be used in a scenario when there are a number of middle tiers but -the number of active connections is fairly less than the number of open -connections. -DRCP when used along with and Universal Connection Pool(UCP) as the client -side connection pool improves the performance. The sample shows UCP with DRCP -in action. The purpose of the client-side pooling mechanism is to maintain the -connections to Connection Broker. Client-side connection pools must attach and -detach connections to the connection broker through `attachServerConnection()` -and `detachServerConnection()`. DRCP should be used in a scenario when there are -a number of middle tiers but the number of active connections is fairly less -than the number of open connections. - -============================================================================ diff --git a/java/ucp/ConnectionManagementSamples/UCPConnectionHarvestingSample.java b/java/ucp/ConnectionManagementSamples/UCPConnectionHarvestingSample.java deleted file mode 100644 index 0e20187f..00000000 --- a/java/ucp/ConnectionManagementSamples/UCPConnectionHarvestingSample.java +++ /dev/null @@ -1,304 +0,0 @@ -/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ -/* - DESCRIPTION - The Connection Harvesting feature ensures that the pool does not run out of - available connections by reclaiming borrowed connections on-demand. It is - useful when an application holds a connection from a pool for a long time - without releasing it. By setting the appropriate HarvestTriggerCount and - HarvestMaxCount, user instructs UCP to reclaim some or all of these - borrowed connections to ensure there are enough in the pool. - - Methods for connection harvesting include: - (1)setConnectionHarvestable(): on a per-connection basis, specifies whether - it is harvestable by the pool. The default is harvestable. - (2)setConnectionHarvestMaxCount(): Maximum number of connections that may be - harvested when harvesting occurs. - (3)setConnectionHarvestTriggerCount(): Specifies the available connection - threshold that triggers connection harvesting. - For example., if the harvest trigger count is set to 10, then harvesting is - triggered when the number of available connections in the pool drops to 10. - - Step 1: Enter the database details in this file. - DB_USER, DB_PASSWORD, DB_URL and CONN_FACTORY_CLASS_NAME are required - Step 2: Run the sample with "ant UCPConnectionHarvestingSample" - - NOTES - Use JDK 1.7 and above - - MODIFIED (MM/DD/YY) - nbsundar 03/09/15 - Creation (Contributor - tzhou) - */ -import java.sql.Connection; -import java.sql.ResultSet; -import java.sql.SQLException; -import java.sql.Statement; - -import oracle.ucp.ConnectionHarvestingCallback; -import oracle.ucp.jdbc.HarvestableConnection; -import oracle.ucp.jdbc.PoolDataSource; -import oracle.ucp.jdbc.PoolDataSourceFactory; - -public class UCPConnectionHarvestingSample { - final static String DB_URL= "jdbc:oracle:thin:@(DESCRIPTION=(ADDRESS=(HOST=myhost)(PORT=1521)(PROTOCOL=tcp))(CONNECT_DATA=(SERVICE_NAME=myorcldbservicename)))"; - final static String DB_USER = "hr"; - final static String DB_PASSWORD = "hr"; - final static String CONN_FACTORY_CLASS_NAME = "oracle.jdbc.pool.OracleDataSource"; - - /* - * The sample demonstrates UCP's Connection Harvesting feature. - *(1)Set the connection pool properties. - * PoolSize=10 connections, HarvestMaxCount=2 and HarvestTriggerCount=5 - *(2)Run the sample with connection Harvesting. - * (2.1) Get 4 connections from UCP and perform a database operation - * (2.2) Get a 5th connection which triggers harvesting - * (2.3) Notice that conns[0] and conns[1] are reclaimed as part of - * harvesting based on LRU (Least Recently Used) algorithm. - * (2.4) Notice that number of available conns=7 and borrowed conns=3 - *(3) Run the sample without connection harvesting. - * (3.1) Get 4 connections from UCP and perform a database operation - * (3.2) Mark conns[0] and conns[1] as non-harvestable - * (3.3) Get a 5th connection which triggers harvesting - * (3.4) Notice that conns[2] and conns[3] are reclaimed as part of - * harvesting and conns[0] and conns[1] are not harvested or released - * (3.5) Notice that number of available connections=7 and borrowed conns= 3 - */ - public static void main(String args[]) throws Exception { - UCPConnectionHarvestingSample sample = new UCPConnectionHarvestingSample(); - sample.run(); - } - - /* - * Shows the outcomes with and without HarvestableConnection. - */ - void run() throws Exception { - PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); - pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS_NAME); - pds.setUser(DB_USER); - pds.setPassword(DB_PASSWORD); - pds.setURL(DB_URL); - // Set UCP properties - pds.setConnectionPoolName("HarvestingSamplePool"); - pds.setInitialPoolSize(10); - pds.setMaxPoolSize(25); - - // Configure connection harvesting: - // Borrowed connections could be held for long thus causing connection pool - // to run out of available connections. Connection Harvesting helps in - // reclaiming borrowed connections thus ensuring at least some are - // always available. - pds.setConnectionHarvestTriggerCount(5); - pds.setConnectionHarvestMaxCount(2); - - // demonstrates HavestableConnection behaviour - runWithHarvestableConnection(pds); - // demonstrates Non-HarvestableConnection behaviour - runWithoutHarvestableConnection(pds); - } - - /* - * Displays how the harvestable connection works. - */ - void runWithHarvestableConnection(PoolDataSource pds) throws Exception { - System.out.println("## Run with Harvestable connections ##"); - System.out.println("Initial available connections: " - + pds.getAvailableConnectionsCount()); - - Connection[] conns = new Connection[5]; - TestConnectionHarvestingCallback[] cbks = new TestConnectionHarvestingCallback[10]; - - // First borrow 4 connections--conns[0] and conns[1] are least-recently used - for (int i = 0; i < 4; i++) { - conns[i] = pds.getConnection(); - cbks[i] = new TestConnectionHarvestingCallback(conns[i]); - // Registers a ConnectionHarvestingCallback with the this connection. - ((HarvestableConnection) conns[i]) - .registerConnectionHarvestingCallback(cbks[i]); - // Perform a database operation - doSQLWork(conns[i], 2); - } - - // Get another new connection to trigger harvesting - conns[4] = pds.getConnection(); - cbks[4] = new TestConnectionHarvestingCallback(conns[4]); - ((HarvestableConnection) conns[4]) - .registerConnectionHarvestingCallback(cbks[4]); - - System.out.println("Requested 5 connections ..."); - - System.out.println("Available connections: " - + pds.getAvailableConnectionsCount()); - System.out.println("Borrowed connections: " - + pds.getBorrowedConnectionsCount()); - System.out.println("Waiting for 30 secs to trigger harvesting"); - // Harvesting should happen - Thread.sleep(30000); - - // conns[0] and conns[1]'s physical connections should be "harvested" - // by the pool and these two logical connections should be closed - System.out.println("Checking on the five connections ..."); - System.out.println(" conns[0] should be closed --" + conns[0].isClosed()); - System.out.println(" conns[1] should be closed --" + conns[1].isClosed()); - System.out.println(" conns[2] should be open --" + !conns[2].isClosed()); - System.out.println(" conns[3] should be open --" + !conns[3].isClosed()); - System.out.println(" conns[4] should be open --" + !conns[4].isClosed()); - - System.out.println("Checking on the pool ..."); - System.out.println(" Available connections should be 7: " - + (pds.getAvailableConnectionsCount() == 7)); - System.out.println(" Borrowed connections should be 3: " - + (pds.getBorrowedConnectionsCount() == 3)); - - for (int i = 2; i < 5; i++) - conns[i].close(); - } - - /* - * The method displays first_name and last_name from employees table - */ - void runWithoutHarvestableConnection(PoolDataSource pds) throws Exception { - System.out.println("## Run without harvestable connections ##"); - System.out.println("Initial available connections: " - + pds.getAvailableConnectionsCount()); - - Connection[] conns = new Connection[5]; - TestConnectionHarvestingCallback[] cbks = new TestConnectionHarvestingCallback[10]; - - // First borrow 4 connections -- conns[0] and conns[1] are least-recently - // used - for (int i = 0; i < 4; i++) { - conns[i] = pds.getConnection(); - cbks[i] = new TestConnectionHarvestingCallback(conns[i]); - // Registers a ConnectionHarvestingCallback with the this connection. - ((HarvestableConnection) conns[i]) - .registerConnectionHarvestingCallback(cbks[i]); - // Perform a database operation - doSQLWork(conns[i], 2); - } - - // Assuming the application is doing critical work on conns[0] and conns[1] - // and doesn't want these 2 to be "harvested" automatically. - // Mark conns[0] and conns[1] as non-harvestable connections. - ((HarvestableConnection) conns[0]).setConnectionHarvestable(false); - ((HarvestableConnection) conns[1]).setConnectionHarvestable(false); - - // Get another connection to trigger harvesting - conns[4] = pds.getConnection(); - cbks[4] = new TestConnectionHarvestingCallback(conns[4]); - ((HarvestableConnection) conns[4]) - .registerConnectionHarvestingCallback(cbks[4]); - - System.out.println("Requested 5 connections ..."); - - System.out.println("Available connections: " - + pds.getAvailableConnectionsCount()); - System.out.println("Borrowed connections: " - + pds.getBorrowedConnectionsCount()); - - System.out.println("Waiting for 30 secs to trigger harvesting"); - // Harvesting should happen - Thread.sleep(30000); - - // conns[2] and conns[3]'s physical connections should be "harvested" - // by the pool and these two logical connections should be closed. - // conns[0] and conns[1]'s physical connections will not be "harvested". - System.out.println("Checking on the five connections ..."); - System.out.println(" conns[0] should be open --" + !conns[0].isClosed()); - System.out.println(" conns[1] should be open --" + !conns[1].isClosed()); - System.out.println(" conns[2] should be closed --" + conns[2].isClosed()); - System.out.println(" conns[3] should be closed --" + conns[3].isClosed()); - System.out.println(" conns[4] should be open --" + !conns[4].isClosed()); - - System.out.println("Checking on the pool ..."); - System.out.println(" Available connections should be 7: " - + (pds.getAvailableConnectionsCount() == 7)); - System.out.println(" Borrowed connections should be 3: " - + (pds.getBorrowedConnectionsCount() == 3)); - - conns[0].close(); - conns[1].close(); - conns[4].close(); - } - - /* - * Creates a EMP_TEST table and perform an insert, update and select database - * operations on the new table created. - */ - public static void doSQLWork(Connection conn, int loopstoRun) { - for (int i = 0; i < loopstoRun; i++) { - try { - conn.setAutoCommit(false); - // Prepare a statement to execute the SQL Queries. - Statement statement = conn.createStatement(); - - // Create table EMP_TEST - statement.executeUpdate("create table EMP_TEST(EMPLOYEEID NUMBER," - + "EMPLOYEENAME VARCHAR2 (20))"); - // Insert some records into table EMP_TEST - statement - .executeUpdate("insert into EMP_TEST values(1, 'Jennifer Jones')"); - statement - .executeUpdate("insert into EMP_TEST values(2, 'Alex Debouir')"); - - // update a record on EMP_TEST table. - statement - .executeUpdate("update EMP_TEST set EMPLOYEENAME='Alex Deborie'" - + " where EMPLOYEEID=2"); - // verify table EMP_TEST - ResultSet resultSet = statement.executeQuery("select * from EMP_TEST"); - while (resultSet.next()) { - // System.out.println(resultSet.getInt(1) + " " - // + resultSet.getString(2)); - } - // Close ResultSet and Statement - resultSet.close(); - statement.close(); - - resultSet = null; - statement = null; - } - catch (SQLException e) { - System.out.println("UCPConnectionHarvestingSample - " - + "doSQLWork()-SQLException occurred : " + e.getMessage()); - } - finally { - // Clean-up after everything - try (Statement statement = conn.createStatement()) { - statement.execute("drop table EMP_TEST"); - } - catch (SQLException e) { - System.out.println("UCPConnectionHarvestingSample - " - + "doSQLWork()- SQLException occurred : " + e.getMessage()); - } - } - } - } - - /* - * Sample connection harvesting callback implementation is shown here. Refer - * to ConnectionHarvestingCallback in UCP Javadoc for more details. - * (http://docs.oracle.com/database/121/JJUAR/toc.htm) - */ - class TestConnectionHarvestingCallback implements - ConnectionHarvestingCallback { - private Object objForCleanup = null; - - public TestConnectionHarvestingCallback(Object objForCleanup) { - this.objForCleanup = objForCleanup; - } - - public boolean cleanup() { - try { - doCleanup(objForCleanup); - } - catch (Exception exc) { - return false; - } - - return true; - } - - private void doCleanup(Object obj) throws Exception { - ((Connection) obj).close(); - } - } -} diff --git a/java/ucp/ConnectionManagementSamples/UCPConnectionLabelingSample.java b/java/ucp/ConnectionManagementSamples/UCPConnectionLabelingSample.java deleted file mode 100644 index 18cd5e98..00000000 --- a/java/ucp/ConnectionManagementSamples/UCPConnectionLabelingSample.java +++ /dev/null @@ -1,259 +0,0 @@ -/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ - -/* - DESCRIPTION - Connection Labeling is used when an application wants to request a - particular connection with the desired label from the connection pool. - - Connection Labeling enables an application to associate custom labels - to a connection. By associating labels with a connection, an application - can search and retrieve an already initialized connection from the pool - and avoid the time and cost of connection re-initialization. Connection - labeling also makes it faster to find/retrieve connections - with specific properties (specified through labels). - - Connection labeling is application-driven and requires two interfaces. - (a) oracle.ucp.jdbc.LabelableConnection: It is used to retrieve, apply - and remove connection labels. - (b) oracle.ucp.ConnectionLabelingCallback: used to create a labeling - callback that determines if a connection with a requested label - already exists. Refer to ConnectionLabelingCallback in UCP Javadoc - (http://docs.oracle.com/database/121/JJUAR/toc.htm) - - Step 1: Enter the database details in this file. - DB_USER, DB_PASSWORD, DB_URL and CONN_FACTORY_CLASS_NAME are required - Step 2: Run the sample with "ant UCPConnectionLabelingSample" - - NOTES - Use JDK 1.7 and above - - MODIFIED (MM/DD/YY) - nbsundar 12/15/15 - . - nbsundar 11/24/15 - update - nbsundar 03/09/15 - Creation (tzhou - Contributor) - */ -import java.sql.Connection; -import java.sql.ResultSet; -import java.sql.SQLException; -import java.sql.Statement; -import java.util.Map; -import java.util.Set; -import java.util.Properties; - -import oracle.ucp.ConnectionLabelingCallback; -import oracle.ucp.jdbc.LabelableConnection; -import oracle.ucp.jdbc.PoolDataSource; -import oracle.ucp.jdbc.PoolDataSourceFactory; - -public class UCPConnectionLabelingSample { - final static String DB_URL= "jdbc:oracle:thin:@(DESCRIPTION=(ADDRESS=(HOST=myhost)(PORT=1521)(PROTOCOL=tcp))(CONNECT_DATA=(SERVICE_NAME=myorcldbservicename)))"; - final static String DB_USER = "hr"; - final static String DB_PASSWORD = "hr"; - final static String CONN_FACTORY_CLASS_NAME = "oracle.jdbc.pool.OracleDataSource"; - - /* The sample demonstrates UCP's Connection Labeling feature. - *(1) Set up the connection pool: - * Initialize the pool with 2 connections (InitialPoolSize = 2) and - * register a labeling callback (TestConnectionLabelingCallback). - *(2) Run the sample for connection Labeling: - * (2.1) Get the 1st connection from UCP and label the connection - * (2.2) Request 2nd connection with the same label - * (2.3) Notice that the cost() method in TestConnectionLabelingCallback - * gets invoked on connections in the pool. The cost() method projects - * the cost of configuring connections considering label-matching - * differences. The pool uses this method to select a connection - * with the least reconfiguration cost. - * (2.4) If the pool finds a connection with cost 0, it returns the - * connection without calling configure(); for any connection with - * above-zero cost, the pool invokes configure() in the labeling - * callback, and then returns the connection to application. - * (2.5) The purpose of the configure() method is to bring the - * connection to the desired state, which could include both - * client-side and server-side actions. The method should also - * apply or remove labels from the connection. - */ - public static void main(String args[]) throws Exception { - UCPConnectionLabelingSample sample = new UCPConnectionLabelingSample(); - // Demonstrates Connection Labeling - sample.run(); - } - /* - * Shows UCP's Connection labeling feature. - */ - void run() throws Exception { - PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); - - pds.setConnectionFactoryClassName(CONN_FACTORY_CLASS_NAME); - pds.setUser(DB_USER); - pds.setPassword(DB_PASSWORD); - pds.setURL(DB_URL); - // Set UCP properties - pds.setConnectionPoolName("LabelingSamplePool"); - pds.setInitialPoolSize(2); - - // Register connection labeling callback - TestConnectionLabelingCallback cbk = new TestConnectionLabelingCallback(); - // Registers a connection labeling callback with the connection pool - pds.registerConnectionLabelingCallback(cbk); - - System.out.println("Initial available connection number: " - + pds.getAvailableConnectionsCount()); - - // Fresh connection from pool - System.out.println("Requesting a regular connection from pool ..."); - Connection conn1 = pds.getConnection(); - System.out.println("Available connection number: " - + pds.getAvailableConnectionsCount()); - - // Change the transaction isolation level of the conn1 to - // java.sql.Connection.TRANSACTION_SERIALIZABLE - conn1.setTransactionIsolation(Connection.TRANSACTION_SERIALIZABLE); - doSQLWork(conn1, 5); - - // Now apply a connection label to this connection - ((LabelableConnection) conn1).applyConnectionLabel("TRANSACTION_ISOLATION", - "8"); - - // Done with this connection for now, return it to pool - System.out.println("Returning labeled connection to pool ..."); - conn1.close(); - System.out.println("Available connection number: " - + pds.getAvailableConnectionsCount()); - - Thread.sleep(10000); - - // The application wants to use connection again - - // Preferred connection label - Properties label = new Properties(); - label.setProperty("TRANSACTION_ISOLATION", "8"); - - // Request connection with the preferred label - System.out.println("Requesting connection with preferred label ..."); - Connection conn2 = pds.getConnection(label); - System.out.println("Available connection number: " - + pds.getAvailableConnectionsCount()); - - System.out.println("Again returning labelled connection to pool ..."); - conn2.close(); - System.out.println("Available connection number: " - + pds.getAvailableConnectionsCount()); - } - - /* - * The method shows database operations. - * It creates a EMP_LIST table and will do an insert, update and select - * on the new table created. - */ - public static void doSQLWork(Connection conn, int loopstoRun) { - for (int i = 0; i < loopstoRun; i++) { - try { - conn.setAutoCommit(false); - // Prepare a statement to execute the SQL Queries. - Statement statement = conn.createStatement(); - - // Create table EMP_LIST - statement.executeUpdate("create table EMP_LIST(EMPLOYEEID NUMBER," - + "EMPLOYEENAME VARCHAR2 (20))"); - // Insert few records into table EMP_LIST - statement.executeUpdate("insert into EMP_LIST values(1, 'Jennifer Jones')"); - statement.executeUpdate("insert into EMP_LIST values(2, 'Alex Debouir')"); - - // Update a record on EMP_LIST table. - statement.executeUpdate("\n update EMP_LIST set EMPLOYEENAME='Alex Deborie'" - + " where EMPLOYEEID=2"); - - // Verify the contents of table EMP_LIST - ResultSet resultSet = statement.executeQuery("select * from EMP_LIST"); - while (resultSet.next()) { - // System.out.println(resultSet.getInt(1) + " " + resultSet.getString(2)); - } - // Close ResultSet and Statement - resultSet.close(); - statement.close(); - - resultSet = null; - statement = null; - } - catch (SQLException e) { - System.out.println("UCPConnectionLabelingSample - " - + "doSQLWork()-SQLException occurred : " + e.getMessage()); - } - finally { - // Clean-up after everything - try (Statement statement = conn.createStatement()) { - statement.execute("drop table EMP_LIST"); - } - catch (SQLException e) { - System.out.println("UCPConnectionLabelingSample - " - + "doSQLWork()- SQLException occurred : " + e.getMessage()); - } - } - } - } -} - -/* - * Sample labeling callback implementation. - */ -class TestConnectionLabelingCallback implements ConnectionLabelingCallback { - public TestConnectionLabelingCallback() { - } - /* - * Projects the cost of configuring connections considering - * label-matching differences. - */ - public int cost(Properties reqLabels, Properties currentLabels) { - // Case 1: exact match - if (reqLabels.equals(currentLabels)) { - System.out.println("## Exact match found!! ##"); - return 0; - } - - // Case 2: Partial match where some labels match with current labels - String iso1 = (String) reqLabels.get("TRANSACTION_ISOLATION"); - String iso2 = (String) currentLabels.get("TRANSACTION_ISOLATION"); - boolean match = (iso1 != null && iso2 != null && iso1 - .equalsIgnoreCase(iso2)); - Set rKeys = reqLabels.keySet(); - Set cKeys = currentLabels.keySet(); - if (match && rKeys.containsAll(cKeys)) { - System.out.println("## Partial match found!! ##"); - return 10; - } - // Case 3: No match - // Do not choose this connection. - System.out.println("## No match found!! ##"); - return Integer.MAX_VALUE; - } - - /* - * Configures the selected connection for a borrowing request before - * returning the connection to the application. - */ - public boolean configure(Properties reqLabels, Object conn) { - try { - String isoStr = (String) reqLabels.get("TRANSACTION_ISOLATION"); - ((Connection) conn).setTransactionIsolation(Integer.valueOf(isoStr)); - - LabelableConnection lconn = (LabelableConnection) conn; - - // Find the unmatched labels on this connection - Properties unmatchedLabels = lconn - .getUnmatchedConnectionLabels(reqLabels); - - // Apply each label in unmatchedLabels to connection - for (Map.Entry label : unmatchedLabels.entrySet()) { - String key = (String) label.getKey(); - String value = (String) label.getValue(); - lconn.applyConnectionLabel(key, value); - } - } - catch (Exception exc) { - return false; - } - return true; - } -} - - diff --git a/java/ucp/ConnectionManagementSamples/build.xml b/java/ucp/ConnectionManagementSamples/build.xml deleted file mode 100644 index 2ddeac03..00000000 --- a/java/ucp/ConnectionManagementSamples/build.xml +++ /dev/null @@ -1,133 +0,0 @@ - - - - - - Build and run Oracle Jdbc Samples - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - Connection Management Samples: Commands to Run - ============================================== - (1) ant UCPSample - (2) ant UCPInactiveConnectionTimeout - (3) ant UCPConnectionWaitTimeout - (4) ant UCPAbandonedConnectionTimeout - (5) ant UCPAbandonedConnectionTimeout - (6) ant UCPTimeToLiveConnectionTimeout - (7) ant UCPConnectionHarvestingSample - (8) ant UCPConnectionLabelingSample - (9) ant UCPWebSessionAffinitySample - (10) ant UCPWithDRCPSample - ============================================== - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - diff --git a/java/ucp/Readme.md b/java/ucp/Readme.md deleted file mode 100644 index 3c8c44a7..00000000 --- a/java/ucp/Readme.md +++ /dev/null @@ -1,48 +0,0 @@ -# Universal Connection Pool (UCP) -The Oracle Universal Connection Pool (UCP) is a feature rich Java connection pool tightly integrated with all Oracle database configurations and architectures, providing high availability, scalability and load balancing for Java applications. -To use UCP, Java applications or containers must have **ucp.jar** in their class path along with **ojdbc8.jar** (for JDK or JRE 8). - -## What's new in 12.2 ? - -* **New Java Standards**: Support for Java SE 8 and JDBC 4.2 -* **New Performance features**: UCP redesign for faster pool operations using Wait-Free technique, Multi-dimensionnal KD-Tree - search, and configurable connection health check frequency -* **New Scalability features**: Shared Pool for Multitenant Database, Shared Pool for Sharded database, Sharding APIs -* **New High Availability features**: Fast Application Notification (FAN) and Oracle Notification Services (ONS) are auto-enabled, - Application Continuity for XA Datasources, and Transaction Guard for XA Datasource -* **New Manageability features**: XML configuration file - -## Downloads - -[Oracle Database 12.2.0.1 UCP Download Page](http://www.oracle.com/technetwork/database/features/jdbc/jdbc-ucp-122-3110062.html) - -## Javadoc - -[12.2 Online UCP Javadoc](http://docs.oracle.com/database/122/JJUAR/toc.htm) - -## Documentation - -[12.2 UCP Developer's Guide](https://docs.oracle.com/database/122/JJUCP/toc.htm) - -## White Papers - -* [Performance, Scalability, Availability, Security, and Manageability with JDBC and UCP in 12.2](http://www.oracle.com/technetwork/database/application-development/jdbc/jdbcanducp122-3628966.pdf) - -* [Connection Management Strategies for Java Applications using JDBC and UCP](http://www.oracle.com/technetwork/database/application-development/jdbc-ucp-conn-mgmt-strategies-3045654.pdf) - -* [What's in Oracle database 12c Release 2 for Java & JavaScript Developers?](http://bit.ly/2orH5jf) - -## Other Resources - -* [UCP and Oracle Database Service on Cloud](http://www.oracle.com/technetwork/database/application-development/jdbc/documentation/index.html) - -* [UCP Landing Page and Other UCP Whitepapers](http://www.oracle.com/technetwork/database/application-development/jdbc/overview/index.html) - -* [Oracle JDBC & UCP Forum](https://community.oracle.com/community/java/database_connectivity/java_database_connectivity/) - - - - - - - diff --git a/javascript/node-oracledb/README.md b/javascript/node-oracledb/README.md index 634b4fd8..d4274066 100644 --- a/javascript/node-oracledb/README.md +++ b/javascript/node-oracledb/README.md @@ -1,16 +1,16 @@ # Node-oracledb Examples -This directory contains [node-oracledb 2.0](https://www.npmjs.com/package/oracledb) examples. +This directory contains [node-oracledb 2.3](https://www.npmjs.com/package/oracledb) examples. The node-oracledb add-on for Node.js powers high performance Oracle Database applications. -[Node-oracledb documentation](https://github.com/oracle/node-oracledb/blob/master/doc/api.md) +[Node-oracledb documentation](https://oracle.github.io/node-oracledb/doc/api.html) [Issues and questions](https://github.com/oracle/node-oracledb/issues) To run the examples: -- [Install node-oracledb](https://github.com/oracle/node-oracledb/blob/master/INSTALL.md). +- [Install node-oracledb](https://oracle.github.io/node-oracledb/INSTALL.html). - Use `demo.sql` to create schema objects used by the samples. For diff --git a/javascript/node-oracledb/blobhttp.js b/javascript/node-oracledb/blobhttp.js index 4205a224..aba442b9 100644 --- a/javascript/node-oracledb/blobhttp.js +++ b/javascript/node-oracledb/blobhttp.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -74,8 +74,7 @@ function handleRequest(request, response) { if (action == '/getimage') { oracledb.getConnection( // gets a connection from the 'default' connection pool - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; @@ -84,8 +83,7 @@ function handleRequest(request, response) { connection.execute( "SELECT b FROM mylobs WHERE id = :id", // get the image { id: 2 }, - function(err, result) - { + function(err, result) { if (err) { console.error(err.message); return; @@ -104,15 +102,13 @@ function handleRequest(request, response) { lob.on( 'end', - function() - { + function() { console.log("lob.on 'end' event"); response.end(); }); lob.on( 'close', - function() - { + function() { console.log("lob.on 'close' event"); connection.close(function(err) { if (err) console.error(err); @@ -120,8 +116,7 @@ function handleRequest(request, response) { }); lob.on( 'error', - function(err) - { + function(err) { console.log("lob.on 'error' event"); console.error(err); connection.close(function(err) { diff --git a/javascript/node-oracledb/clobexample.txt b/javascript/node-oracledb/clobexample.txt index 504cc45d..95519f99 100644 --- a/javascript/node-oracledb/clobexample.txt +++ b/javascript/node-oracledb/clobexample.txt @@ -2,4 +2,4 @@ This is example text used for node-oracledb CLOB examples. The Oracle Database Node.js driver powers high performance Node.js applications. -The node-oracledb home page is at http://www.oracle.com/technetwork/database/database-technologies/scripting-languages/node_js/ +The node-oracledb home page is at http://oracle.github.io/node-oracledb/ diff --git a/javascript/node-oracledb/connect.js b/javascript/node-oracledb/connect.js index 6c58b5ee..a1afd51b 100644 --- a/javascript/node-oracledb/connect.js +++ b/javascript/node-oracledb/connect.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -33,8 +33,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; @@ -42,8 +41,7 @@ oracledb.getConnection( console.log('Connection was successful!'); connection.close( - function(err) - { + function(err) { if (err) { console.error(err.message); return; diff --git a/javascript/node-oracledb/cqn1.js b/javascript/node-oracledb/cqn1.js new file mode 100644 index 00000000..6beffd5a --- /dev/null +++ b/javascript/node-oracledb/cqn1.js @@ -0,0 +1,119 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * cqn1.js + * + * DESCRIPTION + * Shows query-level Continuous Query Notification, allowing a + * method to be invoked when a data set changes. + * + * The user must have been granted CHANGE NOTIFICATION. + * The node-oracledb host must be resolvable by the database host. + * + * This example uses Node 8 syntax, but could be written to use callbacks. + * + *****************************************************************************/ + +const oracledb = require("oracledb"); +let dbConfig = require('./dbconfig.js'); + +dbConfig.events = true; // CQN needs events mode + +let interval = setInterval(function() { + console.log("waiting..."); +}, 5000); + +function myCallback(message) +{ + // message.type is one of the oracledb.SUBSCR_EVENT_TYPE_* values + console.log("Message type:", message.type); + if (message.type == oracledb.SUBSCR_EVENT_TYPE_DEREG) { + clearInterval(interval); + console.log("Deregistration has taken place..."); + return; + } + console.log("Message database name:", message.dbName); + console.log("Message transaction id:", message.txId); + console.log("Message queries:"); + for (let i = 0; i < message.queries.length; i++) { + let query = message.queries[i]; + for (let j = 0; j < query.tables.length; j++) { + let table = query.tables[j]; + console.log("--> --> Table Name:", table.name); + // Note table.operation and row.operation are masks of + // oracledb.CQN_OPCODE_* values + console.log("--> --> Table Operation:", table.operation); + if (table.rows) { + console.log("--> --> Table Rows:"); + for (let k = 0; k < table.rows.length; k++) { + let row = table.rows[k]; + console.log("--> --> --> Row Rowid:", row.rowid); + console.log("--> --> --> Row Operation:", row.operation); + console.log(Array(61).join("-")); + } + } + } + console.log(Array(61).join("=")); + } +} + +const options = { + callback : myCallback, + sql: "SELECT * FROM cqntable WHERE k > :bv", + binds: { bv : 100 }, + timeout : 60, // Stop after 60 seconds + // SUBSCR_QOS_QUERY: generate notifications when rows with k > 100 are changed + // SUBSCR_QOS_ROWIDS: Return ROWIDs in the notification message + qos : oracledb.SUBSCR_QOS_QUERY | oracledb.SUBSCR_QOS_ROWIDS +}; + +async function runTest() { + let conn; + + try { + conn = await oracledb.getConnection(dbConfig); + + await conn.subscribe('mysub', options); + + console.log("Subscription created..."); + + } catch (err) { + console.error(err); + clearInterval(interval); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +process + .on('SIGTERM', function() { + console.log("\nTerminating"); + process.exit(0); + }) + .on('SIGINT', function() { + console.log("\nTerminating"); + process.exit(0); + }); + +runTest(); diff --git a/javascript/node-oracledb/cqn2.js b/javascript/node-oracledb/cqn2.js new file mode 100644 index 00000000..cd49b2bb --- /dev/null +++ b/javascript/node-oracledb/cqn2.js @@ -0,0 +1,119 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * cqn2.js + * + * DESCRIPTION + * Shows object-level Continuous Query Notification (formerly known + * as Database Change Notification), allowing a method to be invoked + * when an object changes. Notification are grouped into intervals. + * + * The user must have been granted CHANGE NOTIFICATION. + * The node-oracledb host must be resolvable by the database host. + * + * This example uses Node 8 syntax, but could be written to use callbacks. + * + *****************************************************************************/ + +const oracledb = require("oracledb"); +let dbConfig = require('./dbconfig.js'); + +dbConfig.events = true; // CQN needs events mode + +let interval = setInterval(function() { + console.log("waiting..."); +}, 5000); + +function myCallback(message) +{ + // message.type is one of the oracledb.SUBSCR_EVENT_TYPE_* values + console.log("Message type:", message.type); + if (message.type == oracledb.SUBSCR_EVENT_TYPE_DEREG) { + clearInterval(interval); + console.log("Deregistration has taken place..."); + return; + } + console.log("Message database name:", message.dbName); + console.log("Message transaction id:", message.txId); + for (let i = 0; i < message.tables.length; i++) { + let table = message.tables[i]; + console.log("--> Table Name:", table.name); + // Note table.operation and row.operation are masks of + // oracledb.CQN_OPCODE_* values + console.log("--> Table Operation:", table.operation); + if (table.rows) { + for (let j = 0; j < table.rows.length; j++) { + let row = table.rows[j]; + console.log("--> --> Row Rowid:", row.rowid); + console.log("--> --> Row Operation:", row.operation); + console.log(Array(61).join("-")); + } + } + console.log(Array(61).join("=")); + } +} + +const options = { + callback : myCallback, + sql: "SELECT * FROM cqntable", + // Stop after 60 seconds + timeout : 60, + // Return ROWIDs in the notification message + qos : oracledb.SUBSCR_QOS_ROWIDS, + // Group notifications in batches covering 10 second + // intervals, and send a summary + groupingClass : oracledb.SUBSCR_GROUPING_CLASS_TIME, + groupingValue : 10, + groupingType : oracledb.SUBSCR_GROUPING_TYPE_SUMMARY +}; + +async function runTest() { + let conn; + + try { + conn = await oracledb.getConnection(dbConfig); + + await conn.subscribe('mysub', options); + + console.log("Subscription created..."); + + } catch (err) { + console.error(err); + clearInterval(interval); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +process + .on('SIGTERM', function() { + console.log("\nTerminating"); + process.exit(0); + }) + .on('SIGINT', function() { + console.log("\nTerminating"); + process.exit(0); + }); + +runTest(); diff --git a/javascript/node-oracledb/dbconfig.js b/javascript/node-oracledb/dbconfig.js index a1bc6f17..b3f155c9 100644 --- a/javascript/node-oracledb/dbconfig.js +++ b/javascript/node-oracledb/dbconfig.js @@ -23,6 +23,8 @@ * to the database. Production applications should consider using * External Authentication to avoid hard coded credentials. * + * To create a database user see https://www.youtube.com/watch?v=WDJacg0NuLo + * * Applications can set the connectString value to an Easy Connect * string, or a Net Service Name from a tnsnames.ora file or * external naming service, or it can be the name of a local Oracle @@ -75,10 +77,10 @@ module.exports = { password : process.env.NODE_ORACLEDB_PASSWORD || "welcome", // For information on connection strings see: - // https://github.com/oracle/node-oracledb/blob/master/doc/api.md#connectionstrings + // https://oracle.github.io/node-oracledb/doc/api.html#connectionstrings connectString : process.env.NODE_ORACLEDB_CONNECTIONSTRING || "localhost/orclpdb", // Setting externalAuth is optional. It defaults to false. See: - // https://github.com/oracle/node-oracledb/blob/master/doc/api.md#extauth + // https://oracle.github.io/node-oracledb/doc/api.html#extauth externalAuth : process.env.NODE_ORACLEDB_EXTERNALAUTH ? true : false }; diff --git a/javascript/node-oracledb/demo.sql b/javascript/node-oracledb/demo.sql index c454a47c..545de182 100644 --- a/javascript/node-oracledb/demo.sql +++ b/javascript/node-oracledb/demo.sql @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -19,7 +19,10 @@ * demo.sql * * DESCRIPTION - * Create database objects for the examples + * Create database objects for the examples in your database user account. + * + * The video https://www.youtube.com/watch?v=WDJacg0NuLo + * shows how to create a new database user. * * Scripts to create Oracle Database's traditional sample schemas can * be found at: https://github.com/oracle/db-sample-schemas @@ -127,7 +130,6 @@ BEGIN EXECUTE IMMEDIATE 'DROP TABLE dmlrupdtab'; EXCEPTION WHEN OTHERS THEN IF S CREATE TABLE dmlrupdtab (id NUMBER, name VARCHAR2(40)); INSERT INTO dmlrupdtab VALUES (1001, 'Venkat'); INSERT INTO dmlrupdtab VALUES (1002, 'Neeharika'); -COMMIT; -- For LOB examples BEGIN EXECUTE IMMEDIATE 'DROP TABLE mylobs'; EXCEPTION WHEN OTHERS THEN IF SQLCODE <> -942 THEN RAISE; END IF; END; @@ -183,3 +185,76 @@ SHOW ERRORS BEGIN EXECUTE IMMEDIATE 'DROP TABLE myraw'; EXCEPTION WHEN OTHERS THEN IF SQLCODE <> -942 THEN RAISE; END IF; END; / CREATE TABLE myraw (r RAW(64)); + +-- For the executemany*.js examples + +BEGIN EXECUTE IMMEDIATE 'DROP TABLE em_tab'; EXCEPTION WHEN OTHERS THEN IF SQLCODE <> -942 THEN RAISE; END IF; END; +/ +BEGIN EXECUTE IMMEDIATE 'DROP TABLE em_childtab'; EXCEPTION WHEN OTHERS THEN IF SQLCODE <> -942 THEN RAISE; END IF; END; +/ +BEGIN EXECUTE IMMEDIATE 'DROP TABLE em_parenttab'; EXCEPTION WHEN OTHERS THEN IF SQLCODE <> -942 THEN RAISE; END IF; END; +/ + +CREATE TABLE em_tab ( + id NUMBER NOT NULL, + val VARCHAR2(20) +); + +CREATE TABLE em_parenttab ( + parentid NUMBER NOT NULL, + description VARCHAR2(60) NOT NULL, + CONSTRAINT parenttab_pk PRIMARY KEY (parentid) +); + +CREATE TABLE em_childtab ( + childid NUMBER NOT NULL, + parentid NUMBER NOT NULL, + description VARCHAR2(30) NOT NULL, + CONSTRAINT em_childtab_pk PRIMARY KEY (childid), + CONSTRAINT em_childtab_fk FOREIGN KEY (parentid) REFERENCES em_parenttab +); + +INSERT INTO em_parenttab VALUES (10, 'Parent 10'); +INSERT INTO em_parenttab VALUES (20, 'Parent 20'); +INSERT INTO em_parenttab VALUES (30, 'Parent 30'); +INSERT INTO em_parenttab VALUES (40, 'Parent 40'); +INSERT INTO em_parenttab VALUES (50, 'Parent 50'); + +INSERT INTO em_childtab VALUES (1001, 10, 'Child 1001 of Parent 10'); +INSERT INTO em_childtab VALUES (1002, 20, 'Child 1002 of Parent 20'); +INSERT INTO em_childtab VALUES (1003, 20, 'Child 1003 of Parent 20'); +INSERT INTO em_childtab VALUES (1004, 20, 'Child 1004 of Parent 20'); +INSERT INTO em_childtab VALUES (1005, 30, 'Child 1005 of Parent 30'); +INSERT INTO em_childtab VALUES (1006, 30, 'Child 1006 of Parent 30'); +INSERT INTO em_childtab VALUES (1007, 40, 'Child 1007 of Parent 40'); +INSERT INTO em_childtab VALUES (1008, 40, 'Child 1008 of Parent 40'); +INSERT INTO em_childtab VALUES (1009, 40, 'Child 1009 of Parent 40'); +INSERT INTO em_childtab VALUES (1010, 40, 'Child 1010 of Parent 40'); +INSERT INTO em_childtab VALUES (1011, 40, 'Child 1011 of Parent 40'); +INSERT INTO em_childtab VALUES (1012, 50, 'Child 1012 of Parent 50'); +INSERT INTO em_childtab VALUES (1013, 50, 'Child 1013 of Parent 50'); +INSERT INTO em_childtab VALUES (1014, 50, 'Child 1014 of Parent 50'); +INSERT INTO em_childtab VALUES (1015, 50, 'Child 1015 of Parent 50'); + +CREATE OR REPLACE PROCEDURE em_testproc ( + a_num IN NUMBER, + a_outnum OUT NUMBER, + a_outstr OUT VARCHAR2) +AS +BEGIN + a_outnum := a_num * 2; + FOR i IN 1..a_num LOOP + a_outstr := a_outstr || 'X'; + END LOOP; +END; +/ + +COMMIT; + + +-- For the cqn*.js examples + +-- The DBA must grant access: +-- GRANT CHANGE NOTIFICATION TO myuser; + +create table cqntable (k number); diff --git a/javascript/node-oracledb/demodrop.sql b/javascript/node-oracledb/demodrop.sql index 68fea34e..16cbf5c0 100644 --- a/javascript/node-oracledb/demodrop.sql +++ b/javascript/node-oracledb/demodrop.sql @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -54,3 +54,13 @@ DROP PROCEDURE lob_in_out; DROP PROCEDURE lobs_in; DROP PROCEDURE lobs_out; + +DROP TABLE em_tab; + +DROP TABLE em_childtab; + +DROP TABLE em_parenttab; + +DROP PROCEDURE em_testproc; + +DROP TABLE cqntable; diff --git a/javascript/node-oracledb/dmlrupd1.js b/javascript/node-oracledb/dmlrupd1.js index 63ed2e9f..37c0a2d3 100644 --- a/javascript/node-oracledb/dmlrupd1.js +++ b/javascript/node-oracledb/dmlrupd1.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -42,10 +42,8 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { - if (err) - { + function(err, connection) { + if (err) { console.error(err); return; } @@ -58,10 +56,8 @@ oracledb.getConnection( rid: { type: oracledb.STRING, dir: oracledb.BIND_OUT } }, { autoCommit: true }, - function(err, result) - { - if (err) - { + function(err, result) { + if (err) { console.error(err); return; } diff --git a/javascript/node-oracledb/dmlrupd2.js b/javascript/node-oracledb/dmlrupd2.js index 167bbb69..28d775bd 100644 --- a/javascript/node-oracledb/dmlrupd2.js +++ b/javascript/node-oracledb/dmlrupd2.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -42,10 +42,8 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { - if (err) - { + function(err, connection) { + if (err) { console.error(err); return; } @@ -60,10 +58,8 @@ oracledb.getConnection( rids: { type: oracledb.STRING, dir: oracledb.BIND_OUT } }, { autoCommit: true }, - function(err, result) - { - if (err) - { + function(err, result) { + if (err) { console.error(err); return; } diff --git a/javascript/node-oracledb/em_batcherrors.js b/javascript/node-oracledb/em_batcherrors.js new file mode 100644 index 00000000..1a1ec150 --- /dev/null +++ b/javascript/node-oracledb/em_batcherrors.js @@ -0,0 +1,89 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_batcherrors.js + * + * DESCRIPTION + * Array DML example showing batchErrors behavior. Note, despite the + * autoCommit flag, no commit occurs because of data errors. However + * valid rows are part of a transaction that can be committed if + * desired. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var async = require('async'); +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +var doconnect = function(cb) { + oracledb.getConnection(dbConfig, cb); +}; + +var dorelease = function(conn) { + conn.close(function (err) { + if (err) + console.error(err.message); + }); +}; + +var doinsert = function(conn, cb) { + var sql = "INSERT INTO em_childtab VALUES (:1, :2, :3)"; + + var binds = [ + [1016, 10, "Child 2 of Parent A"], + [1017, 10, "Child 3 of Parent A"], + [1018, 20, "Child 4 of Parent B"], + [1018, 20, "Child 4 of Parent B"], // duplicate key + [1019, 30, "Child 3 of Parent C"], + [1020, 40, "Child 4 of Parent D"], + [1021, 75, "Child 1 of Parent F"], // parent does not exist + [1022, 40, "Child 6 of Parent D"] + ]; + + var options = { + autoCommit: true, + batchErrors: true, + dmlRowCounts: true, + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.NUMBER }, + { type: oracledb.STRING, maxSize: 20 } + ] + }; + + conn.executeMany(sql, binds, options, function (err, result) { + if (err) + return cb(err, conn); + else { + console.log("Result is:", result); + return cb(null, conn); + } + }); +}; + +async.waterfall( + [ + doconnect, + doinsert + ], + function (err, conn) { + if (err) { console.error("In waterfall error cb: ==>", err, "<=="); } + if (conn) + dorelease(conn); + }); diff --git a/javascript/node-oracledb/em_batcherrors_aa.js b/javascript/node-oracledb/em_batcherrors_aa.js new file mode 100644 index 00000000..168915e8 --- /dev/null +++ b/javascript/node-oracledb/em_batcherrors_aa.js @@ -0,0 +1,87 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_batcherrors_aa.js + * + * DESCRIPTION + * Array DML example showing batchErrors behavior. Note, despite the + * autoCommit flag, no commit occurs because of data errors. However + * valid rows are part of a transaction that can be committed if + * desired. + * This example also uses Async/Await of Node 8. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +const sql = "INSERT INTO em_childtab VALUES (:1, :2, :3)"; + +const binds = [ + [1016, 10, "Child 2 of Parent A"], + [1017, 10, "Child 3 of Parent A"], + [1018, 20, "Child 4 of Parent B"], + [1018, 20, "Child 4 of Parent B"], // duplicate key + [1019, 30, "Child 3 of Parent C"], + [1020, 40, "Child 4 of Parent D"], + [1021, 75, "Child 1 of Parent F"], // parent does not exist + [1022, 40, "Child 6 of Parent D"] +]; + +const options = { + autoCommit: true, + batchErrors: true, + dmlRowCounts: true, + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.NUMBER }, + { type: oracledb.STRING, maxSize: 20 } + ] +}; + +async function run() { + let conn; + let result; + + try { + conn = await oracledb.getConnection( + { + user : dbConfig.user, + password : dbConfig.password, + connectString : dbConfig.connectString + }); + + result = await conn.executeMany(sql, binds, options); + + console.log("Result is:", result); + + } catch (err) { + console.error(err); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +run(); diff --git a/javascript/node-oracledb/em_dmlreturn1.js b/javascript/node-oracledb/em_dmlreturn1.js new file mode 100644 index 00000000..e58f8fb2 --- /dev/null +++ b/javascript/node-oracledb/em_dmlreturn1.js @@ -0,0 +1,93 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_dmlreturn1.js + * + * DESCRIPTION + * executeMany() example of DML RETURNING that returns single values + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var async = require('async'); +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +var doconnect = function(cb) { + oracledb.getConnection(dbConfig, cb); +}; + +var dorelease = function(conn) { + conn.close(function (err) { + if (err) + console.error(err.message); + }); +}; + +var dotruncate = function(conn, cb) { + conn.execute("TRUNCATE TABLE em_tab", function (err) { + return cb(err, conn); + }); +}; + +var doinsert = function(conn, cb) { + var sql = "INSERT INTO em_tab VALUES (:1, :2) RETURNING ROWID, id, val INTO :3, :4, :5"; + + var binds = [ + [1, "Test 1 (One)"], + [2, "Test 2 (Two)"], + [3, "Test 3 (Three)"], + [4, null], + [5, "Test 5 (Five)"] + ]; + + var options = { + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.STRING, maxSize: 20 }, + { type: oracledb.STRING, maxSize: 18, dir: oracledb.BIND_OUT }, + { type: oracledb.NUMBER, dir: oracledb.BIND_OUT }, + { type: oracledb.STRING, maxSize: 25, dir: oracledb.BIND_OUT } + ] + }; + + conn.executeMany(sql, binds, options, function (err, result) { + if (err) + return cb(err, conn); + else { + console.log("rowsAffected is:", result.rowsAffected); + console.log("Out binds:"); + for (let i = 0; i < result.outBinds.length; i++) { + console.log("-->", result.outBinds[i]); + } + return cb(null, conn); + } + }); +}; + +async.waterfall( + [ + doconnect, + dotruncate, + doinsert + ], + function (err, conn) { + if (err) { console.error("In waterfall error cb: ==>", err, "<=="); } + if (conn) + dorelease(conn); + }); diff --git a/javascript/node-oracledb/em_dmlreturn1_aa.js b/javascript/node-oracledb/em_dmlreturn1_aa.js new file mode 100644 index 00000000..c320e9cf --- /dev/null +++ b/javascript/node-oracledb/em_dmlreturn1_aa.js @@ -0,0 +1,82 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_dmlreturn1_aa.js + * + * DESCRIPTION + * executeMany() example of DML RETURNING that returns single values + * This example also uses Async/Await of Node 8. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +const truncateSql = "TRUNCATE TABLE em_tab"; +const insertSql = "INSERT INTO em_tab VALUES (:1, :2) RETURNING ROWID, id, val INTO :3, :4, :5"; + +const binds = [ + [1, "Test 1 (One)"], + [2, "Test 2 (Two)"], + [3, "Test 3 (Three)"], + [4, null], + [5, "Test 5 (Five)"] +]; + +const options = { + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.STRING, maxSize: 20 }, + { type: oracledb.STRING, maxSize: 18, dir: oracledb.BIND_OUT }, + { type: oracledb.NUMBER, dir: oracledb.BIND_OUT }, + { type: oracledb.STRING, maxSize: 25, dir: oracledb.BIND_OUT } + ] +}; + +async function run() { + let conn; + let result; + + try { + conn = await oracledb.getConnection(dbConfig); + + await conn.execute(truncateSql); + + result = await conn.executeMany(insertSql, binds, options); + + console.log("rowsAffected is:", result.rowsAffected); + console.log("Out binds:"); + for (let i = 0; i < result.outBinds.length; i++) { + console.log("-->", result.outBinds[i]); + } + + } catch (err) { + console.error(err); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +run(); diff --git a/javascript/node-oracledb/em_dmlreturn2.js b/javascript/node-oracledb/em_dmlreturn2.js new file mode 100644 index 00000000..764b1ff1 --- /dev/null +++ b/javascript/node-oracledb/em_dmlreturn2.js @@ -0,0 +1,116 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_dmlreturn2.js + * + * DESCRIPTION + * executeMany() example of DML RETURNING that returns multiple values + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var async = require('async'); +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +var doconnect = function(cb) { + oracledb.getConnection(dbConfig, cb); +}; + +var dorelease = function(conn) { + conn.close(function (err) { + if (err) + console.error(err.message); + }); +}; + +var dotruncate = function(conn, cb) { + conn.execute("TRUNCATE TABLE em_tab", function (err) { + return cb(err, conn); + }); +}; + +var doinsert = function(conn, cb) { + var sql = "INSERT INTO em_tab VALUES (:1, :2)"; + + var binds = [ + [1, "Test 1 (One)"], + [2, "Test 2 (Two)"], + [3, "Test 3 (Three)"], + [4, "Test 4 (Four)"], + [5, "Test 5 (Five)"], + [6, "Test 6 (Six)"], + [7, "Test 7 (Seven)"], + [8, "Test 8 (Eight)"] + ]; + + var options = { + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.STRING, maxSize: 20 } + ] + }; + + conn.executeMany(sql, binds, options, function (err) { + return cb(err, conn); + }); +}; + +var dodelete = function(conn, cb) { + var sql = "DELETE FROM em_tab WHERE id < :1 RETURNING id, val INTO :2, :3"; + + var binds = [ + [2], + [6], + [8] + ]; + + var options = { + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.NUMBER, dir: oracledb.BIND_OUT }, + { type: oracledb.STRING, maxSize: 25, dir: oracledb.BIND_OUT } + ] + }; + + conn.executeMany(sql, binds, options, function (err, result) { + if (err) + return cb(err, conn); + else { + console.log("rowsAffected is:", result.rowsAffected); + console.log("Out binds:"); + for (let i = 0; i < result.outBinds.length; i++) { + console.log("-->", result.outBinds[i]); + } + return cb(null, conn); + } + }); +}; + +async.waterfall( + [ + doconnect, + dotruncate, + doinsert, + dodelete + ], + function (err, conn) { + if (err) { console.error("In waterfall error cb: ==>", err, "<=="); } + if (conn) + dorelease(conn); + }); diff --git a/javascript/node-oracledb/em_dmlreturn2_aa.js b/javascript/node-oracledb/em_dmlreturn2_aa.js new file mode 100644 index 00000000..6d992bf0 --- /dev/null +++ b/javascript/node-oracledb/em_dmlreturn2_aa.js @@ -0,0 +1,101 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_dmlreturn2_aa.js + * + * DESCRIPTION + * executeMany() example of DML RETURNING that returns multiple values + * This example also uses Async/Await of Node 8. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +const truncateSql = "TRUNCATE TABLE em_tab"; + +const insertSql = "INSERT INTO em_tab VALUES (:1, :2)"; + +const insertData = [ + [1, "Test 1 (One)"], + [2, "Test 2 (Two)"], + [3, "Test 3 (Three)"], + [4, "Test 4 (Four)"], + [5, "Test 5 (Five)"], + [6, "Test 6 (Six)"], + [7, "Test 7 (Seven)"], + [8, "Test 8 (Eight)"] +]; + +const insertOptions = { + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.STRING, maxSize: 20 } + ] +}; + +const deleteSql = "DELETE FROM em_tab WHERE id < :1 RETURNING id, val INTO :2, :3"; + +const deleteData = [ + [2], + [6], + [8] +]; + +const deleteOptions = { + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.NUMBER, dir: oracledb.BIND_OUT }, + { type: oracledb.STRING, maxSize: 25, dir: oracledb.BIND_OUT } + ] +}; + +async function run() { + let conn; + let result; + + try { + conn = await oracledb.getConnection(dbConfig); + + await conn.execute(truncateSql); + + await conn.executeMany(insertSql, insertData, insertOptions); + + result = await conn.executeMany(deleteSql, deleteData, deleteOptions); + + console.log("rowsAffected is:", result.rowsAffected); + console.log("Out binds:"); + for (let i = 0; i < result.outBinds.length; i++) { + console.log("-->", result.outBinds[i]); + } + + } catch (err) { + console.error(err); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +run(); diff --git a/javascript/node-oracledb/em_insert1.js b/javascript/node-oracledb/em_insert1.js new file mode 100644 index 00000000..b4d20c89 --- /dev/null +++ b/javascript/node-oracledb/em_insert1.js @@ -0,0 +1,88 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_insert1.js + * + * DESCRIPTION + * Array DML example using executeMany() with bind-by-name syntax. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var async = require('async'); +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +var doconnect = function(cb) { + oracledb.getConnection(dbConfig, cb); +}; + +var dorelease = function(conn) { + conn.close(function (err) { + if (err) + console.error(err.message); + }); +}; + +var dotruncate = function(conn, cb) { + conn.execute("TRUNCATE TABLE em_tab", function (err) { + return cb(err, conn); + }); +}; + +var doinsert = function(conn, cb) { + var sql = "INSERT INTO em_tab VALUES (:a, :b)"; + + var binds = [ + { a: 1, b: "Test 1 (One)" }, + { a: 2, b: "Test 2 (Two)" }, + { a: 3, b: "Test 3 (Three)" }, + { a: 4 }, + { a: 5, b: "Test 5 (Five)" } + ]; + + // bindDefs is optional for IN binds but it is generally recommended. + // Without it the data must be scanned to find sizes and types. + var options = { + autoCommit: true, + bindDefs: { + a: { type: oracledb.NUMBER }, + b: { type: oracledb.STRING, maxSize: 15 } + } }; + + conn.executeMany(sql, binds, options, function (err, result) { + if (err) + return cb(err, conn); + else { + console.log("Result is:", result); + return cb(null, conn); + } + }); +}; + +async.waterfall( + [ + doconnect, + dotruncate, + doinsert + ], + function (err, conn) { + if (err) { console.error("In waterfall error cb: ==>", err, "<=="); } + if (conn) + dorelease(conn); + }); diff --git a/javascript/node-oracledb/em_insert1_aa.js b/javascript/node-oracledb/em_insert1_aa.js new file mode 100644 index 00000000..c869c5a8 --- /dev/null +++ b/javascript/node-oracledb/em_insert1_aa.js @@ -0,0 +1,78 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_insert1_aa.js + * + * DESCRIPTION + * Array DML example using executeMany() with bind-by-name syntax. + * This example also uses Async/Await of Node 8. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +const truncateSql = "TRUNCATE TABLE em_tab"; +const insertSql = "INSERT INTO em_tab values (:a, :b)"; + +const binds = [ + { a: 1, b: "Test 1 (One)" }, + { a: 2, b: "Test 2 (Two)" }, + { a: 3, b: "Test 3 (Three)" }, + { a: 4 }, + { a: 5, b: "Test 5 (Five)" } +]; + +// bindDefs is optional for IN binds but it is generally recommended. +// Without it the data must be scanned to find sizes and types. +const options = { + autoCommit: true, + bindDefs: { + a: { type: oracledb.NUMBER }, + b: { type: oracledb.STRING, maxSize: 15 } + } +}; + +async function run() { + let conn; + let result; + + try { + conn = await oracledb.getConnection(dbConfig); + + await conn.execute(truncateSql); + + result = await conn.executeMany(insertSql, binds, options); + + console.log("Result is:", result); + + } catch (err) { + console.error(err); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +run(); diff --git a/javascript/node-oracledb/em_insert2.js b/javascript/node-oracledb/em_insert2.js new file mode 100644 index 00000000..06aab3c6 --- /dev/null +++ b/javascript/node-oracledb/em_insert2.js @@ -0,0 +1,88 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_insert2.js + * + * DESCRIPTION + * Array DML example using executeMany() with bind-by-position syntax. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var async = require('async'); +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +var doconnect = function(cb) { + oracledb.getConnection(dbConfig, cb); +}; + +var dorelease = function(conn) { + conn.close(function (err) { + if (err) + console.error(err.message); + }); +}; + +var dotruncate = function(conn, cb) { + conn.execute("TRUNCATE TABLE em_tab", function (err) { + return cb(err, conn); + }); +}; + +var doinsert = function(conn, cb) { + var sql = "INSERT INTO em_tab VALUES (:1, :2)"; + + var binds = [ + [1, "Test 1 (One)"], + [2, "Test 2 (Two)"], + [3, "Test 3 (Three)"], + [4, null], + [5, "Test 5 (Five)"] + ]; + + // bindDefs is optional for IN binds but it is generally recommended. + // Without it the data must be scanned to find sizes and types. + var options = { + autoCommit: true, + bindDefs: + [ { type: oracledb.NUMBER }, + { type: oracledb.STRING, maxSize: 15 } + ] }; + + conn.executeMany(sql, binds, options, function (err, result) { + if (err) + return cb(err, conn); + else { + console.log("Result is:", result); + return cb(null, conn); + } + }); +}; + +async.waterfall( + [ + doconnect, + dotruncate, + doinsert + ], + function (err, conn) { + if (err) { console.error("In waterfall error cb: ==>", err, "<=="); } + if (conn) + dorelease(conn); + }); diff --git a/javascript/node-oracledb/em_insert2_aa.js b/javascript/node-oracledb/em_insert2_aa.js new file mode 100644 index 00000000..253b4fd9 --- /dev/null +++ b/javascript/node-oracledb/em_insert2_aa.js @@ -0,0 +1,78 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_insert2.js + * + * DESCRIPTION + * Array DML example using executeMany() with bind by position. + * This example also uses Async/Await of Node 8. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +const truncateSql = "TRUNCATE TABLE em_tab"; +const insertSql = "INSERT INTO em_tab values (:1, :2)"; + +const binds = [ + [1, "Test 1 (One)"], + [2, "Test 2 (Two)"], + [3, "Test 3 (Three)"], + [4, null], + [5, "Test 5 (Five)"] +]; + +// bindDefs is optional for IN binds but it is generally recommended. +// Without it the data must be scanned to find sizes and types. +const options = { + autoCommit: true, + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.STRING, maxSize: 15 } + ] +}; + +async function run() { + let conn; + let result; + + try { + conn = await oracledb.getConnection(dbConfig); + + await conn.execute(truncateSql); + + result = await conn.executeMany(insertSql, binds, options); + + console.log("Result is:", result); + + } catch (err) { + console.error(err); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +run(); diff --git a/javascript/node-oracledb/em_plsql.js b/javascript/node-oracledb/em_plsql.js new file mode 100644 index 00000000..c665ac40 --- /dev/null +++ b/javascript/node-oracledb/em_plsql.js @@ -0,0 +1,80 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_plsql.js + * + * DESCRIPTION + * executeMany() example calling PL/SQL. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var async = require('async'); +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +var doconnect = function(cb) { + oracledb.getConnection(dbConfig, cb); +}; + +var dorelease = function(conn) { + conn.close(function (err) { + if (err) + console.error(err.message); + }); +}; + +var doplsql = function(conn, cb) { + var plsql = "BEGIN em_testproc(:1, :2, :3); END;"; + + var binds = [ + [1], + [2], + [3], + [4], + [6] + ]; + + var options = { + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.NUMBER, dir: oracledb.BIND_OUT }, + { type: oracledb.STRING, dir: oracledb.BIND_OUT, maxSize: 20 } + ] + }; + + conn.executeMany(plsql, binds, options, function (err, result) { + if (err) + return cb(err, conn); + else { + console.log("Result is:", result); + return cb(null, conn); + } + }); +}; + +async.waterfall( + [ + doconnect, + doplsql + ], + function (err, conn) { + if (err) { console.error("In waterfall error cb: ==>", err, "<=="); } + if (conn) + dorelease(conn); + }); diff --git a/javascript/node-oracledb/em_plsql_aa.js b/javascript/node-oracledb/em_plsql_aa.js new file mode 100644 index 00000000..f4181cb0 --- /dev/null +++ b/javascript/node-oracledb/em_plsql_aa.js @@ -0,0 +1,73 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_plsql_aa.js + * + * DESCRIPTION + * executeMany() example calling PL/SQL. + * This example also uses Async/Await of Node 8. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +const sql = "BEGIN em_testproc(:1, :2, :3); END;"; + +const binds = [ + [1], + [2], + [3], + [4], + [6] +]; + +const options = { + bindDefs: [ + { type: oracledb.NUMBER }, + { type: oracledb.NUMBER, dir: oracledb.BIND_OUT }, + { type: oracledb.STRING, dir: oracledb.BIND_OUT, maxSize: 20 } + ] +}; + +async function run() { + let conn; + let result; + + try { + conn = await oracledb.getConnection(dbConfig); + + result = await conn.executeMany(sql, binds, options); + + console.log("Result is:", result); + + } catch (err) { + console.error(err); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +run(); diff --git a/javascript/node-oracledb/em_rowcounts.js b/javascript/node-oracledb/em_rowcounts.js new file mode 100644 index 00000000..da65c9ad --- /dev/null +++ b/javascript/node-oracledb/em_rowcounts.js @@ -0,0 +1,74 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_rowcounts.js + * + * DESCRIPTION + * executeMany() example showing dmlRowCounts. + * For this example, there no commit so it is re-runnable. + * This example also uses Async/Await of Node 8. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var async = require('async'); +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +var doconnect = function(cb) { + oracledb.getConnection(dbConfig, cb); +}; + +var dorelease = function(conn) { + conn.close(function (err) { + if (err) + console.error(err.message); + }); +}; + +var dodelete = function(conn, cb) { + var sql = "DELETE FROM em_childtab WHERE parentid = :1"; + + var binds = [ + [20], + [30], + [50] + ]; + + var options = { dmlRowCounts: true }; + + conn.executeMany(sql, binds, options, function (err, result) { + if (err) + return cb(err, conn); + else { + console.log("Result is:", result); + return cb(null, conn); + } + }); +}; + +async.waterfall( + [ + doconnect, + dodelete + ], + function (err, conn) { + if (err) { console.error("In waterfall error cb: ==>", err, "<=="); } + if (conn) + dorelease(conn); + }); diff --git a/javascript/node-oracledb/em_rowcounts_aa.js b/javascript/node-oracledb/em_rowcounts_aa.js new file mode 100644 index 00000000..1e5c7c38 --- /dev/null +++ b/javascript/node-oracledb/em_rowcounts_aa.js @@ -0,0 +1,66 @@ +/* Copyright (c) 2018, Oracle and/or its affiliates. All rights reserved. */ + +/****************************************************************************** + * + * You may not use the identified files except in compliance with the Apache + * License, Version 2.0 (the "License.") + * + * You may obtain a copy of the License at + * http://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. + * + * NAME + * em_rowcounts_aa.js + * + * DESCRIPTION + * executeMany() example showing dmlRowCounts. + * For this example, there no commit so it is re-runnable. + * This example also uses Async/Await of Node 8. + * Use demo.sql to create the required schema. + * + *****************************************************************************/ + +var oracledb = require('oracledb'); +var dbConfig = require('./dbconfig.js'); + +const sql = "DELETE FROM em_childtab WHERE parentid = :1"; + +const binds = [ + [20], + [30], + [50] +]; + +const options = { dmlRowCounts: true }; + +async function run() { + let conn; + let result; + + try { + conn = await oracledb.getConnection(dbConfig); + + result = await conn.executeMany(sql, binds, options); + + console.log("Result is:", result); + + } catch (err) { + console.error(err); + } finally { + if (conn) { + try { + await conn.close(); + } catch (err) { + console.error(err); + } + } + } +} + +run(); diff --git a/javascript/node-oracledb/endtoend.js b/javascript/node-oracledb/endtoend.js index 2936e54b..d39541a2 100644 --- a/javascript/node-oracledb/endtoend.js +++ b/javascript/node-oracledb/endtoend.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -35,8 +35,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; } // These end-to-end tracing attributes are sent to the database on @@ -46,8 +45,7 @@ oracledb.getConnection( connection.action = "Query departments"; connection.execute("SELECT * FROM dual", - function(err, result) - { + function(err, result) { if (err) { doRelease(connection); console.error(err.message); return; } console.log(result.rows); // Sleep 10 seconds to keep the connection open. This allows @@ -62,8 +60,7 @@ oracledb.getConnection( }); // Release the connection -function doRelease(connection) -{ +function doRelease(connection) { connection.close( function(err) { if (err) { diff --git a/javascript/node-oracledb/fetchinfo.js b/javascript/node-oracledb/fetchinfo.js index 8d446337..4cc17e85 100644 --- a/javascript/node-oracledb/fetchinfo.js +++ b/javascript/node-oracledb/fetchinfo.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -40,8 +40,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; @@ -56,8 +55,7 @@ oracledb.getConnection( "COMMISSION_PCT": { type : oracledb.DEFAULT } // override oracledb.fetchAsString } }, - function(err, result) - { + function(err, result) { if (err) { console.error(err.message); doRelease(connection); @@ -68,8 +66,7 @@ oracledb.getConnection( }); }); -function doRelease(connection) -{ +function doRelease(connection) { connection.close( function(err) { if (err) { diff --git a/javascript/node-oracledb/insert1.js b/javascript/node-oracledb/insert1.js index a1cac623..52f817dc 100644 --- a/javascript/node-oracledb/insert1.js +++ b/javascript/node-oracledb/insert1.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -53,8 +53,7 @@ var dodrop = function (conn, cb) { RAISE; END IF; END;`, - function(err) - { + function(err) { if (err) { return cb(err, conn); } else { @@ -67,8 +66,7 @@ var dodrop = function (conn, cb) { var docreate = function (conn, cb) { conn.execute( "CREATE TABLE test (id NUMBER, name VARCHAR2(20))", - function(err) - { + function(err) { if (err) { return cb(err, conn); } else { @@ -82,8 +80,7 @@ var doinsert1 = function (conn, cb) { conn.execute( "INSERT INTO test VALUES (:id, :nm)", { id : {val: 1 }, nm : {val: 'Chris'} }, // 'bind by name' syntax - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -97,8 +94,7 @@ var doinsert2 = function (conn, cb) { conn.execute( "INSERT INTO test VALUES (:id, :nm)", [2, 'Alison'], // 'bind by position' syntax - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -113,8 +109,7 @@ var doupdate = function (conn, cb) { "UPDATE test SET name = :nm", ['Bambi'], { autoCommit: true }, // commit once for all DML in the script - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { diff --git a/javascript/node-oracledb/insert2.js b/javascript/node-oracledb/insert2.js index ea81e223..5d61572c 100644 --- a/javascript/node-oracledb/insert2.js +++ b/javascript/node-oracledb/insert2.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -58,8 +58,7 @@ var dodrop = function (conn, cb) { RAISE; END IF; END;`, - function(err) - { + function(err) { if (err) { return cb(err, conn); } else { @@ -72,8 +71,7 @@ var dodrop = function (conn, cb) { var docreate = function (conn, cb) { conn.execute( "CREATE TABLE test (id NUMBER, name VARCHAR2(20))", - function(err) - { + function(err) { if (err) { return cb(err, conn); } else { @@ -89,8 +87,7 @@ var doinsert_autocommit = function (conn, cb) { "INSERT INTO test VALUES (:id, :nm)", [1, 'Chris'], // Bind values { autoCommit: true}, // Override the default non-autocommit behavior - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -106,8 +103,7 @@ var doinsert_nocommit = function (conn, cb) { "INSERT INTO test VALUES (:id, :nm)", [2, 'Alison'], // Bind values // { autoCommit: true}, // Since this isn't set, operations using a second connection won't see this row - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -125,16 +121,14 @@ var doquery = function (conn, cb) { password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection2) - { + function(err, connection2) { if (err) { console.error(err.message); return cb(err, conn); } connection2.execute( "SELECT * FROM test", - function(err, result) - { + function(err, result) { if (err) { console.error(err.message); return cb(err, conn); @@ -145,8 +139,7 @@ var doquery = function (conn, cb) { console.log(result.rows); connection2.close( - function(err) - { + function(err) { if (err) { console.error(err.message); return cb(err, conn); diff --git a/javascript/node-oracledb/lobinsert1.js b/javascript/node-oracledb/lobinsert1.js index 3be8b0d9..788bb549 100644 --- a/javascript/node-oracledb/lobinsert1.js +++ b/javascript/node-oracledb/lobinsert1.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -75,8 +75,7 @@ var doclobinsert = function(conn, cb) { conn.execute( "INSERT INTO mylobs (id, c) VALUES (:id, :c)", { id: 1, c: str }, - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } @@ -93,8 +92,7 @@ var doblobinsert = function(conn, cb) { conn.execute( "INSERT INTO mylobs (id, b) VALUES (:id, :b)", { id: 2, b: buf }, - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } diff --git a/javascript/node-oracledb/lobinsert2.js b/javascript/node-oracledb/lobinsert2.js index d6ef1f2f..d08c4b54 100644 --- a/javascript/node-oracledb/lobinsert2.js +++ b/javascript/node-oracledb/lobinsert2.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -64,8 +64,7 @@ oracledb.getConnection( function() { console.log("lob.on 'close' event"); connection.commit( - function(err) - { + function(err) { if (!errorHandled) { errorHandled = true; if (err) { diff --git a/javascript/node-oracledb/lobinserttemp.js b/javascript/node-oracledb/lobinserttemp.js index bf0d58be..8e2fcaca 100644 --- a/javascript/node-oracledb/lobinserttemp.js +++ b/javascript/node-oracledb/lobinserttemp.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2016, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2016, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -80,15 +80,13 @@ var doloadtemplob = function (conn, templob, cb) { templob.on( 'close', - function() - { + function() { console.log("templob.on 'close' event"); }); templob.on( 'error', - function(err) - { + function(err) { console.log("templob.on 'error' event"); if (!errorHandled) { errorHandled = true; @@ -98,8 +96,7 @@ var doloadtemplob = function (conn, templob, cb) { templob.on( 'finish', - function() - { + function() { console.log("templob.on 'finish' event"); // The data was loaded into the temporary LOB if (!errorHandled) { @@ -111,8 +108,7 @@ var doloadtemplob = function (conn, templob, cb) { var inStream = fs.createReadStream(inFileName); inStream.on( 'error', - function(err) - { + function(err) { console.log("inStream.on 'error' event"); if (!errorHandled) { errorHandled = true; @@ -130,8 +126,7 @@ var doinsert = function (conn, templob, cb) { { idbv: 3, lobbv: templob }, // type and direction are optional for IN binds { autoCommit: true }, - function(err, result) - { + function(err, result) { if (err) { return cb(err); } diff --git a/javascript/node-oracledb/lobplsqltemp.js b/javascript/node-oracledb/lobplsqltemp.js index e62692b2..ca449ebb 100644 --- a/javascript/node-oracledb/lobplsqltemp.js +++ b/javascript/node-oracledb/lobplsqltemp.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2016, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2016, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -80,15 +80,13 @@ var loadtemplob = function (conn, templob, cb) { templob.on( 'close', - function() - { + function() { console.log("templob.on 'close' event"); }); templob.on( 'error', - function(err) - { + function(err) { console.log("templob.on 'error' event"); if (!errorHandled) { errorHandled = true; @@ -98,8 +96,7 @@ var loadtemplob = function (conn, templob, cb) { templob.on( 'finish', - function() - { + function() { console.log("templob.on 'finish' event"); // The data was loaded into the temporary LOB if (!errorHandled) { @@ -111,8 +108,7 @@ var loadtemplob = function (conn, templob, cb) { var inStream = fs.createReadStream(inFileName); inStream.on( 'error', - function(err) - { + function(err) { console.log("inStream.on 'error' event"); if (!errorHandled) { errorHandled = true; @@ -130,8 +126,7 @@ var doinsert = function (conn, templob, cb) { { id: 3, c: templob }, // type and direction are optional for IN binds { autoCommit: true }, - function(err) - { + function(err) { if (err) { return cb(err); } diff --git a/javascript/node-oracledb/lobselect.js b/javascript/node-oracledb/lobselect.js index 36816ec3..6b647bc8 100644 --- a/javascript/node-oracledb/lobselect.js +++ b/javascript/node-oracledb/lobselect.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2016, 2017 Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2016, 2018 Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -72,8 +72,7 @@ var doclobquery = function(conn, cb) { [1], // An alternative to oracledb.fetchAsString is to use fetchInfo on the column: // { fetchInfo: {"C": {type: oracledb.STRING}} }, - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } @@ -93,8 +92,7 @@ var doblobquery = function(conn, cb) { [2], // An alternative to oracledb.fetchAsBuffer is to use fetchInfo on the column: // { fetchInfo: {"B": {type: oracledb.BUFFER}} }, - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } diff --git a/javascript/node-oracledb/lobstream2.js b/javascript/node-oracledb/lobstream2.js index 87c7ef7c..10d2da46 100644 --- a/javascript/node-oracledb/lobstream2.js +++ b/javascript/node-oracledb/lobstream2.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2016, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2016, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -41,9 +41,9 @@ var doconnect = function(cb) { connectString : dbConfig.connectString }, function(err, conn) { - if (err) + if (err) { return cb(err); - else { + } else { return cb(null, conn); } }); @@ -59,8 +59,7 @@ var dorelease = function(conn) { var doquery = function(conn, cb) { conn.execute( "SELECT c FROM mylobs WHERE id = 1", - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } @@ -88,8 +87,7 @@ var dostream = function(conn, clob, cb) { clob.setEncoding('utf8'); // set the encoding so we get a 'string' not a 'buffer' clob.on( 'error', - function(err) - { + function(err) { console.log("clob.on 'error' event"); if (!errorHandled) { errorHandled = true; @@ -100,23 +98,20 @@ var dostream = function(conn, clob, cb) { }); clob.on( 'data', - function(chunk) - { + function(chunk) { console.log("clob.on 'data' event. Got %d bytes of data", chunk.length); // Build up the string. For larger LOBs you might want to print or use each chunk separately myclob += chunk; // or use Buffer.concat() for BLOBS }); clob.on( 'end', - function() - { + function() { console.log("clob.on 'end' event"); console.log(myclob); }); clob.on( 'close', - function() - { + function() { console.log("clob.on 'close' event"); if (!errorHandled) { return cb(null, conn); diff --git a/javascript/node-oracledb/metadata.js b/javascript/node-oracledb/metadata.js index c3810a11..8e1be22d 100644 --- a/javascript/node-oracledb/metadata.js +++ b/javascript/node-oracledb/metadata.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2016, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -52,8 +52,7 @@ var dorelease = function(conn) { var basic = function (conn, cb) { conn.execute( "SELECT location_id, city FROM locations", - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -69,8 +68,7 @@ var extended = function (conn, cb) { "SELECT location_id, city FROM locations", {}, // no binds { extendedMetaData: true }, // enable the extra metadata - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { diff --git a/javascript/node-oracledb/plsqlfunc.js b/javascript/node-oracledb/plsqlfunc.js index 1fb09b96..6c1376b4 100644 --- a/javascript/node-oracledb/plsqlfunc.js +++ b/javascript/node-oracledb/plsqlfunc.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -40,8 +40,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function (err, connection) - { + function (err, connection) { if (err) { console.error(err.message); return; } var bindvars = { @@ -51,9 +50,10 @@ oracledb.getConnection( }; connection.execute( "BEGIN :ret := testfunc(:p1, :p2); END;", + // The equivalent call with PL/SQL named parameter syntax is: + // "BEGIN :ret := testfunc(p1_in => :p1, p2_in => :p2); END;", bindvars, - function (err, result) - { + function (err, result) { if (err) { console.error(err.message); doRelease(connection); @@ -64,8 +64,7 @@ oracledb.getConnection( }); }); -function doRelease(connection) -{ +function doRelease(connection) { connection.close( function(err) { if (err) { diff --git a/javascript/node-oracledb/plsqlproc.js b/javascript/node-oracledb/plsqlproc.js index 5bc51bd1..4e35e943 100644 --- a/javascript/node-oracledb/plsqlproc.js +++ b/javascript/node-oracledb/plsqlproc.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -41,8 +41,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function (err, connection) - { + function (err, connection) { if (err) { console.error(err.message); return; } var bindvars = { @@ -52,9 +51,10 @@ oracledb.getConnection( }; connection.execute( "BEGIN testproc(:i, :io, :o); END;", + // The equivalent call with PL/SQL named parameter syntax is: + // "BEGIN testproc(p_in => :i, p_inout => :io, p_out => :o); END;", bindvars, - function (err, result) - { + function (err, result) { if (err) { console.error(err.message); doRelease(connection); @@ -65,8 +65,7 @@ oracledb.getConnection( }); }); -function doRelease(connection) -{ +function doRelease(connection) { connection.close( function(err) { if (err) { diff --git a/javascript/node-oracledb/refcursor.js b/javascript/node-oracledb/refcursor.js index 1ccbe982..b6d6d6d1 100644 --- a/javascript/node-oracledb/refcursor.js +++ b/javascript/node-oracledb/refcursor.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -48,8 +48,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; } var bindvars = { sal: 12000, @@ -58,8 +57,7 @@ oracledb.getConnection( connection.execute( "BEGIN get_emp_rs(:sal, :cursor); END;", bindvars, - function(err, result) - { + function(err, result) { if (err) { console.error(err.message); doRelease(connection); @@ -70,12 +68,10 @@ oracledb.getConnection( }); }); -function fetchRowsFromRS(connection, resultSet, numRows) -{ +function fetchRowsFromRS(connection, resultSet, numRows) { resultSet.getRows( // get numRows rows numRows, - function (err, rows) - { + function (err, rows) { if (err) { console.log(err); doClose(connection, resultSet); // always close the ResultSet @@ -89,20 +85,16 @@ function fetchRowsFromRS(connection, resultSet, numRows) }); } -function doRelease(connection) -{ +function doRelease(connection) { connection.close( - function(err) - { + function(err) { if (err) { console.error(err.message); } }); } -function doClose(connection, resultSet) -{ +function doClose(connection, resultSet) { resultSet.close( - function(err) - { + function(err) { if (err) { console.error(err.message); } doRelease(connection); }); diff --git a/javascript/node-oracledb/refcursortoquerystream.js b/javascript/node-oracledb/refcursortoquerystream.js index 2e68ad5c..474f9436 100644 --- a/javascript/node-oracledb/refcursortoquerystream.js +++ b/javascript/node-oracledb/refcursortoquerystream.js @@ -71,7 +71,7 @@ oracledb.getConnection( doRelease(connection); }); - queryStream.on('end', function () { + queryStream.on('close', function () { doRelease(connection); }); } diff --git a/javascript/node-oracledb/resultset1.js b/javascript/node-oracledb/resultset1.js index ec0ccdfb..f030a134 100644 --- a/javascript/node-oracledb/resultset1.js +++ b/javascript/node-oracledb/resultset1.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -47,8 +47,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; } connection.execute( `SELECT employee_id, last_name @@ -57,8 +56,7 @@ oracledb.getConnection( ORDER BY employee_id`, [], // no bind variables { resultSet: true }, // return a ResultSet. Default is false - function(err, result) - { + function(err, result) { if (err) { console.error(err.message); doRelease(connection); @@ -69,11 +67,9 @@ oracledb.getConnection( }); }); -function fetchOneRowFromRS(connection, resultSet) -{ +function fetchOneRowFromRS(connection, resultSet) { resultSet.getRow( // get one row - function (err, row) - { + function (err, row) { if (err) { console.error(err.message); doClose(connection, resultSet); // always close the ResultSet @@ -88,20 +84,16 @@ function fetchOneRowFromRS(connection, resultSet) }); } -function doRelease(connection) -{ +function doRelease(connection) { connection.close( - function(err) - { + function(err) { if (err) { console.error(err.message); } }); } -function doClose(connection, resultSet) -{ +function doClose(connection, resultSet) { resultSet.close( - function(err) - { + function(err) { if (err) { console.error(err.message); } doRelease(connection); }); diff --git a/javascript/node-oracledb/resultset2.js b/javascript/node-oracledb/resultset2.js index 87d16073..5d9821ae 100644 --- a/javascript/node-oracledb/resultset2.js +++ b/javascript/node-oracledb/resultset2.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -38,8 +38,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; } connection.execute( `SELECT employee_id, last_name @@ -50,8 +49,7 @@ oracledb.getConnection( { resultSet: true // return a ResultSet. Default is false }, - function(err, result) - { + function(err, result) { if (err) { console.error(err.message); doRelease(connection); @@ -62,12 +60,10 @@ oracledb.getConnection( }); }); -function fetchRowsFromRS(connection, resultSet, numRows) -{ +function fetchRowsFromRS(connection, resultSet, numRows) { resultSet.getRows( numRows, // get this many rows - function (err, rows) - { + function (err, rows) { if (err) { console.error(err); doClose(connection, resultSet); // always close the ResultSet @@ -84,20 +80,16 @@ function fetchRowsFromRS(connection, resultSet, numRows) }); } -function doRelease(connection) -{ +function doRelease(connection) { connection.close( - function(err) - { + function(err) { if (err) { console.error(err.message); } }); } -function doClose(connection, resultSet) -{ +function doClose(connection, resultSet) { resultSet.close( - function(err) - { + function(err) { if (err) { console.error(err.message); } doRelease(connection); }); diff --git a/javascript/node-oracledb/resultsettoquerystream.js b/javascript/node-oracledb/resultsettoquerystream.js index 772cf934..63c123a7 100644 --- a/javascript/node-oracledb/resultsettoquerystream.js +++ b/javascript/node-oracledb/resultsettoquerystream.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2016, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -35,8 +35,7 @@ var dbConfig = require('./dbconfig.js'); oracledb.getConnection( dbConfig, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; } var sql = "SELECT employee_id, last_name FROM employees WHERE ROWNUM < 25 ORDER BY employee_id"; connection.execute( @@ -45,10 +44,8 @@ oracledb.getConnection( { resultSet: true }, - function(err, result) - { - if (err) - { + function(err, result) { + if (err) { console.error(err.message); doRelease(connection); return; @@ -64,7 +61,7 @@ oracledb.getConnection( doRelease(connection); }); - queryStream.on('end', function() { + queryStream.on('close', function() { doRelease(connection); }); } @@ -72,11 +69,9 @@ oracledb.getConnection( } ); -function doRelease(connection) -{ +function doRelease(connection) { connection.close( - function(err) - { + function(err) { if (err) { console.error(err.message); } }); } diff --git a/javascript/node-oracledb/rowlimit.js b/javascript/node-oracledb/rowlimit.js index bee74670..dc75fd2a 100644 --- a/javascript/node-oracledb/rowlimit.js +++ b/javascript/node-oracledb/rowlimit.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -51,8 +51,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function (err, connection) - { + function (err, connection) { if (err) { console.error(err.message); return; @@ -71,8 +70,8 @@ oracledb.getConnection( connection.execute( sql, - {offset: myoffset, maxnumrows: mymaxnumrows}, - {maxRows: 150}, + { offset: myoffset, maxnumrows: mymaxnumrows }, + { maxRows: 150 }, function(err, result) { if (err) { console.error(err.message); diff --git a/javascript/node-oracledb/select1.js b/javascript/node-oracledb/select1.js index 02e708e6..369d4a14 100644 --- a/javascript/node-oracledb/select1.js +++ b/javascript/node-oracledb/select1.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -42,8 +42,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; @@ -68,8 +67,7 @@ oracledb.getConnection( }, // The callback function handles the SQL execution results - function(err, result) - { + function(err, result) { if (err) { console.error(err.message); doRelease(connection); @@ -82,8 +80,7 @@ oracledb.getConnection( }); // Note: connections should always be released when not needed -function doRelease(connection) -{ +function doRelease(connection) { connection.close( function(err) { if (err) { diff --git a/javascript/node-oracledb/select2.js b/javascript/node-oracledb/select2.js index 35444653..f58d5969 100644 --- a/javascript/node-oracledb/select2.js +++ b/javascript/node-oracledb/select2.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -69,8 +69,7 @@ var dorelease = function(conn) { var doquery_array = function (conn, cb) { conn.execute( "SELECT location_id, city FROM locations WHERE city LIKE 'S%' ORDER BY city", - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -88,8 +87,7 @@ var doquery_object = function (conn, cb) { {}, // A bind variable parameter is needed to disambiguate the following options parameter // otherwise you will get Error: ORA-01036: illegal variable name/number { outFormat: oracledb.OBJECT }, // outFormat can be OBJECT or ARRAY. The default is ARRAY - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { diff --git a/javascript/node-oracledb/selectjson.js b/javascript/node-oracledb/selectjson.js index 4b56bce7..89a03b8f 100644 --- a/javascript/node-oracledb/selectjson.js +++ b/javascript/node-oracledb/selectjson.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -77,8 +77,7 @@ var dojsonquery = function (conn, cb) { console.log('1. Selecting JSON stored in a VARCHAR2 column'); conn.execute( "SELECT po_document FROM j_purchaseorder WHERE JSON_EXISTS (po_document, '$.location')", - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -89,13 +88,27 @@ var dojsonquery = function (conn, cb) { }); }; -// 2. Using JSON_VALUE to extract a value from a JSON column +// 2. Extract a value from a JSON column. This syntax requires Oracle Database 12.2 +var dorelationalquerydot = function (conn, cb) { + console.log('2. Using dot-notation to extract a value from a JSON column'); + conn.execute( + "SELECT po.po_document.location FROM j_purchaseorder po", + function(err, result) { + if (err) { + return cb(err, conn); + } else { + console.log('Query results: ', result.rows[0][0]); // just show first record + return cb(null, conn); + } + }); +}; + +// 3. Using JSON_VALUE to extract a value from a JSON column var dorelationalquery = function (conn, cb) { - console.log('2. Using JSON_VALUE to extract a value from a JSON column'); + console.log('3. Using JSON_VALUE to extract a value from a JSON column'); conn.execute( "SELECT JSON_VALUE(po_document, '$.location') FROM j_purchaseorder", - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -105,9 +118,9 @@ var dorelationalquery = function (conn, cb) { }); }; -// 3. Using JSON_OBJECT to extract relational data as JSON +// 4. Using JSON_OBJECT to extract relational data as JSON var dojsonfromrelational = function (conn, cb) { - console.log('3. Using JSON_OBJECT to extract relational data as JSON'); + console.log('4. Using JSON_OBJECT to extract relational data as JSON'); if (conn.oracleServerVersion < 1202000000) { // JSON_OBJECT is new in Oracle Database 12.2 console.log('The JSON_OBJECT example only works with Oracle Database 12.2 or greater'); return cb(null, conn); @@ -117,8 +130,7 @@ var dojsonfromrelational = function (conn, cb) { FROM departments d WHERE department_id < :did`, [50], - function(err, result) - { + function(err, result) { if (err) { return cb(err, conn); } else { @@ -136,6 +148,7 @@ async.waterfall( checkver, doinsert, dojsonquery, + dorelationalquerydot, dorelationalquery, dojsonfromrelational ], diff --git a/javascript/node-oracledb/selectjsonblob.js b/javascript/node-oracledb/selectjsonblob.js index 0e67523a..3c856096 100644 --- a/javascript/node-oracledb/selectjsonblob.js +++ b/javascript/node-oracledb/selectjsonblob.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -19,7 +19,7 @@ * selectjsonblob.js * * DESCRIPTION - * Executes sample insert and query using a JSON column with BLOB storage. + * Executes sample insert and query statements using a JSON column with BLOB storage. * Requires Oracle Database 12.1.0.2, which has extensive JSON datatype support. * See https://docs.oracle.com/database/122/ADJSN/toc.htm * @@ -60,8 +60,7 @@ var doinsert = function (conn, cb) { "INSERT INTO j_purchaseorder_b (po_document) VALUES (:lobbv)", { lobbv: b }, // { autoCommit: true }, // uncomment if you want data to persist - function(err) - { + function(err) { if (err) { return cb(err, conn); } else { @@ -71,33 +70,49 @@ var doinsert = function (conn, cb) { }); }; -// Select JSON stored in a BLOB column +// Select JSON with JSON_EXISTS var dojsonquery = function (conn, cb) { - console.log('Selecting JSON stored in a BLOB column'); + console.log('Selecting JSON stored in a BLOB column:'); conn.execute( "SELECT po_document FROM j_purchaseorder_b WHERE JSON_EXISTS (po_document, '$.location')", [], { fetchInfo: { "PO_DOCUMENT": { type: oracledb.BUFFER } } }, // Fetch as a Buffer instead of a Stream - function(err, result) - { + function(err, result) { if (err) return cb(err, conn); if (result.rows.length === 0) return cb(new Error('No results'), conn); - console.log('Query results:'); console.log(result.rows[0][0].toString('utf8')); return cb(null, conn); }); }; +// Select a JSON value using dot-notation. This syntax requires Oracle Database 12.2 + +var dojsonquerydot = function (conn, cb) { + console.log('Selecting a JSON value:'); + conn.execute( + "SELECT pob.po_document.location FROM j_purchaseorder_b pob", + function(err, result) { + if (err) + return cb(err, conn); + if (result.rows.length === 0) + return cb(new Error('No results'), conn); + + console.log(result.rows[0][0]); + return cb(null, conn); + }); +}; + async.waterfall( [ doconnect, checkver, doinsert, - dojsonquery + dojsonquery, + dojsonquerydot ], function (err, conn) { if (err) { console.error("In waterfall error cb: ==>", err, "<=="); } diff --git a/javascript/node-oracledb/selectstream.js b/javascript/node-oracledb/selectstream.js index 59a433d1..b8d79605 100644 --- a/javascript/node-oracledb/selectstream.js +++ b/javascript/node-oracledb/selectstream.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2016, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2016, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -38,8 +38,7 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; diff --git a/javascript/node-oracledb/version.js b/javascript/node-oracledb/version.js index 76dc010d..1f63308f 100644 --- a/javascript/node-oracledb/version.js +++ b/javascript/node-oracledb/version.js @@ -1,4 +1,4 @@ -/* Copyright (c) 2015, 2017, Oracle and/or its affiliates. All rights reserved. */ +/* Copyright (c) 2015, 2018, Oracle and/or its affiliates. All rights reserved. */ /****************************************************************************** * @@ -26,27 +26,15 @@ var oracledb = require('oracledb'); var dbConfig = require('./dbconfig.js'); -var addonVer, clientVer, serverVer; -var major, minor, update, port, portUpdate; - console.log("Run at: " + new Date()); console.log("Node.js version: " + process.version + " (" + process.platform, process.arch + ")"); -addonVer = oracledb.version; -major = Math.floor(addonVer / 10000); -minor = Math.floor(addonVer / 100) % 100; -update = addonVer % 100; -//console.log("Node-oracledb version: " + addonVer); -console.log("Node-oracledb text format: " + major + "." + minor + "." + update); +// console.log("Node-oracledb version:", oracledb.version); // numeric version format is useful for comparisons +// console.log("Node-oracledb version suffix:", oracledb.versionSuffix); // e.g. "-beta.1", or empty for production releases +console.log("Node-oracledb version:", oracledb.versionString); // version (including the suffix) -clientVer = oracledb.oracleClientVersion; -major = Math.floor (clientVer / 100000000); -minor = Math.floor (clientVer / 1000000) % 100 ; -update = Math.floor (clientVer / 10000) % 100 ; -port = Math.floor (clientVer / 100) % 100 ; -portUpdate = clientVer % 100 ; -//console.log("Oracle Client library version: " + clientVer); -console.log("Oracle Client library text format: " + major + "." + minor + "." + update + "." + port + "." + portUpdate); +//console.log("Oracle Client library version:", oracledb.oracleClientVersion); // numeric version format +console.log("Oracle Client library version:", oracledb.oracleClientVersionString); oracledb.getConnection( { @@ -54,19 +42,12 @@ oracledb.getConnection( password : dbConfig.password, connectString : dbConfig.connectString }, - function(err, connection) - { + function(err, connection) { if (err) { console.error(err.message); return; } - serverVer = connection.oracleServerVersion; - major = Math.floor (serverVer / 100000000); - minor = Math.floor (serverVer / 1000000) % 100 ; - update = Math.floor (serverVer / 10000) % 100 ; - port = Math.floor (serverVer / 100) % 100 ; - portUpdate = serverVer % 100 ; - // console.log("Oracle Database version: " + serverVer); - console.log("Oracle Database text format: " + major + "." + minor + "." + update + "." + port + "." + portUpdate); + // console.log("Oracle Database version:", connection.oracleServerVersion); // numeric version format + console.log("Oracle Database version:", connection.oracleServerVersionString); }); diff --git a/javascript/node-oracledb/webapp.js b/javascript/node-oracledb/webapp.js index 5ee2abb6..41f1b6fc 100644 --- a/javascript/node-oracledb/webapp.js +++ b/javascript/node-oracledb/webapp.js @@ -47,15 +47,16 @@ function init() { password: dbConfig.password, connectString: dbConfig.connectString // Default values shown below + // events: false, // whether to handle Oracle Database FAN and RLB events // externalAuth: false, // whether connections should be established using External Authentication + // poolAlias: 'myalias' // set an alias to allow access to the pool via a name + // poolIncrement: 1, // only grow the pool by one connection at a time // poolMax: 4, // maximum size of the pool. Increase UV_THREADPOOL_SIZE if you increase poolMax // poolMin: 0, // start with no connections; let the pool shrink completely - // poolIncrement: 1, // only grow the pool by one connection at a time - // poolTimeout: 60, // terminate connections that are idle in the pool for 60 seconds // poolPingInterval: 60, // check aliveness of connection if in the pool for 60 seconds + // poolTimeout: 60, // terminate connections that are idle in the pool for 60 seconds // queueRequests: true, // let Node.js queue new getConnection() requests if all pool connections are in use // queueTimeout: 60000, // terminate getConnection() calls in the queue longer than 60000 milliseconds - // poolAlias: 'myalias' // could set an alias to allow access to the pool via a name // stmtCacheSize: 30 // number of statements that are cached in the statement cache of each connection }, function(err, pool) { diff --git a/javascript/node-oracledb/webapppromises.js b/javascript/node-oracledb/webapppromises.js index fbedfefa..4a53d417 100644 --- a/javascript/node-oracledb/webapppromises.js +++ b/javascript/node-oracledb/webapppromises.js @@ -47,15 +47,16 @@ function init() { password: dbConfig.password, connectString: dbConfig.connectString // Default values shown below + // events: false, // whether to handle Oracle Database FAN and RLB events // externalAuth: false, // whether connections should be established using External Authentication + // poolAlias: 'myalias' // set an alias to allow access to the pool via a name. + // poolIncrement: 1, // only grow the pool by one connection at a time // poolMax: 4, // maximum size of the pool. Increase UV_THREADPOOL_SIZE if you increase poolMax // poolMin: 0, // start with no connections; let the pool shrink completely - // poolIncrement: 1, // only grow the pool by one connection at a time - // poolTimeout: 60, // terminate connections that are idle in the pool for 60 seconds // poolPingInterval: 60, // check aliveness of connection if in the pool for 60 seconds + // poolTimeout: 60, // terminate connections that are idle in the pool for 60 seconds // queueRequests: true, // let Node.js queue new getConnection() requests if all pool connections are in use // queueTimeout: 60000, // terminate getConnection() calls in the queue longer than 60000 milliseconds - // poolAlias: 'myalias' // could set an alias to allow access to the pool via a name. // stmtCacheSize: 30 // number of statements that are cached in the statement cache of each connection }) .then(function(pool) { diff --git a/javascript/rest-api/part-3-handling-get-requests/hr_app/controllers/employees.js b/javascript/rest-api/part-3-handling-get-requests/hr_app/controllers/employees.js index a5257c6c..2310cf62 100644 --- a/javascript/rest-api/part-3-handling-get-requests/hr_app/controllers/employees.js +++ b/javascript/rest-api/part-3-handling-get-requests/hr_app/controllers/employees.js @@ -4,7 +4,7 @@ async function get(req, res, next) { try { const context = {}; - context.id = Number(req.params.id); + context.id = parseInt(req.params.id, 10); const rows = await employees.find(context); diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/config/database.js b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/config/database.js new file mode 100644 index 00000000..40831f85 --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/config/database.js @@ -0,0 +1,10 @@ +module.exports = { + hrPool: { + user: process.env.HR_USER, + password: process.env.HR_PASSWORD, + connectString: process.env.HR_CONNECTIONSTRING, + poolMin: 10, + poolMax: 10, + poolIncrement: 0 + } +}; diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/config/web-server.js b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/config/web-server.js new file mode 100644 index 00000000..ff74b593 --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/config/web-server.js @@ -0,0 +1,3 @@ +module.exports = { + port: process.env.HTTP_PORT || 3000 +}; diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/controllers/employees.js b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/controllers/employees.js new file mode 100644 index 00000000..b22bae5e --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/controllers/employees.js @@ -0,0 +1,95 @@ +const employees = require('../db_apis/employees.js'); + +async function get(req, res, next) { + try { + const context = {}; + + context.id = parseInt(req.params.id, 10); + + const rows = await employees.find(context); + + if (req.params.id) { + if (rows.length === 1) { + res.status(200).json(rows[0]); + } else { + res.status(404).end(); + } + } else { + res.status(200).json(rows); + } + } catch (err) { + next(err); + } +} + +module.exports.get = get; + +function getEmployeeFromRec(req) { + const employee = { + first_name: req.body.first_name, + last_name: req.body.last_name, + email: req.body.email, + phone_number: req.body.phone_number, + hire_date: req.body.hire_date, + job_id: req.body.job_id, + salary: req.body.salary, + commission_pct: req.body.commission_pct, + manager_id: req.body.manager_id, + department_id: req.body.department_id + }; + + return employee; +} + +async function post(req, res, next) { + try { + let employee = getEmployeeFromRec(req); + + employee = await employees.create(employee); + + res.status(201).json(employee); + } catch (err) { + next(err); + } +} + +module.exports.post = post; + +async function put(req, res, next) { + try { + let employee = getEmployeeFromRec(req); + + employee.employee_id = parseInt(req.params.id, 10); + + employee = await employees.update(employee); + + if (employee !== null) { + res.status(200).json(employee); + } else { + res.status(404).end(); + } + } catch (err) { + next(err); + } +} + +module.exports.put = put; + +async function del(req, res, next) { + try { + const id = parseInt(req.params.id, 10); + + const success = await employees.delete(id); + + if (success) { + res.status(204).end(); + } else { + res.status(404).end(); + } + } catch (err) { + next(err); + } +} + +module.exports.delete = del; + diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/db_apis/employees.js b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/db_apis/employees.js new file mode 100644 index 00000000..5e02d3f6 --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/db_apis/employees.js @@ -0,0 +1,131 @@ +const oracledb = require('oracledb'); +const database = require('../services/database.js'); + +const baseQuery = + `select employee_id "id", + first_name "first_name", + last_name "last_name", + email "email", + phone_number "phone_number", + hire_date "hire_date", + job_id "job_id", + salary "salary", + commission_pct "commission_pct", + manager_id "manager_id", + department_id "department_id" + from employees`; + +async function find(context) { + let query = baseQuery; + const binds = {}; + + if (context.id) { + binds.employee_id = context.id; + + query += `\nwhere employee_id = :employee_id`; + } + + const result = await database.simpleExecute(query, binds); + + return result.rows; +} + +module.exports.find = find; + +const createSql = + `insert into employees ( + first_name, + last_name, + email, + phone_number, + hire_date, + job_id, + salary, + commission_pct, + manager_id, + department_id + ) values ( + :first_name, + :last_name, + :email, + :phone_number, + :hire_date, + :job_id, + :salary, + :commission_pct, + :manager_id, + :department_id + ) returning employee_id + into :employee_id`; + +async function create(emp) { + const employee = Object.assign({}, emp); + + employee.employee_id = { + dir: oracledb.BIND_OUT, + type: oracledb.NUMBER + } + + const result = await database.simpleExecute(createSql, employee); + + employee.employee_id = result.outBinds.employee_id[0]; + + return employee; +} + +module.exports.create = create; + +const updateSql = + `update employees + set first_name = :first_name, + last_name = :last_name, + email = :email, + phone_number = :phone_number, + hire_date = :hire_date, + job_id = :job_id, + salary = :salary, + commission_pct = :commission_pct, + manager_id = :manager_id, + department_id = :department_id + where employee_id = :employee_id`; + +async function update(emp) { + const employee = Object.assign({}, emp); + const result = await database.simpleExecute(updateSql, employee); + + if (result.rowsAffected === 1) { + return employee; + } else { + return null; + } +} + +module.exports.update = update; + +const deleteSql = + `begin + + delete from job_history + where employee_id = :employee_id; + + delete from employees + where employee_id = :employee_id; + + :rowcount := sql%rowcount; + + end;` + +async function del(id) { + const binds = { + employee_id: id, + rowcount: { + dir: oracledb.BIND_OUT, + type: oracledb.NUMBER + } + } + const result = await database.simpleExecute(deleteSql, binds); + + return result.outBinds.rowcount === 1; +} + +module.exports.delete = del; diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/index.js b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/index.js new file mode 100644 index 00000000..0eba3fad --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/index.js @@ -0,0 +1,86 @@ +const webServer = require('./services/web-server.js'); +const database = require('./services/database.js'); +const dbConfig = require('./config/database.js'); +const defaultThreadPoolSize = 4; + +// Increase thread pool size by poolMax +process.env.UV_THREADPOOL_SIZE = dbConfig.hrPool.poolMax + defaultThreadPoolSize; + +async function startup() { + console.log('Starting application'); + + try { + console.log('Initializing database module'); + + await database.initialize(); + } catch (err) { + console.error(err); + + process.exit(1); // Non-zero failure code + } + + try { + console.log('Initializing web server module'); + + await webServer.initialize(); + } catch (err) { + console.error(err); + + process.exit(1); // Non-zero failure code + } +} + +startup(); + +async function shutdown(e) { + let err = e; + + console.log('Shutting down application'); + + try { + console.log('Closing web server module'); + + await webServer.close(); + } catch (e) { + console.error(e); + + err = err || e; + } + + try { + console.log('Closing database module'); + + await database.close(); + } catch (e) { + console.error(e); + + err = err || e; + } + + console.log('Exiting process'); + + if (err) { + process.exit(1); // Non-zero failure code + } else { + process.exit(0); + } +} + +process.on('SIGTERM', () => { + console.log('Received SIGTERM'); + + shutdown(); +}); + +process.on('SIGINT', () => { + console.log('Received SIGINT'); + + shutdown(); +}); + +process.on('uncaughtException', err => { + console.log('Uncaught exception'); + console.error(err); + + shutdown(err); +}); diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/package-lock.json b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/package-lock.json new file mode 100644 index 00000000..c2f35b4f --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/package-lock.json @@ -0,0 +1,392 @@ +{ + "name": "hr_app", + "version": "0.1.0", + "lockfileVersion": 1, + "requires": true, + "dependencies": { + "accepts": { + "version": "1.3.5", + "resolved": "https://registry.npmjs.org/accepts/-/accepts-1.3.5.tgz", + "integrity": "sha1-63d99gEXI6OxTopywIBcjoZ0a9I=", + "requires": { + "mime-types": "2.1.18", + "negotiator": "0.6.1" + } + }, + "array-flatten": { + "version": "1.1.1", + "resolved": "https://registry.npmjs.org/array-flatten/-/array-flatten-1.1.1.tgz", + "integrity": "sha1-ml9pkFGx5wczKPKgCJaLZOopVdI=" + }, + "basic-auth": { + "version": "2.0.0", + "resolved": "https://registry.npmjs.org/basic-auth/-/basic-auth-2.0.0.tgz", + "integrity": "sha1-AV2z81PgLlY3d1X5YnQuiYHnu7o=", + "requires": { + "safe-buffer": "5.1.1" + } + }, + "body-parser": { + "version": "1.18.2", + "resolved": "https://registry.npmjs.org/body-parser/-/body-parser-1.18.2.tgz", + "integrity": "sha1-h2eKGdhLR9hZuDGZvVm84iKxBFQ=", + "requires": { + "bytes": "3.0.0", + "content-type": "1.0.4", + "debug": "2.6.9", + "depd": "1.1.2", + "http-errors": "1.6.2", + "iconv-lite": "0.4.19", + "on-finished": "2.3.0", + "qs": "6.5.1", + "raw-body": "2.3.2", + "type-is": "1.6.16" + } + }, + "bytes": { + "version": "3.0.0", + "resolved": "https://registry.npmjs.org/bytes/-/bytes-3.0.0.tgz", + "integrity": "sha1-0ygVQE1olpn4Wk6k+odV3ROpYEg=" + }, + "content-disposition": { + "version": "0.5.2", + "resolved": "https://registry.npmjs.org/content-disposition/-/content-disposition-0.5.2.tgz", + "integrity": "sha1-DPaLud318r55YcOoUXjLhdunjLQ=" + }, + "content-type": { + "version": "1.0.4", + "resolved": "https://registry.npmjs.org/content-type/-/content-type-1.0.4.tgz", + "integrity": "sha512-hIP3EEPs8tB9AT1L+NUqtwOAps4mk2Zob89MWXMHjHWg9milF/j4osnnQLXBCBFBk/tvIG/tUc9mOUJiPBhPXA==" + }, + "cookie": { + "version": "0.3.1", + "resolved": "https://registry.npmjs.org/cookie/-/cookie-0.3.1.tgz", + "integrity": "sha1-5+Ch+e9DtMi6klxcWpboBtFoc7s=" + }, + "cookie-signature": { + "version": "1.0.6", + "resolved": "https://registry.npmjs.org/cookie-signature/-/cookie-signature-1.0.6.tgz", + "integrity": "sha1-4wOogrNCzD7oylE6eZmXNNqzriw=" + }, + "debug": { + "version": "2.6.9", + "resolved": "https://registry.npmjs.org/debug/-/debug-2.6.9.tgz", + "integrity": "sha512-bC7ElrdJaJnPbAP+1EotYvqZsb3ecl5wi6Bfi6BJTUcNowp6cvspg0jXznRTKDjm/E7AdgFBVeAPVMNcKGsHMA==", + "requires": { + "ms": "2.0.0" + } + }, + "depd": { + "version": "1.1.2", + "resolved": "https://registry.npmjs.org/depd/-/depd-1.1.2.tgz", + "integrity": "sha1-m81S4UwJd2PnSbJ0xDRu0uVgtak=" + }, + "destroy": { + "version": "1.0.4", + "resolved": "https://registry.npmjs.org/destroy/-/destroy-1.0.4.tgz", + "integrity": "sha1-l4hXRCxEdJ5CBmE+N5RiBYJqvYA=" + }, + "ee-first": { + "version": "1.1.1", + "resolved": "https://registry.npmjs.org/ee-first/-/ee-first-1.1.1.tgz", + "integrity": "sha1-WQxhFWsK4vTwJVcyoViyZrxWsh0=" + }, + "encodeurl": { + "version": "1.0.2", + "resolved": "https://registry.npmjs.org/encodeurl/-/encodeurl-1.0.2.tgz", + "integrity": "sha1-rT/0yG7C0CkyL1oCw6mmBslbP1k=" + }, + "escape-html": { + "version": "1.0.3", + "resolved": "https://registry.npmjs.org/escape-html/-/escape-html-1.0.3.tgz", + "integrity": "sha1-Aljq5NPQwJdN4cFpGI7wBR0dGYg=" + }, + "etag": { + "version": "1.8.1", + "resolved": "https://registry.npmjs.org/etag/-/etag-1.8.1.tgz", + "integrity": "sha1-Qa4u62XvpiJorr/qg6x9eSmbCIc=" + }, + "express": { + "version": "4.16.3", + "resolved": "https://registry.npmjs.org/express/-/express-4.16.3.tgz", + "integrity": "sha1-avilAjUNsyRuzEvs9rWjTSL37VM=", + "requires": { + "accepts": "1.3.5", + "array-flatten": "1.1.1", + "body-parser": "1.18.2", + "content-disposition": "0.5.2", + "content-type": "1.0.4", + "cookie": "0.3.1", + "cookie-signature": "1.0.6", + "debug": "2.6.9", + "depd": "1.1.2", + "encodeurl": "1.0.2", + "escape-html": "1.0.3", + "etag": "1.8.1", + "finalhandler": "1.1.1", + "fresh": "0.5.2", + "merge-descriptors": "1.0.1", + "methods": "1.1.2", + "on-finished": "2.3.0", + "parseurl": "1.3.2", + "path-to-regexp": "0.1.7", + "proxy-addr": "2.0.3", + "qs": "6.5.1", + "range-parser": "1.2.0", + "safe-buffer": "5.1.1", + "send": "0.16.2", + "serve-static": "1.13.2", + "setprototypeof": "1.1.0", + "statuses": "1.4.0", + "type-is": "1.6.16", + "utils-merge": "1.0.1", + "vary": "1.1.2" + } + }, + "finalhandler": { + "version": "1.1.1", + "resolved": "https://registry.npmjs.org/finalhandler/-/finalhandler-1.1.1.tgz", + "integrity": "sha512-Y1GUDo39ez4aHAw7MysnUD5JzYX+WaIj8I57kO3aEPT1fFRL4sr7mjei97FgnwhAyyzRYmQZaTHb2+9uZ1dPtg==", + "requires": { + "debug": "2.6.9", + "encodeurl": "1.0.2", + "escape-html": "1.0.3", + "on-finished": "2.3.0", + "parseurl": "1.3.2", + "statuses": "1.4.0", + "unpipe": "1.0.0" + } + }, + "forwarded": { + "version": "0.1.2", + "resolved": "https://registry.npmjs.org/forwarded/-/forwarded-0.1.2.tgz", + "integrity": "sha1-mMI9qxF1ZXuMBXPozszZGw/xjIQ=" + }, + "fresh": { + "version": "0.5.2", + "resolved": "https://registry.npmjs.org/fresh/-/fresh-0.5.2.tgz", + "integrity": "sha1-PYyt2Q2XZWn6g1qx+OSyOhBWBac=" + }, + "http-errors": { + "version": "1.6.2", + "resolved": "https://registry.npmjs.org/http-errors/-/http-errors-1.6.2.tgz", + "integrity": "sha1-CgAsyFcHGSp+eUbO7cERVfYOxzY=", + "requires": { + "depd": "1.1.1", + "inherits": "2.0.3", + "setprototypeof": "1.0.3", + "statuses": "1.4.0" + }, + "dependencies": { + "depd": { + "version": "1.1.1", + "resolved": "https://registry.npmjs.org/depd/-/depd-1.1.1.tgz", + "integrity": "sha1-V4O04cRZ8G+lyif5kfPQbnoxA1k=" + }, + "setprototypeof": { + "version": "1.0.3", + "resolved": "https://registry.npmjs.org/setprototypeof/-/setprototypeof-1.0.3.tgz", + "integrity": "sha1-ZlZ+NwQ+608E2RvWWMDL77VbjgQ=" + } + } + }, + "iconv-lite": { + "version": "0.4.19", + "resolved": "https://registry.npmjs.org/iconv-lite/-/iconv-lite-0.4.19.tgz", + "integrity": "sha512-oTZqweIP51xaGPI4uPa56/Pri/480R+mo7SeU+YETByQNhDG55ycFyNLIgta9vXhILrxXDmF7ZGhqZIcuN0gJQ==" + }, + "inherits": { + "version": "2.0.3", + "resolved": "https://registry.npmjs.org/inherits/-/inherits-2.0.3.tgz", + "integrity": "sha1-Yzwsg+PaQqUC9SRmAiSA9CCCYd4=" + }, + "ipaddr.js": { + "version": "1.6.0", + "resolved": "https://registry.npmjs.org/ipaddr.js/-/ipaddr.js-1.6.0.tgz", + "integrity": "sha1-4/o1e3c9phnybpXwSdBVxyeW+Gs=" + }, + "media-typer": { + "version": "0.3.0", + "resolved": "https://registry.npmjs.org/media-typer/-/media-typer-0.3.0.tgz", + "integrity": "sha1-hxDXrwqmJvj/+hzgAWhUUmMlV0g=" + }, + "merge-descriptors": { + "version": "1.0.1", + "resolved": "https://registry.npmjs.org/merge-descriptors/-/merge-descriptors-1.0.1.tgz", + "integrity": "sha1-sAqqVW3YtEVoFQ7J0blT8/kMu2E=" + }, + "methods": { + "version": "1.1.2", + "resolved": "https://registry.npmjs.org/methods/-/methods-1.1.2.tgz", + "integrity": "sha1-VSmk1nZUE07cxSZmVoNbD4Ua/O4=" + }, + "mime": { + "version": "1.4.1", + "resolved": "https://registry.npmjs.org/mime/-/mime-1.4.1.tgz", + "integrity": "sha512-KI1+qOZu5DcW6wayYHSzR/tXKCDC5Om4s1z2QJjDULzLcmf3DvzS7oluY4HCTrc+9FiKmWUgeNLg7W3uIQvxtQ==" + }, + "mime-db": { + "version": "1.33.0", + "resolved": "https://registry.npmjs.org/mime-db/-/mime-db-1.33.0.tgz", + "integrity": "sha512-BHJ/EKruNIqJf/QahvxwQZXKygOQ256myeN/Ew+THcAa5q+PjyTTMMeNQC4DZw5AwfvelsUrA6B67NKMqXDbzQ==" + }, + "mime-types": { + "version": "2.1.18", + "resolved": "https://registry.npmjs.org/mime-types/-/mime-types-2.1.18.tgz", + "integrity": "sha512-lc/aahn+t4/SWV/qcmumYjymLsWfN3ELhpmVuUFjgsORruuZPVSwAQryq+HHGvO/SI2KVX26bx+En+zhM8g8hQ==", + "requires": { + "mime-db": "1.33.0" + } + }, + "morgan": { + "version": "1.9.0", + "resolved": "https://registry.npmjs.org/morgan/-/morgan-1.9.0.tgz", + "integrity": "sha1-0B+mxlhZt2/PMbPLU6OCGjEdgFE=", + "requires": { + "basic-auth": "2.0.0", + "debug": "2.6.9", + "depd": "1.1.2", + "on-finished": "2.3.0", + "on-headers": "1.0.1" + } + }, + "ms": { + "version": "2.0.0", + "resolved": "https://registry.npmjs.org/ms/-/ms-2.0.0.tgz", + "integrity": "sha1-VgiurfwAvmwpAd9fmGF4jeDVl8g=" + }, + "negotiator": { + "version": "0.6.1", + "resolved": "https://registry.npmjs.org/negotiator/-/negotiator-0.6.1.tgz", + "integrity": "sha1-KzJxhOiZIQEXeyhWP7XnECrNDKk=" + }, + "on-finished": { + "version": "2.3.0", + "resolved": "https://registry.npmjs.org/on-finished/-/on-finished-2.3.0.tgz", + "integrity": "sha1-IPEzZIGwg811M3mSoWlxqi2QaUc=", + "requires": { + "ee-first": "1.1.1" + } + }, + "on-headers": { + "version": "1.0.1", + "resolved": "https://registry.npmjs.org/on-headers/-/on-headers-1.0.1.tgz", + "integrity": "sha1-ko9dD0cNSTQmUepnlLCFfBAGk/c=" + }, + "oracledb": { + "version": "2.2.0", + "resolved": "https://registry.npmjs.org/oracledb/-/oracledb-2.2.0.tgz", + "integrity": "sha512-ywwalyryeJYb5dr1JScyPcNxCeN0zExrKLtorSdptBZqhfS5Dp9KLgGOExc+XMMfEejXGtC/RfiDxKaGn6+VJA==" + }, + "parseurl": { + "version": "1.3.2", + "resolved": "https://registry.npmjs.org/parseurl/-/parseurl-1.3.2.tgz", + "integrity": "sha1-/CidTtiZMRlGDBViUyYs3I3mW/M=" + }, + "path-to-regexp": { + "version": "0.1.7", + "resolved": "https://registry.npmjs.org/path-to-regexp/-/path-to-regexp-0.1.7.tgz", + "integrity": "sha1-32BBeABfUi8V60SQ5yR6G/qmf4w=" + }, + "proxy-addr": { + "version": "2.0.3", + "resolved": "https://registry.npmjs.org/proxy-addr/-/proxy-addr-2.0.3.tgz", + "integrity": "sha512-jQTChiCJteusULxjBp8+jftSQE5Obdl3k4cnmLA6WXtK6XFuWRnvVL7aCiBqaLPM8c4ph0S4tKna8XvmIwEnXQ==", + "requires": { + "forwarded": "0.1.2", + "ipaddr.js": "1.6.0" + } + }, + "qs": { + "version": "6.5.1", + "resolved": "https://registry.npmjs.org/qs/-/qs-6.5.1.tgz", + "integrity": "sha512-eRzhrN1WSINYCDCbrz796z37LOe3m5tmW7RQf6oBntukAG1nmovJvhnwHHRMAfeoItc1m2Hk02WER2aQ/iqs+A==" + }, + "range-parser": { + "version": "1.2.0", + "resolved": "https://registry.npmjs.org/range-parser/-/range-parser-1.2.0.tgz", + "integrity": "sha1-9JvmtIeJTdxA3MlKMi9hEJLgDV4=" + }, + "raw-body": { + "version": "2.3.2", + "resolved": "https://registry.npmjs.org/raw-body/-/raw-body-2.3.2.tgz", + "integrity": "sha1-vNYMd9Prk83gBQKVw/N5OJvIj4k=", + "requires": { + "bytes": "3.0.0", + "http-errors": "1.6.2", + "iconv-lite": "0.4.19", + "unpipe": "1.0.0" + } + }, + "safe-buffer": { + "version": "5.1.1", + "resolved": "https://registry.npmjs.org/safe-buffer/-/safe-buffer-5.1.1.tgz", + "integrity": "sha512-kKvNJn6Mm93gAczWVJg7wH+wGYWNrDHdWvpUmHyEsgCtIwwo3bqPtV4tR5tuPaUhTOo/kvhVwd8XwwOllGYkbg==" + }, + "send": { + "version": "0.16.2", + "resolved": "https://registry.npmjs.org/send/-/send-0.16.2.tgz", + "integrity": "sha512-E64YFPUssFHEFBvpbbjr44NCLtI1AohxQ8ZSiJjQLskAdKuriYEP6VyGEsRDH8ScozGpkaX1BGvhanqCwkcEZw==", + "requires": { + "debug": "2.6.9", + "depd": "1.1.2", + "destroy": "1.0.4", + "encodeurl": "1.0.2", + "escape-html": "1.0.3", + "etag": "1.8.1", + "fresh": "0.5.2", + "http-errors": "1.6.2", + "mime": "1.4.1", + "ms": "2.0.0", + "on-finished": "2.3.0", + "range-parser": "1.2.0", + "statuses": "1.4.0" + } + }, + "serve-static": { + "version": "1.13.2", + "resolved": "https://registry.npmjs.org/serve-static/-/serve-static-1.13.2.tgz", + "integrity": "sha512-p/tdJrO4U387R9oMjb1oj7qSMaMfmOyd4j9hOFoxZe2baQszgHcSWjuya/CiT5kgZZKRudHNOA0pYXOl8rQ5nw==", + "requires": { + "encodeurl": "1.0.2", + "escape-html": "1.0.3", + "parseurl": "1.3.2", + "send": "0.16.2" + } + }, + "setprototypeof": { + "version": "1.1.0", + "resolved": "https://registry.npmjs.org/setprototypeof/-/setprototypeof-1.1.0.tgz", + "integrity": "sha512-BvE/TwpZX4FXExxOxZyRGQQv651MSwmWKZGqvmPcRIjDqWub67kTKuIMx43cZZrS/cBBzwBcNDWoFxt2XEFIpQ==" + }, + "statuses": { + "version": "1.4.0", + "resolved": "https://registry.npmjs.org/statuses/-/statuses-1.4.0.tgz", + "integrity": "sha512-zhSCtt8v2NDrRlPQpCNtw/heZLtfUDqxBM1udqikb/Hbk52LK4nQSwr10u77iopCW5LsyHpuXS0GnEc48mLeew==" + }, + "type-is": { + "version": "1.6.16", + "resolved": "https://registry.npmjs.org/type-is/-/type-is-1.6.16.tgz", + "integrity": "sha512-HRkVv/5qY2G6I8iab9cI7v1bOIdhm94dVjQCPFElW9W+3GeDOSHmy2EBYe4VTApuzolPcmgFTN3ftVJRKR2J9Q==", + "requires": { + "media-typer": "0.3.0", + "mime-types": "2.1.18" + } + }, + "unpipe": { + "version": "1.0.0", + "resolved": "https://registry.npmjs.org/unpipe/-/unpipe-1.0.0.tgz", + "integrity": "sha1-sr9O6FFKrmFltIF4KdIbLvSZBOw=" + }, + "utils-merge": { + "version": "1.0.1", + "resolved": "https://registry.npmjs.org/utils-merge/-/utils-merge-1.0.1.tgz", + "integrity": "sha1-n5VxD1CiZ5R7LMwSR0HBAoQn5xM=" + }, + "vary": { + "version": "1.1.2", + "resolved": "https://registry.npmjs.org/vary/-/vary-1.1.2.tgz", + "integrity": "sha1-IpnwLG3tMNSllhsLn3RSShj2NPw=" + } + } +} diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/package.json b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/package.json new file mode 100644 index 00000000..44dc8bc0 --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/package.json @@ -0,0 +1,16 @@ +{ + "name": "hr_app", + "version": "0.1.0", + "description": "Creating a REST API with Node.js and Oracle Database", + "main": "index.js", + "scripts": { + "test": "echo \"Error: no test specified\" && exit 1" + }, + "keywords": [], + "license": "Apache-2.0", + "dependencies": { + "express": "^4.16.3", + "morgan": "^1.9.0", + "oracledb": "^2.2.0" + } +} diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/database.js b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/database.js new file mode 100644 index 00000000..d7cb8e0a --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/database.js @@ -0,0 +1,43 @@ +const oracledb = require('oracledb'); +const dbConfig = require('../config/database.js'); + +async function initialize() { + await oracledb.createPool(dbConfig.hrPool); +} + +module.exports.initialize = initialize; + +async function close() { + await oracledb.getPool().close(); +} + +module.exports.close = close; + +function simpleExecute(statement, binds = [], opts = {}) { + return new Promise(async (resolve, reject) => { + let conn; + + opts.outFormat = oracledb.OBJECT; + opts.autoCommit = true; + + try { + conn = await oracledb.getConnection(); + + const result = await conn.execute(statement, binds, opts); + + resolve(result); + } catch (err) { + reject(err); + } finally { + if (conn) { // conn assignment worked, need to close + try { + await conn.close(); + } catch (err) { + console.log(err); + } + } + } + }); +} + +module.exports.simpleExecute = simpleExecute; diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/router.js b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/router.js new file mode 100644 index 00000000..e3d9011f --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/router.js @@ -0,0 +1,11 @@ +const express = require('express'); +const router = new express.Router(); +const employees = require('../controllers/employees.js'); + +router.route('/employees/:id?') + .get(employees.get) + .post(employees.post) + .put(employees.put) + .delete(employees.delete); + +module.exports = router; diff --git a/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/web-server.js b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/web-server.js new file mode 100644 index 00000000..c509b646 --- /dev/null +++ b/javascript/rest-api/part-4-handling-post-put-and-delete-requests/hr_app/services/web-server.js @@ -0,0 +1,64 @@ +const http = require('http'); +const express = require('express'); +const morgan = require('morgan'); +const webServerConfig = require('../config/web-server.js'); +const router = require('./router.js'); + +let httpServer; + +function initialize() { + return new Promise((resolve, reject) => { + const app = express(); + httpServer = http.createServer(app); + + // Combines logging info from request and response + app.use(morgan('combined')); + + // Parse incoming JSON requests and revive JSON. + app.use(express.json({ + reviver: reviveJson + })); + + // Mount the router at /api so all its routes start with /api + app.use('/api', router); + + httpServer.listen(webServerConfig.port, err => { + if (err) { + reject(err); + return; + } + + console.log(`Web server listening on localhost:${webServerConfig.port}`); + + resolve(); + }); + }); +} + +module.exports.initialize = initialize; + +function close() { + return new Promise((resolve, reject) => { + httpServer.close((err) => { + if (err) { + reject(err); + return; + } + + resolve(); + }); + }); +} + +module.exports.close = close; + +const iso8601RegExp = /^\d{4}-\d{2}-\d{2}T\d{2}:\d{2}:\d{2}(\.\d{3})?Z$/; + +function reviveJson(key, value) { + // revive ISO 8601 date strings to instances of Date + if (typeof value === 'string' && iso8601RegExp.test(value)) { + return new Date(value); + } else { + return value; + } +} diff --git a/optimizer/autonomous/README.md b/optimizer/autonomous/README.md new file mode 100644 index 00000000..dfeabb88 --- /dev/null +++ b/optimizer/autonomous/README.md @@ -0,0 +1,11 @@ +This directory contains examples dedicated the topic of the autonomous Oracle Optimizer. + +Unless otherwise stated, I used SQLCL to connect to the cloud database as follows: + +
+$ sql /nolog
+SQL> set cloudconfig wallet_file.zip
+SQL> connect adwcu1/password@dbname_high
+
+ +The directory *stats_on_load* contains a demonstration of how statistics are maintained for direct path INSERT, even if the target table contains rows. diff --git a/optimizer/autonomous/hints/README.md b/optimizer/autonomous/hints/README.md new file mode 100644 index 00000000..02ae129f --- /dev/null +++ b/optimizer/autonomous/hints/README.md @@ -0,0 +1,21 @@ +This example demonstrates hint usage in ADWC. + +Create a test user using the *user.sql* script. + +To run the entire example, log in ADWC using the LOW consumer group and then: + +* @tabs - Create test tables (note that it drops tables TABLE1 and TABLE2) +* @q1 - The default query plan +* @q2 - The query includes hints that are not obeyed +* @q3 - The ALTER SESSION allows the optimizer to use hints + +### DISCLAIMER + +* These scripts are provided for educational purposes only. +* They are NOT supported by Oracle World Wide Technical Support. +* The scripts have been tested and they appear to work as intended. +* You should always run scripts on a test instance. + +### WARNING + +* These scripts drop and create tables. For use on test databases. diff --git a/optimizer/autonomous/hints/plan.sql b/optimizer/autonomous/hints/plan.sql new file mode 100644 index 00000000..cf6b7294 --- /dev/null +++ b/optimizer/autonomous/hints/plan.sql @@ -0,0 +1,9 @@ +set trims on +set linesize 200 +set tab off +set pagesize 1000 +column plan_table_output format a180 + +SELECT * +FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'TYPICAL')); + diff --git a/optimizer/autonomous/hints/q1.lst b/optimizer/autonomous/hints/q1.lst new file mode 100644 index 00000000..21c9d22e --- /dev/null +++ b/optimizer/autonomous/hints/q1.lst @@ -0,0 +1,60 @@ +SQL> @q1 +SQL> select sum(t1.num), sum(t2.num) + 2 from table1 t1 + 3 join table2 t2 on (t1.id = t2.id); + +SUM(T1.NUM) SUM(T2.NUM) +----------- ----------- + 1 10 + +SQL> +SQL> @plan +SQL> set trims on +SQL> set linesize 200 +SQL> set tab off +SQL> set pagesize 1000 +SQL> column plan_table_output format a180 +SQL> +SQL> SELECT * + 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'TYPICAL')); + +PLAN_TABLE_OUTPUT +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ +SQL_ID 60t3bw2rtn35d, child number 6 +------------------------------------- +select sum(t1.num), sum(t2.num) from table1 t1 join table2 t2 on +(t1.id = t2.id) + +Plan hash value: 339338377 + +--------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | +--------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 4 (100)| | +| 1 | RESULT CACHE | db11srrdf8ar4d06x4b1j674pp | | | | | +| 2 | SORT AGGREGATE | | 1 | 52 | | | +|* 3 | HASH JOIN | | 1 | 52 | 4 (0)| 00:00:01 | +| 4 | TABLE ACCESS FULL| TABLE2 | 1 | 26 | 2 (0)| 00:00:01 | +| 5 | TABLE ACCESS FULL| TABLE1 | 1000 | 26000 | 2 (0)| 00:00:01 | +--------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 3 - access("T1"."ID"="T2"."ID") + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - dynamic statistics used: dynamic sampling (level=2) + - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation + + +33 rows selected. + +SQL> +SQL> spool off diff --git a/optimizer/autonomous/hints/q1.sql b/optimizer/autonomous/hints/q1.sql new file mode 100644 index 00000000..b82fd3d2 --- /dev/null +++ b/optimizer/autonomous/hints/q1.sql @@ -0,0 +1,5 @@ +select sum(t1.num), sum(t2.num) +from table1 t1 +join table2 t2 on (t1.id = t2.id); + +@plan diff --git a/optimizer/autonomous/hints/q2.lst b/optimizer/autonomous/hints/q2.lst new file mode 100644 index 00000000..899ffe70 --- /dev/null +++ b/optimizer/autonomous/hints/q2.lst @@ -0,0 +1,61 @@ +SQL> @q2 +SQL> select /*+ LEADING(t1 t2) USE_NL(t2) */ + 2 sum(t1.num), sum(t2.num) + 3 from table1 t1 + 4 join table2 t2 on (t1.id = t2.id); + +SUM(T1.NUM) SUM(T2.NUM) +----------- ----------- + 1 10 + +SQL> +SQL> @plan +SQL> set trims on +SQL> set linesize 200 +SQL> set tab off +SQL> set pagesize 1000 +SQL> column plan_table_output format a180 +SQL> +SQL> SELECT * + 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'TYPICAL')); + +PLAN_TABLE_OUTPUT +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ +SQL_ID 1c899cktncv5m, child number 0 +------------------------------------- +select /*+ LEADING(t1 t2) USE_NL(t2) */ sum(t1.num), sum(t2.num) +from table1 t1 join table2 t2 on (t1.id = t2.id) + +Plan hash value: 339338377 + +--------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | +--------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 4 (100)| | +| 1 | RESULT CACHE | db11srrdf8ar4d06x4b1j674pp | | | | | +| 2 | SORT AGGREGATE | | 1 | 52 | | | +|* 3 | HASH JOIN | | 1 | 52 | 4 (0)| 00:00:01 | +| 4 | TABLE ACCESS FULL| TABLE2 | 1 | 26 | 2 (0)| 00:00:01 | +| 5 | TABLE ACCESS FULL| TABLE1 | 1000 | 26000 | 2 (0)| 00:00:01 | +--------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 3 - access("T1"."ID"="T2"."ID") + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - dynamic statistics used: dynamic sampling (level=2) + - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation + + +33 rows selected. + +SQL> +SQL> spool off diff --git a/optimizer/autonomous/hints/q2.sql b/optimizer/autonomous/hints/q2.sql new file mode 100644 index 00000000..fe3334a9 --- /dev/null +++ b/optimizer/autonomous/hints/q2.sql @@ -0,0 +1,6 @@ +select /*+ LEADING(t1 t2) USE_NL(t2) */ + sum(t1.num), sum(t2.num) +from table1 t1 +join table2 t2 on (t1.id = t2.id); + +@plan diff --git a/optimizer/autonomous/hints/q3.lst b/optimizer/autonomous/hints/q3.lst new file mode 100644 index 00000000..69d0bed6 --- /dev/null +++ b/optimizer/autonomous/hints/q3.lst @@ -0,0 +1,71 @@ +SQL> @q3 +SQL> alter session set optimizer_ignore_hints = false; + +Session altered. + +SQL> +SQL> select /*+ LEADING(t1 t2) USE_NL(t2) */ + 2 sum(t1.num), sum(t2.num) + 3 from table1 t1 + 4 join table2 t2 on (t1.id = t2.id); + +SUM(T1.NUM) SUM(T2.NUM) +----------- ----------- + 1 10 + +SQL> +SQL> @plan +SQL> set trims on +SQL> set linesize 200 +SQL> set tab off +SQL> set pagesize 1000 +SQL> column plan_table_output format a180 +SQL> +SQL> SELECT * + 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'TYPICAL')); + +PLAN_TABLE_OUTPUT +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ +SQL_ID 1jvgvrv93ma6h, child number 2 +------------------------------------- +select /*+ LEADING(t1 t2) USE_NL(t2) */ sum(t1.num), +sum(t2.num) from table1 t1 join table2 t2 on (t1.id = t2.id) + +Plan hash value: 3862413962 + +--------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | +--------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 73 (100)| | +| 1 | RESULT CACHE | db11srrdf8ar4d06x4b1j674pp | | | | | +| 2 | SORT AGGREGATE | | 1 | 52 | | | +| 3 | NESTED LOOPS | | 1 | 52 | 73 (3)| 00:00:01 | +| 4 | TABLE ACCESS FULL| TABLE1 | 1000 | 26000 | 2 (0)| 00:00:01 | +|* 5 | TABLE ACCESS FULL| TABLE2 | 1 | 26 | 0 (0)| | +--------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 5 - filter("T1"."ID"="T2"."ID") + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - dynamic statistics used: dynamic sampling (level=2) + - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation + + +33 rows selected. + +SQL> +SQL> +SQL> alter session set optimizer_ignore_hints = true; + +Session altered. + +SQL> spool off diff --git a/optimizer/autonomous/hints/q3.sql b/optimizer/autonomous/hints/q3.sql new file mode 100644 index 00000000..17ccd0f4 --- /dev/null +++ b/optimizer/autonomous/hints/q3.sql @@ -0,0 +1,10 @@ +alter session set optimizer_ignore_hints = false; + +select /*+ LEADING(t1 t2) USE_NL(t2) */ + sum(t1.num), sum(t2.num) +from table1 t1 +join table2 t2 on (t1.id = t2.id); + +@plan + +alter session set optimizer_ignore_hints = true; diff --git a/optimizer/autonomous/hints/tabs.sql b/optimizer/autonomous/hints/tabs.sql new file mode 100644 index 00000000..1e862271 --- /dev/null +++ b/optimizer/autonomous/hints/tabs.sql @@ -0,0 +1,37 @@ +begin + execute immediate 'drop table table2 purge'; +exception + when others then + if sqlcode != -942 then + raise; + end if; +end; +/ + +begin + execute immediate 'drop table table1 purge'; +exception + when others then + if sqlcode != -942 then + raise; + end if; +end; +/ + +create table table1 (id number(10) primary key, num number(10), txt varchar2(50)); + +create table table2 (id number(10) primary key, t1id number(10), num number(10), txt varchar2(50), + constraint t1fk foreign key (t1id) references table1 (id)); + +begin + for i in 1..1000 + loop + insert into table1 values (i,i,'TABLE 1 '||i); + end loop; +end; +/ + +insert into table2 values (1,1,10,'TABLE 2'); + +commit; + diff --git a/optimizer/autonomous/hints/user.sql b/optimizer/autonomous/hints/user.sql new file mode 100644 index 00000000..cc262f84 --- /dev/null +++ b/optimizer/autonomous/hints/user.sql @@ -0,0 +1,13 @@ +-- +-- Log into admin account and create a test user as follows +-- +create user adwu1 identified by "choose your password"; + +grant ALTER SESSION to adwu1; +grant CREATE TABLE to adwu1; +grant CREATE VIEW to adwu1; +grant CREATE SESSION to adwu1; +-- +grant select on v$session to adwu1; +grant select on v$sql_plan to adwu1; +grant select on v$sql to adwu1; diff --git a/optimizer/autonomous/stats_answering/README.md b/optimizer/autonomous/stats_answering/README.md new file mode 100644 index 00000000..b1705309 --- /dev/null +++ b/optimizer/autonomous/stats_answering/README.md @@ -0,0 +1,20 @@ +This example demonstrates the Statistics-Base Query Transformation - how optimizer statistics can be used to answer certain queries. + +Create a test user using the *user.sql* script. + +Run the enture example using the *example.sql* script. + +See an example of expected output in *example.lst*. + +Note that the performance characteristics of the queries will change if the *test_stats.sql* is executed more than once (depending on the server result cache, cursor cache and DML used on the fact table). Re-running the *make_fact.sql* will reset the test and yield the expected results. + +### DISCLAIMER + +* These scripts are provided for educational purposes only. +* They are NOT supported by Oracle World Wide Technical Support. +* The scripts have been tested and they appear to work as intended. +* You should always run scripts on a test instance. + +### WARNING + +* These scripts drop and create tables. For use on test databases. diff --git a/optimizer/autonomous/stats_answering/example.lst b/optimizer/autonomous/stats_answering/example.lst new file mode 100644 index 00000000..c4f80c1e --- /dev/null +++ b/optimizer/autonomous/stats_answering/example.lst @@ -0,0 +1,1063 @@ +SQL> +SQL> @make_dim +SQL> REM +SQL> REM Small DIM table +SQL> REM +SQL> set timing on +SQL> set linesize 250 +SQL> set tab off +SQL> set trims on +SQL> set echo on +SQL> +SQL> drop table dim1 purge; + +Error starting at line : 10 File @ /u01/npb/Features/GIT2/oracle-db-examples/optimizer/autonomous/stats_answering/make_dim.sql +In command - +drop table dim1 purge +Error report - +ORA-00942: table or view does not exist + +Elapsed: 00:00:00.231 +SQL> +SQL> create table dim1 (dnum number(10)); + +Table DIM1 created. + +Elapsed: 00:00:00.094 +SQL> +SQL> insert into dim1 values (13); + +1 row inserted. + +Elapsed: 00:00:00.161 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.086 +SQL> exec dbms_stats.gather_table_stats(user,'dim1'); + +PL/SQL procedure successfully completed. + +Elapsed: 00:00:01.375 +Elapsed: 00:00:01.375 +SQL> @make_fact +SQL> REM +SQL> REM Fact table for demo statistics query answering +SQL> REM +SQL> set timing on +SQL> set linesize 250 +SQL> set tab off +SQL> set trims on +SQL> set echo on +SQL> +SQL> drop table fact1 purge; + +Error starting at line : 10 File @ /u01/npb/Features/GIT2/oracle-db-examples/optimizer/autonomous/stats_answering/make_fact.sql +In command - +drop table fact1 purge +Error report - +ORA-00942: table or view does not exist + +Elapsed: 00:00:00.178 +SQL> drop table fact1_source purge; + +Table FACT1_SOURCE dropped. + +Elapsed: 00:00:00.163 +SQL> +SQL> -- +SQL> -- In this case we are using VARCHAR2(20) +SQL> -- We have to keep the column under 64 bytes +SQL> -- to answer aggregate queries on this column +SQL> -- using stats. +SQL> -- +SQL> create table fact1 (num0 number(10), num1 number(10), txt1 varchar2(20), txt2 varchar2(100), dt1 date); + +Table FACT1 created. + +Elapsed: 00:00:00.094 +SQL> +SQL> create table fact1_source as + 2 select * from fact1 where 1=-1; + +Table FACT1_SOURCE created. + +Elapsed: 00:00:00.108 +SQL> +SQL> insert /*+ APPEND */ into fact1_source + 2 select rownum,mod(rownum,10),'XXX'||rownum,'XXX'||rownum,sysdate-rownum + 3 from dual connect by rownum <= 10000; + +10,000 rows inserted. + +Elapsed: 00:00:00.398 +SQL> +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.089 +SQL> +SQL> -- +SQL> -- Insert rows into FACT1 +SQL> -- +SQL> insert /*+ APPEND */ into fact1 select num0,0,txt1,txt2,dt1 from fact1_source; + +10,000 rows inserted. + +Elapsed: 00:00:00.637 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.090 +SQL> +SQL> -- +SQL> -- Let's speed up row generation... +SQL> -- +SQL> set autocommit on +SQL> insert /*+ APPEND */ into fact1 select num0,1,txt1,txt2,dt1 from fact1; + +10,000 rows inserted. + +Commit complete. +Elapsed: 00:00:00.720 +SQL> insert /*+ APPEND */ into fact1 select num0,2,txt1,txt2,dt1 from fact1; + +20,000 rows inserted. + +Commit complete. +Elapsed: 00:00:00.729 +SQL> insert /*+ APPEND */ into fact1 select num0,3,txt1,txt2,dt1 from fact1; + +40,000 rows inserted. + +Commit complete. +Elapsed: 00:00:00.940 +SQL> insert /*+ APPEND */ into fact1 select num0,4,txt1,txt2,dt1 from fact1; + +80,000 rows inserted. + +Commit complete. +Elapsed: 00:00:00.982 +SQL> insert /*+ APPEND */ into fact1 select num0,5,txt1,txt2,dt1 from fact1; + +160,000 rows inserted. + +Commit complete. +Elapsed: 00:00:01.168 +SQL> insert /*+ APPEND */ into fact1 select num0,6,txt1,txt2,dt1 from fact1; + +320,000 rows inserted. + +Commit complete. +Elapsed: 00:00:01.232 +SQL> insert /*+ APPEND */ into fact1 select num0,7,txt1,txt2,dt1 from fact1; + +640,000 rows inserted. + +Commit complete. +Elapsed: 00:00:01.814 +SQL> insert /*+ APPEND */ into fact1 select num0,8,txt1,txt2,dt1 from fact1; + +1,280,000 rows inserted. + +Commit complete. +Elapsed: 00:00:03.075 +SQL> insert /*+ APPEND */ into fact1 select num0,9,txt1,txt2,dt1 from fact1; + +2,560,000 rows inserted. + +Commit complete. +Elapsed: 00:00:05.286 +SQL> insert /*+ APPEND */ into fact1 select num0,10,txt1,txt2,dt1 from fact1; + +5,120,000 rows inserted. + +Commit complete. +Elapsed: 00:00:09.954 +SQL> insert /*+ APPEND */ into fact1 select num0,11,txt1,txt2,dt1 from fact1; + +10,240,000 rows inserted. + +Commit complete. +Elapsed: 00:00:18.394 +SQL> insert /*+ APPEND */ into fact1 select num0,12,txt1,txt2,dt1 from fact1; + +20,480,000 rows inserted. + +Commit complete. +Elapsed: 00:00:36.210 +SQL> insert /*+ APPEND */ into fact1 select num0,13,txt1,txt2,dt1 from fact1; + +40,960,000 rows inserted. + +Commit complete. +Elapsed: 00:00:37.308 +SQL> set autocommit off +Elapsed: 00:00:37.310 +SQL> @test_stats +SQL> set echo on +SQL> set timing on +SQL> set linesize 250 +SQL> set trims on +SQL> column MAX(TXT1) format a30 +SQL> column MIN(TXT1) format a30 +SQL> column MAX(TXT2) format a30 +SQL> column MIN(TXT2) format a30 +SQL> +SQL> -- +SQL> -- The following queries use stats answering +SQL> -- +SQL> select max(num0),min(num1) from fact1; + + MAX(NUM0) MIN(NUM1) +---------- ---------- + 10000 0 + +Elapsed: 00:00:00.643 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 3x0hnv3a17a0u, child number 1 +------------------------------------- +select max(num0),min(num1) from fact1 + +Plan hash value: 2785769099 + +------------------------------------------------------------------------------------------------------------------------------------ +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +------------------------------------------------------------------------------------------------------------------------------------ +| 0 | SELECT STATEMENT | | | | 636 (100)| | | | | +| 1 | RESULT CACHE | 28rukjky1u2p2ga4jm528ra8fa | | | | | | | | +| 2 | VIEW | VW_SQT_65BBF4BE | 1 | 26 | 624 (76)| 00:00:01 | | | | +| 3 | SORT AGGREGATE | | 1 | 7 | | | | | | +| 4 | PX COORDINATOR | | | | | | | | | +| 5 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 7 | | | Q1,00 | P->S | QC (RAND) | +| 6 | SORT AGGREGATE | | 1 | 7 | | | Q1,00 | PCWP | | +| 7 | PX BLOCK ITERATOR | | 81M| 546M| 624 (76)| 00:00:01 | Q1,00 | PCWC | | +|* 8 | TABLE ACCESS FULL| FACT1 | 81M| 546M| 624 (76)| 00:00:01 | Q1,00 | PCWP | | +------------------------------------------------------------------------------------------------------------------------------------ + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 8 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 2 + + +34 rows selected. + +Elapsed: 00:00:00.193 +Elapsed: 00:00:00.193 +SQL> pause p... +p... + +SQL> +SQL> select max(num0),min(num1),min(txt1),max(txt1),count(*) from fact1; + + MAX(NUM0) MIN(NUM1) MIN(TXT1) MAX(TXT1) COUNT(*) +---------- ---------- ------------------------------ ------------------------------ ---------- + 10000 0 XXX1 XXX9999 81920000 + +Elapsed: 00:00:00.313 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 1zjjqqwsb9xtw, child number 1 +------------------------------------- +select max(num0),min(num1),min(txt1),max(txt1),count(*) from fact1 + +Plan hash value: 2785769099 + +------------------------------------------------------------------------------------------------------------------------------------ +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +------------------------------------------------------------------------------------------------------------------------------------ +| 0 | SELECT STATEMENT | | | | 702 (100)| | | | | +| 1 | RESULT CACHE | aygs0w5b8s8t29tj637h9wj779 | | | | | | | | +| 2 | VIEW | VW_SQT_65BBF4BE | 1 | 63 | 679 (78)| 00:00:01 | | | | +| 3 | SORT AGGREGATE | | 1 | 15 | | | | | | +| 4 | PX COORDINATOR | | | | | | | | | +| 5 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 15 | | | Q1,00 | P->S | QC (RAND) | +| 6 | SORT AGGREGATE | | 1 | 15 | | | Q1,00 | PCWP | | +| 7 | PX BLOCK ITERATOR | | 81M| 1171M| 679 (78)| 00:00:01 | Q1,00 | PCWC | | +|* 8 | TABLE ACCESS FULL| FACT1 | 81M| 1171M| 679 (78)| 00:00:01 | Q1,00 | PCWP | | +------------------------------------------------------------------------------------------------------------------------------------ + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 8 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 2 + + +34 rows selected. + +Elapsed: 00:00:00.180 +Elapsed: 00:00:00.180 +SQL> pause p... +p... + +SQL> +SQL> select max(txt1),min(txt1),count(txt1) from fact1; + +MAX(TXT1) MIN(TXT1) COUNT(TXT1) +------------------------------ ------------------------------ ----------- +XXX9999 XXX1 81920000 + +Elapsed: 00:00:00.274 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 76xvnad5mkgdf, child number 1 +------------------------------------- +select max(txt1),min(txt1),count(txt1) from fact1 + +Plan hash value: 2785769099 + +------------------------------------------------------------------------------------------------------------------------------------ +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +------------------------------------------------------------------------------------------------------------------------------------ +| 0 | SELECT STATEMENT | | | | 696 (100)| | | | | +| 1 | RESULT CACHE | 5ab938m617x17b385hyqg6uxx3 | | | | | | | | +| 2 | VIEW | VW_SQT_65BBF4BE | 1 | 37 | 679 (78)| 00:00:01 | | | | +| 3 | SORT AGGREGATE | | 1 | 8 | | | | | | +| 4 | PX COORDINATOR | | | | | | | | | +| 5 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 8 | | | Q1,00 | P->S | QC (RAND) | +| 6 | SORT AGGREGATE | | 1 | 8 | | | Q1,00 | PCWP | | +| 7 | PX BLOCK ITERATOR | | 81M| 625M| 679 (78)| 00:00:01 | Q1,00 | PCWC | | +|* 8 | TABLE ACCESS FULL| FACT1 | 81M| 625M| 679 (78)| 00:00:01 | Q1,00 | PCWP | | +------------------------------------------------------------------------------------------------------------------------------------ + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 8 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 2 + + +34 rows selected. + +Elapsed: 00:00:00.154 +Elapsed: 00:00:00.154 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- Selecting SYSDATE first because SQLCL executes +SQL> -- a query to retrieve NLS information and we are not +SQL> -- interested in seeing that query plan. +SQL> -- +SQL> select sysdate from dual; + +SYSDATE +--------- +18-MAY-18 + +Elapsed: 00:00:00.336 +SQL> select max(dt1) from fact1; + +MAX(DT1) +--------- +17-MAY-18 + +Elapsed: 00:00:00.175 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 1gnjpd7q1d5ma, child number 1 +------------------------------------- +select max(dt1) from fact1 + +Plan hash value: 2785769099 + +------------------------------------------------------------------------------------------------------------------------------------ +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +------------------------------------------------------------------------------------------------------------------------------------ +| 0 | SELECT STATEMENT | | | | 798 (100)| | | | | +| 1 | RESULT CACHE | az2k0wy6h946y2ytym1fn1dpxx | | | | | | | | +| 2 | VIEW | VW_SQT_65BBF4BE | 1 | 9 | 790 (81)| 00:00:01 | | | | +| 3 | SORT AGGREGATE | | 1 | 8 | | | | | | +| 4 | PX COORDINATOR | | | | | | | | | +| 5 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 8 | | | Q1,00 | P->S | QC (RAND) | +| 6 | SORT AGGREGATE | | 1 | 8 | | | Q1,00 | PCWP | | +| 7 | PX BLOCK ITERATOR | | 81M| 625M| 790 (81)| 00:00:01 | Q1,00 | PCWC | | +|* 8 | TABLE ACCESS FULL| FACT1 | 81M| 625M| 790 (81)| 00:00:01 | Q1,00 | PCWP | | +------------------------------------------------------------------------------------------------------------------------------------ + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 8 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 2 + + +34 rows selected. + +Elapsed: 00:00:00.175 +Elapsed: 00:00:00.175 +SQL> pause p... +p... + +SQL> +SQL> select approx_count_distinct(num1) from fact1; + +APPROX_COUNT_DISTINCT(NUM1) +--------------------------- + 14 + +Elapsed: 00:00:00.160 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID g05pjsw2y6hvs, child number 1 +------------------------------------- +select approx_count_distinct(num1) from fact1 + +Plan hash value: 2785769099 + +-------------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +-------------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 631 (100)| | | | | +| 1 | RESULT CACHE | fruzw0bcjqdc811pjcukukh7h3 | | | | | | | | +| 2 | VIEW | VW_SQT_65BBF4BE | 1 | 13 | 624 (76)| 00:00:01 | | | | +| 3 | SORT AGGREGATE APPROX | | 1 | 3 | | | | | | +| 4 | PX COORDINATOR | | | | | | | | | +| 5 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 3 | | | Q1,00 | P->S | QC (RAND) | +| 6 | SORT AGGREGATE APPROX| | 1 | 3 | | | Q1,00 | PCWP | | +| 7 | PX BLOCK ITERATOR | | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWC | | +|* 8 | TABLE ACCESS FULL | FACT1 | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWP | | +-------------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 8 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 2 + + +34 rows selected. + +Elapsed: 00:00:00.166 +Elapsed: 00:00:00.167 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- The transformation can be used in more complex queries +SQL> -- +SQL> select * from dim1 where dnum = (select max(num1) from fact1); + + DNUM +---------- + 13 + +Elapsed: 00:00:00.137 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 271xpwgggk88w, child number 1 +------------------------------------- +select * from dim1 where dnum = (select max(num1) from fact1) + +Plan hash value: 3663464221 + +------------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +------------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 634 (100)| | | | | +| 1 | RESULT CACHE | 48hbbn7w62q755hksrwanvrqsx | | | | | | | | +|* 2 | TABLE ACCESS FULL | DIM1 | 1 | 3 | 2 (0)| 00:00:01 | | | | +| 3 | VIEW | VW_SQT_EA69C9F1 | 1 | 13 | 624 (76)| 00:00:01 | | | | +| 4 | SORT AGGREGATE | | 1 | 3 | | | | | | +| 5 | PX COORDINATOR | | | | | | | | | +| 6 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 3 | | | Q1,00 | P->S | QC (RAND) | +| 7 | SORT AGGREGATE | | 1 | 3 | | | Q1,00 | PCWP | | +| 8 | PX BLOCK ITERATOR | | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWC | | +|* 9 | TABLE ACCESS FULL| FACT1 | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWP | | +------------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 2 - filter("DNUM"=) + 9 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 4 + + +36 rows selected. + +Elapsed: 00:00:00.175 +Elapsed: 00:00:00.176 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- The following queries do not use stats query answering. +SQL> -- +SQL> +SQL> -- +SQL> -- Operating on the aggregate column +SQL> -- +SQL> select max(num1)+1 from fact1 where num1 > 0; + +MAX(NUM1)+1 +----------- + 14 + +Elapsed: 00:00:01.367 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 2g53d6p99a575, child number 1 +------------------------------------- +select max(num1)+1 from fact1 where num1 > 0 + +Plan hash value: 2304087426 + +----------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +----------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 763 (100)| | | | | +| 1 | RESULT CACHE | aymkxy5mdbsgp77n3wfm6jjusn | | | | | | | | +| 2 | SORT AGGREGATE | | 1 | 3 | | | | | | +| 3 | PX COORDINATOR | | | | | | | | | +| 4 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 3 | | | Q1,00 | P->S | QC (RAND) | +| 5 | SORT AGGREGATE | | 1 | 3 | | | Q1,00 | PCWP | | +| 6 | PX BLOCK ITERATOR | | 81M| 234M| 763 (80)| 00:00:01 | Q1,00 | PCWC | | +|* 7 | TABLE ACCESS FULL| FACT1 | 81M| 234M| 763 (80)| 00:00:01 | Q1,00 | PCWP | | +----------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 7 - access(:Z>=:Z AND :Z<=:Z) + filter("NUM1">0) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 4 + + +34 rows selected. + +Elapsed: 00:00:00.163 +Elapsed: 00:00:00.163 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- WHERE clause +SQL> -- +SQL> select max(num1) from fact1 where num1 > 0; + + MAX(NUM1) +---------- + 13 + +Elapsed: 00:00:00.951 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 0rqq0xxkgzfyf, child number 1 +------------------------------------- +select max(num1) from fact1 where num1 > 0 + +Plan hash value: 2304087426 + +----------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +----------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 763 (100)| | | | | +| 1 | RESULT CACHE | f85vnu93z7ws580vwfw0dtdj29 | | | | | | | | +| 2 | SORT AGGREGATE | | 1 | 3 | | | | | | +| 3 | PX COORDINATOR | | | | | | | | | +| 4 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 3 | | | Q1,00 | P->S | QC (RAND) | +| 5 | SORT AGGREGATE | | 1 | 3 | | | Q1,00 | PCWP | | +| 6 | PX BLOCK ITERATOR | | 81M| 234M| 763 (80)| 00:00:01 | Q1,00 | PCWC | | +|* 7 | TABLE ACCESS FULL| FACT1 | 81M| 234M| 763 (80)| 00:00:01 | Q1,00 | PCWP | | +----------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 7 - access(:Z>=:Z AND :Z<=:Z) + filter("NUM1">0) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 4 + + +34 rows selected. + +Elapsed: 00:00:00.153 +Elapsed: 00:00:00.154 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- TXT2 column is VARCHAR2(100) - too wide +SQL> -- +SQL> select min(txt2), max(txt2) from fact1; + +MIN(TXT2) MAX(TXT2) +------------------------------ ------------------------------ +XXX1 XXX9999 + +Elapsed: 00:00:01.530 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID a19svh2shq0x2, child number 1 +------------------------------------- +select min(txt2), max(txt2) from fact1 + +Plan hash value: 2304087426 + +----------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +----------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 735 (100)| | | | | +| 1 | RESULT CACHE | 9yn73hch6kc0159fpjznkbqu57 | | | | | | | | +| 2 | SORT AGGREGATE | | 1 | 8 | | | | | | +| 3 | PX COORDINATOR | | | | | | | | | +| 4 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 8 | | | Q1,00 | P->S | QC (RAND) | +| 5 | SORT AGGREGATE | | 1 | 8 | | | Q1,00 | PCWP | | +| 6 | PX BLOCK ITERATOR | | 81M| 625M| 735 (80)| 00:00:01 | Q1,00 | PCWC | | +|* 7 | TABLE ACCESS FULL| FACT1 | 81M| 625M| 735 (80)| 00:00:01 | Q1,00 | PCWP | | +----------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 7 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 4 + + +33 rows selected. + +Elapsed: 00:00:00.140 +Elapsed: 00:00:00.141 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- Not a supported aggregate +SQL> -- +SQL> select sum(num1) from fact1; + + SUM(NUM1) +---------- + 983050000 + +Elapsed: 00:00:01.089 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 2xdrfdubucvqd, child number 1 +------------------------------------- +select sum(num1) from fact1 + +Plan hash value: 2304087426 + +----------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +----------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 624 (100)| | | | | +| 1 | RESULT CACHE | 724t93tbh4ka575ubbbqvw3tub | | | | | | | | +| 2 | SORT AGGREGATE | | 1 | 3 | | | | | | +| 3 | PX COORDINATOR | | | | | | | | | +| 4 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 3 | | | Q1,00 | P->S | QC (RAND) | +| 5 | SORT AGGREGATE | | 1 | 3 | | | Q1,00 | PCWP | | +| 6 | PX BLOCK ITERATOR | | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWC | | +|* 7 | TABLE ACCESS FULL| FACT1 | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWP | | +----------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 7 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 4 + + +33 rows selected. + +Elapsed: 00:00:00.156 +Elapsed: 00:00:00.156 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- Incidentally, the result cache helps us +SQL> -- out instead. If the query is executed a +SQL> -- second time, we can get the result from cache. +SQL> -- +SQL> select sum(num1) from fact1; + + SUM(NUM1) +---------- + 983050000 + +Elapsed: 00:00:00.099 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 2xdrfdubucvqd, child number 1 +------------------------------------- +select sum(num1) from fact1 + +Plan hash value: 2304087426 + +----------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +----------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 624 (100)| | | | | +| 1 | RESULT CACHE | 724t93tbh4ka575ubbbqvw3tub | | | | | | | | +| 2 | SORT AGGREGATE | | 1 | 3 | | | | | | +| 3 | PX COORDINATOR | | | | | | | | | +| 4 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 3 | | | Q1,00 | P->S | QC (RAND) | +| 5 | SORT AGGREGATE | | 1 | 3 | | | Q1,00 | PCWP | | +| 6 | PX BLOCK ITERATOR | | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWC | | +|* 7 | TABLE ACCESS FULL| FACT1 | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWP | | +----------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 7 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 4 + + +33 rows selected. + +Elapsed: 00:00:00.146 +Elapsed: 00:00:00.146 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- Not a simple column aggregate +SQL> -- +SQL> select max(num1+10) from fact1; + +MAX(NUM1+10) +------------ + 23 + +Elapsed: 00:00:01.523 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID 790j5tmk17my6, child number 1 +------------------------------------- +select max(num1+10) from fact1 + +Plan hash value: 2304087426 + +----------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +----------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | | | 624 (100)| | | | | +| 1 | RESULT CACHE | bqanp6phbh7v6cmkuwyp088agn | | | | | | | | +| 2 | SORT AGGREGATE | | 1 | 3 | | | | | | +| 3 | PX COORDINATOR | | | | | | | | | +| 4 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 3 | | | Q1,00 | P->S | QC (RAND) | +| 5 | SORT AGGREGATE | | 1 | 3 | | | Q1,00 | PCWP | | +| 6 | PX BLOCK ITERATOR | | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWC | | +|* 7 | TABLE ACCESS FULL| FACT1 | 81M| 234M| 624 (76)| 00:00:01 | Q1,00 | PCWP | | +----------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 7 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 4 + + +33 rows selected. + +Elapsed: 00:00:00.149 +Elapsed: 00:00:00.150 +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- Let's get a baseline elapsed time for this query +SQL> -- +SQL> select /* RUN1 */ max(num0),min(num0),min(num1),max(num1) from fact1; + + MAX(NUM0) MIN(NUM0) MIN(NUM1) MAX(NUM1) +---------- ---------- ---------- ---------- + 10000 1 0 13 + +Elapsed: 00:00:00.290 +SQL> -- Note the short elapsed time because we are using stats +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- DML prevents us from using stats to answer our query +SQL> -- so we'll insert a row and re-try the "RUN1" query again. +SQL> -- I'm using a different comment (RUN2) to change the query text so we +SQL> -- get a new query in the cursor cache. It's the same query though +SQL> -- of course. +SQL> -- +SQL> insert into fact1 values (1,1,'XXX1','XXX1',sysdate); + +1 row inserted. + +Elapsed: 00:00:00.092 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.086 +SQL> select /* RUN2 */ max(num0),min(num0),min(num1),max(num1) from fact1; + + MAX(NUM0) MIN(NUM0) MIN(NUM1) MAX(NUM1) +---------- ---------- ---------- ---------- + 10000 1 0 13 + +Elapsed: 00:00:02.419 +SQL> -- The DML has prevented us from using stats and this is +SQL> -- reflected in the longer elapsed time. +SQL> pause p... +p... + +SQL> +SQL> select /* RUN3 */ max(num0),min(num0),min(num1),max(num1) from fact1; + + MAX(NUM0) MIN(NUM0) MIN(NUM1) MAX(NUM1) +---------- ---------- ---------- ---------- + 10000 1 0 13 + +Elapsed: 00:00:02.406 +SQL> @plan +SQL> set tab off +SQL> SET LINESIZE 250 +SQL> SET PAGESIZE 500 +SQL> SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +SQL_ID dm9mw5035bvtg, child number 1 +------------------------------------- +select /* RUN3 */ max(num0),min(num0),min(num1),max(num1) from fact1 + +Plan hash value: 2785769099 + +------------------------------------------------------------------------------------------------------------------------------------ +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | +------------------------------------------------------------------------------------------------------------------------------------ +| 0 | SELECT STATEMENT | | | | 644 (100)| | | | | +| 1 | RESULT CACHE | 132jzxwpc5dq72bx6dhx6djsq5 | | | | | | | | +| 2 | VIEW | VW_SQT_65BBF4BE | 1 | 52 | 624 (76)| 00:00:01 | | | | +| 3 | SORT AGGREGATE | | 1 | 7 | | | | | | +| 4 | PX COORDINATOR | | | | | | | | | +| 5 | PX SEND QC (RANDOM) | :TQ10000 | 1 | 7 | | | Q1,00 | P->S | QC (RAND) | +| 6 | SORT AGGREGATE | | 1 | 7 | | | Q1,00 | PCWP | | +| 7 | PX BLOCK ITERATOR | | 81M| 546M| 624 (76)| 00:00:01 | Q1,00 | PCWC | | +|* 8 | TABLE ACCESS FULL| FACT1 | 81M| 546M| 624 (76)| 00:00:01 | Q1,00 | PCWP | | +------------------------------------------------------------------------------------------------------------------------------------ + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 8 - access(:Z>=:Z AND :Z<=:Z) + +Result Cache Information (identified by operation id): +------------------------------------------------------ + + 1 - + +Note +----- + - automatic DOP: Computed Degree of Parallelism is 2 + + +34 rows selected. + +Elapsed: 00:00:00.160 +Elapsed: 00:00:00.167 +SQL> -- The plan reflects that stats query answering is POSSIBLE. +SQL> -- In this case it could not be used because of the DML and this +SQL> -- is reflected in the longer elapsed time (than the +SQL> -- RUN1 example above). +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- Get stats back up to date +SQL> -- +SQL> exec dbms_stats.gather_table_stats(user,'FACT1'); + +PL/SQL procedure successfully completed. + +Elapsed: 00:00:31.733 +Elapsed: 00:00:31.733 +SQL> +SQL> spool off diff --git a/optimizer/autonomous/stats_answering/example.sql b/optimizer/autonomous/stats_answering/example.sql new file mode 100644 index 00000000..0ad68d8b --- /dev/null +++ b/optimizer/autonomous/stats_answering/example.sql @@ -0,0 +1,9 @@ +set echo on + +spool example + +@make_dim +@make_fact +@test_stats + +spool off diff --git a/optimizer/autonomous/stats_answering/make_dim.sql b/optimizer/autonomous/stats_answering/make_dim.sql new file mode 100644 index 00000000..60b97c16 --- /dev/null +++ b/optimizer/autonomous/stats_answering/make_dim.sql @@ -0,0 +1,16 @@ +REM +REM Small DIM table +REM +set timing on +set linesize 250 +set tab off +set trims on +set echo on + +drop table dim1 purge; + +create table dim1 (dnum number(10)); + +insert into dim1 values (13); +commit; +exec dbms_stats.gather_table_stats(user,'dim1'); diff --git a/optimizer/autonomous/stats_answering/make_fact.sql b/optimizer/autonomous/stats_answering/make_fact.sql new file mode 100644 index 00000000..2d0e9bae --- /dev/null +++ b/optimizer/autonomous/stats_answering/make_fact.sql @@ -0,0 +1,53 @@ +REM +REM Fact table for demo statistics query answering +REM +set timing on +set linesize 250 +set tab off +set trims on +set echo on + +drop table fact1 purge; +drop table fact1_source purge; + +-- +-- In this case we are using VARCHAR2(20) +-- We have to keep the column under 64 bytes +-- to answer aggregate queries on this column +-- using stats. +-- +create table fact1 (num0 number(10), num1 number(10), txt1 varchar2(20), txt2 varchar2(100), dt1 date); + +create table fact1_source as +select * from fact1 where 1=-1; + +insert /*+ APPEND */ into fact1_source +select rownum,mod(rownum,10),'XXX'||rownum,'XXX'||rownum,sysdate-rownum +from dual connect by rownum <= 10000; + +commit; + +-- +-- Insert rows into FACT1 +-- +insert /*+ APPEND */ into fact1 select num0,0,txt1,txt2,dt1 from fact1_source; +commit; + +-- +-- Let's speed up row generation... +-- +set autocommit on +insert /*+ APPEND */ into fact1 select num0,1,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,2,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,3,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,4,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,5,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,6,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,7,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,8,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,9,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,10,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,11,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,12,txt1,txt2,dt1 from fact1; +insert /*+ APPEND */ into fact1 select num0,13,txt1,txt2,dt1 from fact1; +set autocommit off diff --git a/optimizer/autonomous/stats_answering/plan.sql b/optimizer/autonomous/stats_answering/plan.sql new file mode 100644 index 00000000..5b4c7417 --- /dev/null +++ b/optimizer/autonomous/stats_answering/plan.sql @@ -0,0 +1,4 @@ +set tab off +SET LINESIZE 250 +SET PAGESIZE 500 +SELECT * FROM table(DBMS_XPLAN.DISPLAY_CURSOR()); diff --git a/optimizer/autonomous/stats_answering/test_stats.sql b/optimizer/autonomous/stats_answering/test_stats.sql new file mode 100644 index 00000000..af192b74 --- /dev/null +++ b/optimizer/autonomous/stats_answering/test_stats.sql @@ -0,0 +1,126 @@ +set echo on +set timing on +set linesize 250 +set trims on +column MAX(TXT1) format a30 +column MIN(TXT1) format a30 +column MAX(TXT2) format a30 +column MIN(TXT2) format a30 + +-- +-- The following queries use stats answering +-- +select max(num0),min(num1) from fact1; +@plan +pause p... + +select max(num0),min(num1),min(txt1),max(txt1),count(*) from fact1; +@plan +pause p... + +select max(txt1),min(txt1),count(txt1) from fact1; +@plan +pause p... + +-- +-- Selecting SYSDATE first because SQLCL executes +-- a query to retrieve NLS information and we are not +-- interested in seeing that query plan. +-- +select sysdate from dual; +select max(dt1) from fact1; +@plan +pause p... + +select approx_count_distinct(num1) from fact1; +@plan +pause p... + +-- +-- The transformation can be used in more complex queries +-- +select * from dim1 where dnum = (select max(num1) from fact1); +@plan +pause p... + +-- +-- The following queries do not use stats query answering. +-- + +-- +-- Operating on the aggregate column +-- +select max(num1)+1 from fact1 where num1 > 0; +@plan +pause p... + +-- +-- WHERE clause +-- +select max(num1) from fact1 where num1 > 0; +@plan +pause p... + +-- +-- TXT2 column is VARCHAR2(100) - too wide +-- +select min(txt2), max(txt2) from fact1; +@plan +pause p... + +-- +-- Not a supported aggregate +-- +select sum(num1) from fact1; +@plan +pause p... + +-- +-- Incidentally, the result cache helps us +-- out instead. If the query is executed a +-- second time, we can get the result from cache. +-- +select sum(num1) from fact1; +@plan +pause p... + +-- +-- Not a simple column aggregate +-- +select max(num1+10) from fact1; +@plan +pause p... + +-- +-- Let's get a baseline elapsed time for this query +-- +select /* RUN1 */ max(num0),min(num0),min(num1),max(num1) from fact1; +-- Note the short elapsed time because we are using stats +pause p... + +-- +-- DML prevents us from using stats to answer our query +-- so we'll insert a row and re-try the "RUN1" query again. +-- I'm using a different comment (RUN2) to change the query text so we +-- get a new query in the cursor cache. It's the same query though +-- of course. +-- +insert into fact1 values (1,1,'XXX1','XXX1',sysdate); +commit; +select /* RUN2 */ max(num0),min(num0),min(num1),max(num1) from fact1; +-- The DML has prevented us from using stats and this is +-- reflected in the longer elapsed time. +pause p... + +select /* RUN3 */ max(num0),min(num0),min(num1),max(num1) from fact1; +@plan +-- The plan reflects that stats query answering is POSSIBLE. +-- In this case it could not be used because of the DML and this +-- is reflected in the longer elapsed time (than the +-- RUN1 example above). +pause p... + +-- +-- Get stats back up to date +-- +exec dbms_stats.gather_table_stats(user,'FACT1'); diff --git a/optimizer/autonomous/stats_answering/user.sql b/optimizer/autonomous/stats_answering/user.sql new file mode 100644 index 00000000..cc262f84 --- /dev/null +++ b/optimizer/autonomous/stats_answering/user.sql @@ -0,0 +1,13 @@ +-- +-- Log into admin account and create a test user as follows +-- +create user adwu1 identified by "choose your password"; + +grant ALTER SESSION to adwu1; +grant CREATE TABLE to adwu1; +grant CREATE VIEW to adwu1; +grant CREATE SESSION to adwu1; +-- +grant select on v$session to adwu1; +grant select on v$sql_plan to adwu1; +grant select on v$sql to adwu1; diff --git a/optimizer/autonomous/stats_on_load/README.md b/optimizer/autonomous/stats_on_load/README.md new file mode 100644 index 00000000..82ebf270 --- /dev/null +++ b/optimizer/autonomous/stats_on_load/README.md @@ -0,0 +1,16 @@ +This example demonstrates that statistics are maintained during direct path load. + +Create a test user using the *user.sql* script. + +Run the test using *test_load.sql*. + +### DISCLAIMER + +* These scripts are provided for educational purposes only. +* They are NOT supported by Oracle World Wide Technical Support. +* The scripts have been tested and they appear to work as intended. +* You should always run scripts on a test instance. + +### WARNING + +* These scripts drop and create tables. For use on test databases. diff --git a/optimizer/autonomous/stats_on_load/stat.sql b/optimizer/autonomous/stats_on_load/stat.sql new file mode 100644 index 00000000..dec23309 --- /dev/null +++ b/optimizer/autonomous/stats_on_load/stat.sql @@ -0,0 +1,16 @@ +-- +-- Show statistics for FACT1 +-- +-- The histogram query is by Tim Hall: https://oracle-base.com/articles/12c/histograms-enhancements-12cr1 +-- +select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +SELECT '<=' || endpoint_value AS range, + endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency +FROM user_tab_histograms +WHERE table_name = 'FACT1' +AND column_name = 'NUM1' +ORDER BY endpoint_value; diff --git a/optimizer/autonomous/stats_on_load/test_load.lst b/optimizer/autonomous/stats_on_load/test_load.lst new file mode 100644 index 00000000..0b7c99bd --- /dev/null +++ b/optimizer/autonomous/stats_on_load/test_load.lst @@ -0,0 +1,926 @@ +SQL> +SQL> drop table fact1 purge; + +Error starting at line : 18 File @ /u01/npb/Features/GIT2/oracle-db-examples/optimizer/autonomous/stats_on_load/test_load.sql +In command - +drop table fact1 purge +Error report - +ORA-00942: table or view does not exist + +Elapsed: 00:00:00.217 +SQL> drop table fact1_source purge; + +Error starting at line : 19 File @ /u01/npb/Features/GIT2/oracle-db-examples/optimizer/autonomous/stats_on_load/test_load.sql +In command - +drop table fact1_source purge +Error report - +ORA-00942: table or view does not exist + +Elapsed: 00:00:00.180 +SQL> +SQL> create table fact1 (num0 number(10), num1 number(10), txt1 varchar2(100)); + +Table FACT1 created. + +Elapsed: 00:00:00.093 +SQL> +SQL> create table fact1_source as + 2 select * from fact1 where 1=-1; + +Table FACT1_SOURCE created. + +Elapsed: 00:00:00.112 +SQL> +SQL> insert /*+ APPEND */ into fact1_source + 2 select rownum,mod(rownum,10),'XXX'||rownum + 3 from dual connect by rownum <= 10000; + +10,000 rows inserted. + +Elapsed: 00:00:00.471 +SQL> +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.093 +SQL> +SQL> -- +SQL> -- Notice that NUM_ROWS is maintained on initial load - and this +SQL> -- has been available since 12c. +SQL> -- +SQL> select table_name,num_rows from user_tables where table_name = 'FACT1_SOURCE'; + +TABLE_NAME NUM_ROWS +------------------------------ ---------- +FACT1_SOURCE 10000 + +Elapsed: 00:00:00.318 +SQL> +SQL> pause p... +p... + +SQL> +SQL> -- +SQL> -- Insert rows into FACT1 +SQL> -- +SQL> insert /*+ APPEND */ into fact1 select num0,1,txt1 from fact1_source; + +10,000 rows inserted. + +Elapsed: 00:00:00.519 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.101 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 10000 10000 NO + +Elapsed: 00:00:00.110 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 10000 HYBRID +FACT1 NUM1 C102 C102 10000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 10000 HYBRID + +Elapsed: 00:00:00.133 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 5500 + +Elapsed: 00:00:00.095 +Elapsed: 00:00:00.096 +SQL> +SQL> -- Notice above that statistics are created. +SQL> -- Histograms have been created too. +SQL> pause p... +p... + +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,2,txt1 from fact1_source; + +10,000 rows inserted. + +Elapsed: 00:00:00.414 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.095 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 20000 20000 NO + +Elapsed: 00:00:00.112 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 20000 HYBRID +FACT1 NUM1 C102 C103 20000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 20000 HYBRID + +Elapsed: 00:00:00.134 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 + +Elapsed: 00:00:00.111 +Elapsed: 00:00:00.112 +SQL> +SQL> -- Notice above that the stats have been updated. +SQL> -- Histograms have been maintained too. +SQL> -- ADWC will maintain statistics even if the target +SQL> -- table in not empty before the load! +SQL> pause p... +p... + +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,3,txt1 from fact1_source; + +10,000 rows inserted. + +Elapsed: 00:00:00.394 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.107 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 30000 30000 NO + +Elapsed: 00:00:00.112 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 30000 HYBRID +FACT1 NUM1 C102 C104 30000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 30000 HYBRID + +Elapsed: 00:00:00.119 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 + +Elapsed: 00:00:00.105 +Elapsed: 00:00:00.106 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,4,txt1 from fact1_source; + +10,000 rows inserted. + +Elapsed: 00:00:00.259 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.099 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 40000 40000 NO + +Elapsed: 00:00:00.099 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 40000 HYBRID +FACT1 NUM1 C102 C105 40000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 40000 HYBRID + +Elapsed: 00:00:00.105 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 + +Elapsed: 00:00:00.103 +Elapsed: 00:00:00.104 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,5,txt1 from fact1; + +40,000 rows inserted. + +Elapsed: 00:00:00.519 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.093 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 80000 80000 NO + +Elapsed: 00:00:00.103 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 80000 HYBRID +FACT1 NUM1 C102 C106 80000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 80000 HYBRID + +Elapsed: 00:00:00.094 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 + +Elapsed: 00:00:00.109 +Elapsed: 00:00:00.110 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,6,txt1 from fact1; + +80,000 rows inserted. + +Elapsed: 00:00:00.559 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.093 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 160000 160000 NO + +Elapsed: 00:00:00.102 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 160000 HYBRID +FACT1 NUM1 C102 C107 160000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 160000 HYBRID + +Elapsed: 00:00:00.118 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 + +6 rows selected. + +Elapsed: 00:00:00.109 +Elapsed: 00:00:00.120 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,7,txt1 from fact1; + +160,000 rows inserted. + +Elapsed: 00:00:00.643 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.093 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 320000 320000 NO + +Elapsed: 00:00:00.098 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 320000 HYBRID +FACT1 NUM1 C102 C108 320000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 320000 HYBRID + +Elapsed: 00:00:00.118 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 + +7 rows selected. + +Elapsed: 00:00:00.109 +Elapsed: 00:00:00.109 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,8,txt1 from fact1; + +320,000 rows inserted. + +Elapsed: 00:00:00.732 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.097 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 640000 640000 NO + +Elapsed: 00:00:00.108 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 640000 HYBRID +FACT1 NUM1 C102 C109 640000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 640000 HYBRID + +Elapsed: 00:00:00.109 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 + +8 rows selected. + +Elapsed: 00:00:00.096 +Elapsed: 00:00:00.097 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,9,txt1 from fact1; + +640,000 rows inserted. + +Elapsed: 00:00:01.294 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.092 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 1280000 1280000 NO + +Elapsed: 00:00:00.109 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 1280000 HYBRID +FACT1 NUM1 C102 C10A 1280000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 1280000 HYBRID + +Elapsed: 00:00:00.102 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 +<=9 1 640000 + +9 rows selected. + +Elapsed: 00:00:00.109 +Elapsed: 00:00:00.111 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,10,txt1 from fact1; + +1,280,000 rows inserted. + +Elapsed: 00:00:02.166 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.095 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 2560000 2560000 NO + +Elapsed: 00:00:00.100 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 2560000 HYBRID +FACT1 NUM1 C102 C10B 2560000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 2560000 HYBRID + +Elapsed: 00:00:00.101 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 +<=9 1 640000 +<=10 1 1280000 + +10 rows selected. + +Elapsed: 00:00:00.096 +Elapsed: 00:00:00.096 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,11,txt1 from fact1; + +2,560,000 rows inserted. + +Elapsed: 00:00:03.961 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.092 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 5120000 5120000 NO + +Elapsed: 00:00:00.103 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 5120000 HYBRID +FACT1 NUM1 C102 C10C 5120000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 5120000 HYBRID + +Elapsed: 00:00:00.093 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 +<=9 1 640000 +<=10 1 1280000 +<=11 1 2560000 + +11 rows selected. + +Elapsed: 00:00:00.103 +Elapsed: 00:00:00.104 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,12,txt1 from fact1; + +5,120,000 rows inserted. + +Elapsed: 00:00:07.366 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.094 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 10240000 10240000 NO + +Elapsed: 00:00:00.097 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 10240000 HYBRID +FACT1 NUM1 C102 C10D 10240000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 10240000 HYBRID + +Elapsed: 00:00:00.094 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 +<=9 1 640000 +<=10 1 1280000 +<=11 1 2560000 +<=12 1 5120000 + +12 rows selected. + +Elapsed: 00:00:00.105 +Elapsed: 00:00:00.106 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,13,txt1 from fact1; + +10,240,000 rows inserted. + +Elapsed: 00:00:14.345 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.095 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 20480000 20480000 NO + +Elapsed: 00:00:00.099 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 20480000 HYBRID +FACT1 NUM1 C102 C10E 20480000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 20480000 HYBRID + +Elapsed: 00:00:00.126 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 +<=9 1 640000 +<=10 1 1280000 +<=11 1 2560000 +<=12 1 5120000 +<=13 1 10240000 + +13 rows selected. + +Elapsed: 00:00:00.104 +Elapsed: 00:00:00.105 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,14,txt1 from fact1; + +20,480,000 rows inserted. + +Elapsed: 00:00:28.133 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.094 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 40960000 40960000 NO + +Elapsed: 00:00:00.095 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 40960000 HYBRID +FACT1 NUM1 C102 C10F 40960000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 40960000 HYBRID + +Elapsed: 00:00:00.092 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 +<=9 1 640000 +<=10 1 1280000 +<=11 1 2560000 +<=12 1 5120000 +<=13 1 10240000 +<=14 1 20480000 + +14 rows selected. + +Elapsed: 00:00:00.095 +Elapsed: 00:00:00.096 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,15,txt1 from fact1; + +40,960,000 rows inserted. + +Elapsed: 00:00:55.637 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.097 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 81920000 81920000 NO + +Elapsed: 00:00:00.100 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 81920000 HYBRID +FACT1 NUM1 C102 C110 81920000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 81920000 HYBRID + +Elapsed: 00:00:00.118 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 +<=9 1 640000 +<=10 1 1280000 +<=11 1 2560000 +<=12 1 5120000 +<=13 1 10240000 +<=14 1 20480000 +<=15 1 40960000 + +15 rows selected. + +Elapsed: 00:00:00.108 +Elapsed: 00:00:00.109 +SQL> +SQL> insert /*+ APPEND */ into fact1 select num0,16,txt1 from fact1; + +81,920,000 rows inserted. + +Elapsed: 00:00:49.970 +SQL> commit; + +Commit complete. + +Elapsed: 00:00:00.134 +SQL> @stat +SQL> select table_name,num_rows,sample_size,stale_stats from user_tab_statistics where table_name = 'FACT1'; + +TABLE_NAME NUM_ROWS SAMPLE_SIZE STA +------------------------------ ---------- ----------- --- +FACT1 163840000 163840000 NO + +Elapsed: 00:00:00.097 +SQL> +SQL> select table_name,column_name,low_value,high_value,sample_size,histogram from user_tab_col_statistics where table_name = 'FACT1'; + +TABLE_NAME COLUMN_NAME LOW_VALUE HIGH_VALUE SAMPLE_SIZE HISTOGRAM +------------------------------ ------------------------------ ------------------------------ ------------------------------ ----------- --------------- +FACT1 NUM0 C102 C302 163840000 HYBRID +FACT1 NUM1 C102 C111 163840000 FREQUENCY +FACT1 TXT1 58585831 58585839393939 163840000 HYBRID + +Elapsed: 00:00:00.094 +SQL> +SQL> SELECT '<=' || endpoint_value AS range, + 2 endpoint_value - (LAG(endpoint_value, 1, -1) OVER (ORDER BY endpoint_value)+1) + 1 AS vals_in_range, + 3 endpoint_number - LAG(endpoint_number, 1, 0) OVER (ORDER BY endpoint_value) AS frequency + 4 FROM user_tab_histograms + 5 WHERE table_name = 'FACT1' + 6 AND column_name = 'NUM1' + 7 ORDER BY endpoint_value; + +RANGE VALS_IN_RANGE FREQUENCY +---------- ------------- ---------- +<=1 2 10000 +<=2 1 10000 +<=3 1 10000 +<=4 1 10000 +<=5 1 40000 +<=6 1 80000 +<=7 1 160000 +<=8 1 320000 +<=9 1 640000 +<=10 1 1280000 +<=11 1 2560000 +<=12 1 5120000 +<=13 1 10240000 +<=14 1 20480000 +<=15 1 40960000 +<=16 1 81920000 + +16 rows selected. + +Elapsed: 00:00:00.109 +Elapsed: 00:00:00.110 +SQL> spool off diff --git a/optimizer/autonomous/stats_on_load/test_load.sql b/optimizer/autonomous/stats_on_load/test_load.sql new file mode 100644 index 00000000..2beecf31 --- /dev/null +++ b/optimizer/autonomous/stats_on_load/test_load.sql @@ -0,0 +1,116 @@ +REM +REM Demo direct path loading and stats maintenance. +REM +set timing on +column stale format a5 +column table_name format a30 +column column_name format a30 +column high_value format a30 +column low_value format a30 +column range format a10 +set linesize 250 +set tab off +set trims on +set echo on + +spool test_load + +drop table fact1 purge; +drop table fact1_source purge; + +create table fact1 (num0 number(10), num1 number(10), txt1 varchar2(100)); + +create table fact1_source as +select * from fact1 where 1=-1; + +insert /*+ APPEND */ into fact1_source +select rownum,mod(rownum,10),'XXX'||rownum +from dual connect by rownum <= 10000; + +commit; + +-- +-- Notice that NUM_ROWS is maintained on initial load - and this +-- has been available since 12c. +-- +select table_name,num_rows from user_tables where table_name = 'FACT1_SOURCE'; + +pause p... + +-- +-- Insert rows into FACT1 +-- +insert /*+ APPEND */ into fact1 select num0,1,txt1 from fact1_source; +commit; +@stat + +-- Notice above that statistics are created. +-- Histograms have been created too. +pause p... + +insert /*+ APPEND */ into fact1 select num0,2,txt1 from fact1_source; +commit; +@stat + +-- Notice above that the stats have been updated. +-- Histograms have been maintained too. +-- ADWC will maintain statistics even if the target +-- table in not empty before the load! +pause p... + +insert /*+ APPEND */ into fact1 select num0,3,txt1 from fact1_source; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,4,txt1 from fact1_source; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,5,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,6,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,7,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,8,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,9,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,10,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,11,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,12,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,13,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,14,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,15,txt1 from fact1; +commit; +@stat + +insert /*+ APPEND */ into fact1 select num0,16,txt1 from fact1; +commit; +@stat +spool off diff --git a/optimizer/autonomous/stats_on_load/user.sql b/optimizer/autonomous/stats_on_load/user.sql new file mode 100644 index 00000000..cc262f84 --- /dev/null +++ b/optimizer/autonomous/stats_on_load/user.sql @@ -0,0 +1,13 @@ +-- +-- Log into admin account and create a test user as follows +-- +create user adwu1 identified by "choose your password"; + +grant ALTER SESSION to adwu1; +grant CREATE TABLE to adwu1; +grant CREATE VIEW to adwu1; +grant CREATE SESSION to adwu1; +-- +grant select on v$session to adwu1; +grant select on v$sql_plan to adwu1; +grant select on v$sql to adwu1; diff --git a/optimizer/execution_plans/part0/README.md b/optimizer/execution_plans/part0/README.md index 29ffac17..0c3fda98 100644 --- a/optimizer/execution_plans/part0/README.md +++ b/optimizer/execution_plans/part0/README.md @@ -8,7 +8,7 @@ To run the examples yourself, use a DBA account and start by running "ctables.sq Next, run the examples: eg1.sql ... eg6.sql -An interactive report from Enterprise Manager us also included: EM_sqlmonitor_output.html +I have included an interactive report saved from Enterprise Manager: EM_sqlmonitor_output.html ### DISCLAIMER diff --git a/optimizer/execution_plans/part0/eg1.lst b/optimizer/execution_plans/part0/eg1.lst index 9dd77db2..8cd2eaa4 100644 --- a/optimizer/execution_plans/part0/eg1.lst +++ b/optimizer/execution_plans/part0/eg1.lst @@ -1,9 +1,28 @@ SQL> @eg1 +SQL> column ename format a20 +SQL> column rname format a20 +SQL> +SQL> select e.ename,r.rname + 2 from employees e + 3 join roles r on (r.id = e.role_id) + 4 join departments d on (d.id = e.dept_id) + 5 where e.staffno <= 10 + 6 and d.dname in ('Department Name 1','Department Name 2'); ENAME RNAME -------------------- -------------------- Employee Name 1 Role Name 1 +SQL> +SQL> @plan +SQL> -- +SQL> -- An example of retrieving a useful SQL Execution Plan +SQL> -- +SQL> set linesize 220 tab off pagesize 1000 trims on +SQL> column plan_table_output format a120 +SQL> +SQL> SELECT * + 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'ALL +OUTLINE')); PLAN_TABLE_OUTPUT ------------------------------------------------------------------------------------------------------------------------ diff --git a/optimizer/execution_plans/part0/eg2.lst b/optimizer/execution_plans/part0/eg2.lst index 00fecf7e..2a032dd3 100644 --- a/optimizer/execution_plans/part0/eg2.lst +++ b/optimizer/execution_plans/part0/eg2.lst @@ -1,9 +1,29 @@ SQL> @eg2 +SQL> column ename format a20 +SQL> column rname format a20 +SQL> +SQL> select /*+ gather_plan_statistics */ + 2 e.ename,r.rname + 3 from employees e + 4 join roles r on (r.id = e.role_id) + 5 join departments d on (d.id = e.dept_id) + 6 where e.staffno <= 10 + 7 and d.dname in ('Department Name 1','Department Name 2'); ENAME RNAME -------------------- -------------------- Employee Name 1 Role Name 1 +SQL> +SQL> @stats +SQL> -- +SQL> -- Retrieving plan statistics and a useful plan +SQL> -- +SQL> set linesize 210 tab off pagesize 1000 trims on +SQL> column plan_table_output format a200 +SQL> +SQL> SELECT * + 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'ALLSTATS LAST ALL +OUTLINE')); PLAN_TABLE_OUTPUT -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- @@ -20,8 +40,8 @@ Plan hash value: 2341252972 | Id | Operation | Name | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time | A-Rows | A-Time | Buffers | OMem | 1Mem | Used-Mem | -------------------------------------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | | | 6 (100)| | 1 |00:00:00.01 | 28 | | | | -|* 1 | HASH JOIN | | 1 | 3 | 192 | 6 (0)| 00:00:01 | 1 |00:00:00.01 | 28 | 1448K| 1448K| 535K (0)| -|* 2 | HASH JOIN | | 1 | 3 | 147 | 4 (0)| 00:00:01 | 2 |00:00:00.01 | 17 | 2545K| 2545K| 804K (0)| +|* 1 | HASH JOIN | | 1 | 3 | 192 | 6 (0)| 00:00:01 | 1 |00:00:00.01 | 28 | 1448K| 1448K| 533K (0)| +|* 2 | HASH JOIN | | 1 | 3 | 147 | 4 (0)| 00:00:01 | 2 |00:00:00.01 | 17 | 2545K| 2545K| 768K (0)| |* 3 | TABLE ACCESS FULL| DEPARTMENTS | 1 | 2 | 42 | 2 (0)| 00:00:01 | 2 |00:00:00.01 | 7 | | | | |* 4 | TABLE ACCESS FULL| EMPLOYEES | 1 | 10 | 280 | 2 (0)| 00:00:01 | 10 |00:00:00.01 | 7 | | | | | 5 | TABLE ACCESS FULL | ROLES | 1 | 20 | 300 | 2 (0)| 00:00:01 | 20 |00:00:00.01 | 8 | | | | diff --git a/optimizer/execution_plans/part0/eg3.lst b/optimizer/execution_plans/part0/eg3.lst index ea9664fc..63df6272 100644 --- a/optimizer/execution_plans/part0/eg3.lst +++ b/optimizer/execution_plans/part0/eg3.lst @@ -1,12 +1,55 @@ SQL> @eg3 +SQL> column ename format a20 +SQL> column rname format a20 +SQL> +SQL> -- +SQL> -- Use this to capture a SQL_ID +SQL> -- +SQL> var sqlid varchar2(100) +SQL> +SQL> -- +SQL> -- Long running queries will be monitored automatically +SQL> -- so the hint won't always be required. In this case, +SQL> -- it's over very quickly so I've added the hint. +SQL> -- +SQL> select /*+ MONITOR */ + 2 e.ename,r.rname + 3 from employees e + 4 join roles r on (r.id = e.role_id) + 5 join departments d on (d.id = e.dept_id) + 6 where e.staffno <= 10 + 7 and d.dname in ('Department Name 1','Department Name 2'); ENAME RNAME -------------------- -------------------- Employee Name 1 Role Name 1 +SQL> +SQL> -- +SQL> -- Get the SQL_ID of the last SQL statement we ran +SQL> -- +SQL> begin + 2 select prev_sql_id + 3 into :sqlid + 4 from v$session + 5 where sid=userenv('sid') + 6 and username is not null + 7 and prev_hash_value <> 0 + 8 and rownum<2; + 9 end; + 10 / PL/SQL procedure successfully completed. +SQL> +SQL> -- +SQL> -- Text first, then HTML +SQL> -- +SQL> set long 100000 pagesize 0 linesize 250 tab off trims on +SQL> column report format a230 +SQL> +SQL> select DBMS_SQL_MONITOR.REPORT_SQL_MONITOR (sql_id=>:sqlid, report_level=>'all', type=>'text') report + 2 from dual; SQL Monitoring Report SQL Text @@ -17,25 +60,25 @@ Global Information ------------------------------ Status : DONE (ALL ROWS) Instance ID : 1 - Session : ADHOC (44:61676) + Session : ADHOC (26:20218) SQL ID : an05rsj1up1k5 - SQL Execution ID : 16777228 - Execution Started : 03/16/2018 13:45:05 - First Refresh Time : 03/16/2018 13:45:05 - Last Refresh Time : 03/16/2018 13:45:05 - Duration : .001969s + SQL Execution ID : 16777229 + Execution Started : 04/18/2018 17:11:00 + First Refresh Time : 04/18/2018 17:11:00 + Last Refresh Time : 04/18/2018 17:11:00 + Duration : .003154s Module/Action : SQL*Plus/- Service : SYS$USERS Program : sqlplus@prod12c (TNS V1-V3) Fetch Calls : 2 Global Stats -======================================= -| Elapsed | Other | Fetch | Buffer | -| Time(s) | Waits(s) | Calls | Gets | -======================================= -| 0.00 | 0.00 | 2 | 28 | -======================================= +================================================= +| Elapsed | Cpu | Other | Fetch | Buffer | +| Time(s) | Time(s) | Waits(s) | Calls | Gets | +================================================= +| 0.00 | 0.00 | 0.00 | 2 | 28 | +================================================= SQL Plan Monitoring Details (Plan Hash Value=2341252972) ========================================================================================================================================== @@ -43,11 +86,14 @@ SQL Plan Monitoring Details (Plan Hash Value=2341252972) | | | | (Estim) | | Active(s) | Active | | (Actual) | (Max) | (%) | (# samples) | ========================================================================================================================================== | 0 | SELECT STATEMENT | | | | 1 | +0 | 1 | 1 | . | | | -| 1 | HASH JOIN | | 3 | 6 | 1 | +0 | 1 | 1 | 523KB | | | -| 2 | HASH JOIN | | 3 | 4 | 1 | +0 | 1 | 2 | 788KB | | | +| 1 | HASH JOIN | | 3 | 6 | 1 | +0 | 1 | 1 | 533KB | | | +| 2 | HASH JOIN | | 3 | 4 | 1 | +0 | 1 | 2 | 768KB | | | | 3 | TABLE ACCESS FULL | DEPARTMENTS | 2 | 2 | 1 | +0 | 1 | 2 | . | | | | 4 | TABLE ACCESS FULL | EMPLOYEES | 10 | 2 | 1 | +0 | 1 | 10 | . | | | | 5 | TABLE ACCESS FULL | ROLES | 20 | 2 | 1 | +0 | 1 | 20 | . | | | ========================================================================================================================================== +SQL> +SQL> set termout off feedback off +SQL> spool monitor_output.html diff --git a/optimizer/execution_plans/part0/eg4.lst b/optimizer/execution_plans/part0/eg4.lst index 9d4e4a70..7f1e3854 100644 --- a/optimizer/execution_plans/part0/eg4.lst +++ b/optimizer/execution_plans/part0/eg4.lst @@ -1,5 +1,38 @@ SQL> @eg4 +SQL> column ename format a20 +SQL> column rname format a20 +SQL> +SQL> var sqlid varchar2(100) +SQL> +SQL> select /* MY_TEST_QUERY */ + 2 e.ename,r.rname + 3 from employees e + 4 join roles r on (r.id = e.role_id) + 5 join departments d on (d.id = e.dept_id) + 6 where e.staffno <= 10 + 7 and d.dname in ('Department Name 1','Department Name 2'); Employee Name 1 Role Name 1 +SQL> +SQL> -- +SQL> -- In this example, let's search for the query +SQL> -- in V$SQL. We could do this in another session +SQL> -- while the query is executing. +SQL> -- +SQL> begin + 2 select sql_id + 3 into :sqlid + 4 from v$sql + 5 where sql_text like '%MY_TEST_QUERY%' + 6 and sql_text not like '%v$sql%' + 7 and rownum<2; + 8 end; + 9 / +SQL> +SQL> set long 100000 pagesize 0 linesize 250 tab off trims on +SQL> column plan_table_output format a230 +SQL> +SQL> SELECT * + 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(SQL_ID=>:sqlid,FORMAT=>'ALL +OUTLINE')); SQL_ID fzfk7qqax6chk, child number 0 ------------------------------------- select /* MY_TEST_QUERY */ e.ename,r.rname from employees e @@ -73,6 +106,5 @@ Column Projection Information (identified by operation id): "E"."ROLE_ID"[NUMBER,22] 5 - (rowset=256) "R"."ID"[NUMBER,22], "R"."RNAME"[VARCHAR2,100] -SQL> spoll off -SP2-0042: unknown command "spoll off" - rest of line ignored. +SQL> SQL> spool off diff --git a/optimizer/execution_plans/part0/eg5.lst b/optimizer/execution_plans/part0/eg5.lst index 7f8a48ee..169ffe25 100644 --- a/optimizer/execution_plans/part0/eg5.lst +++ b/optimizer/execution_plans/part0/eg5.lst @@ -1,5 +1,45 @@ SQL> @eg5 +SQL> column ename format a20 +SQL> column rname format a20 +SQL> +SQL> var sqlid varchar2(100) +SQL> +SQL> select /* MY_TEST_QUERY */ /*+ MONITOR */ + 2 e.ename,r.rname + 3 from employees e + 4 join roles r on (r.id = e.role_id) + 5 join departments d on (d.id = e.dept_id) + 6 where e.staffno <= 10 + 7 and d.dname in ('Department Name 1','Department Name 2'); Employee Name 1 Role Name 1 +SQL> +SQL> -- +SQL> -- In this example, let's search for the query +SQL> -- in V$SQL. We could do this in another session +SQL> -- while the query is executing. +SQL> -- +SQL> begin + 2 select sql_id + 3 into :sqlid + 4 from v$sql + 5 where sql_text like '%MY_TEST_QUERY%' + 6 and sql_text not like '%v$sql%' + 7 and rownum<2; + 8 end; + 9 / +SQL> +SQL> -- +SQL> -- Generate the SQL Monitor Report +SQL> -- +SQL> -- If the test query was long-running, we could run this +SQL> -- in a seperate SQL Plus session and watch the query's +SQL> -- progress. +SQL> -- +SQL> set long 100000 pagesize 0 linesize 250 tab off trims on +SQL> column report format a230 +SQL> +SQL> select DBMS_SQL_MONITOR.REPORT_SQL_MONITOR (sql_id=>:sqlid, report_level=>'all', type=>'text') report + 2 from dual; SQL Monitoring Report SQL Text @@ -10,25 +50,25 @@ Global Information ------------------------------ Status : DONE (ALL ROWS) Instance ID : 1 - Session : ADHOC (44:61676) + Session : ADHOC (26:20218) SQL ID : 1j5mhvb79631d - SQL Execution ID : 16777220 - Execution Started : 03/16/2018 13:45:23 - First Refresh Time : 03/16/2018 13:45:23 - Last Refresh Time : 03/16/2018 13:45:23 - Duration : .000591s + SQL Execution ID : 16777221 + Execution Started : 04/18/2018 17:11:54 + First Refresh Time : 04/18/2018 17:11:54 + Last Refresh Time : 04/18/2018 17:11:54 + Duration : .001999s Module/Action : SQL*Plus/- Service : SYS$USERS Program : sqlplus@prod12c (TNS V1-V3) Fetch Calls : 2 Global Stats -======================================= -| Elapsed | Other | Fetch | Buffer | -| Time(s) | Waits(s) | Calls | Gets | -======================================= -| 0.00 | 0.00 | 2 | 28 | -======================================= +====================================== +| Elapsed | Cpu | Fetch | Buffer | +| Time(s) | Time(s) | Calls | Gets | +====================================== +| 0.00 | 0.00 | 2 | 28 | +====================================== SQL Plan Monitoring Details (Plan Hash Value=2341252972) ========================================================================================================================================== @@ -36,11 +76,12 @@ SQL Plan Monitoring Details (Plan Hash Value=2341252972) | | | | (Estim) | | Active(s) | Active | | (Actual) | (Max) | (%) | (# samples) | ========================================================================================================================================== | 0 | SELECT STATEMENT | | | | 1 | +0 | 1 | 1 | . | | | -| 1 | HASH JOIN | | 3 | 6 | 1 | +0 | 1 | 1 | 545KB | | | -| 2 | HASH JOIN | | 3 | 4 | 1 | +0 | 1 | 2 | 837KB | | | +| 1 | HASH JOIN | | 3 | 6 | 1 | +0 | 1 | 1 | 534KB | | | +| 2 | HASH JOIN | | 3 | 4 | 1 | +0 | 1 | 2 | 848KB | | | | 3 | TABLE ACCESS FULL | DEPARTMENTS | 2 | 2 | 1 | +0 | 1 | 2 | . | | | | 4 | TABLE ACCESS FULL | EMPLOYEES | 10 | 2 | 1 | +0 | 1 | 10 | . | | | | 5 | TABLE ACCESS FULL | ROLES | 20 | 2 | 1 | +0 | 1 | 20 | . | | | ========================================================================================================================================== +SQL> SQL> spool off diff --git a/optimizer/execution_plans/part0/eg6.lst b/optimizer/execution_plans/part0/eg6.lst index 5f48bc17..08449010 100644 --- a/optimizer/execution_plans/part0/eg6.lst +++ b/optimizer/execution_plans/part0/eg6.lst @@ -1,5 +1,25 @@ SQL> @eg6 +SQL> column ename format a20 +SQL> column rname format a20 +SQL> +SQL> select /*+ PARALLEL (e 2) */ + 2 e.ename,r.rname + 3 from employees e + 4 join roles r on (r.id = e.role_id) + 5 join departments d on (d.id = e.dept_id) + 6 where e.staffno <= 10 + 7 and d.dname in ('Department Name 1','Department Name 2'); Employee Name 1 Role Name 1 +SQL> +SQL> @planp +SQL> -- +SQL> -- Displaying a parallel SQL execution plan +SQL> -- +SQL> set linesize 220 tab off pagesize 1000 trims on +SQL> column plan_table_output format a120 +SQL> +SQL> SELECT * + 2 FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'ALL +OUTLINE PARALLEL')); PLAN_TABLE_OUTPUT ------------------------------------------------------------------------------------------------------------------------ diff --git a/optimizer/execution_plans/part0/monitor_output.html b/optimizer/execution_plans/part0/monitor_output.html index 0358ba71..940fba6e 100644 --- a/optimizer/execution_plans/part0/monitor_output.html +++ b/optimizer/execution_plans/part0/monitor_output.html @@ -1,3 +1,5 @@ +SQL> select DBMS_SQL_MONITOR.REPORT_SQL_MONITOR (sql_id=>:sqlid, report_level=>'all', type=>'active') report + 2 from dual; @@ -19,76 +21,77 @@ +SQL> spool off diff --git a/optimizer/execution_plans/part0/plan.sql b/optimizer/execution_plans/part0/plan.sql index 6605385b..e757db9a 100644 --- a/optimizer/execution_plans/part0/plan.sql +++ b/optimizer/execution_plans/part0/plan.sql @@ -1,3 +1,6 @@ +-- +-- An example of retrieving a useful SQL Execution Plan +-- set linesize 220 tab off pagesize 1000 trims on column plan_table_output format a120 diff --git a/optimizer/execution_plans/part0/planp.sql b/optimizer/execution_plans/part0/planp.sql index bbbdd5c8..e31aff09 100644 --- a/optimizer/execution_plans/part0/planp.sql +++ b/optimizer/execution_plans/part0/planp.sql @@ -1,3 +1,6 @@ +-- +-- Displaying a parallel SQL execution plan +-- set linesize 220 tab off pagesize 1000 trims on column plan_table_output format a120 diff --git a/optimizer/execution_plans/part0/stats.sql b/optimizer/execution_plans/part0/stats.sql index f40cc255..d1e82a7f 100644 --- a/optimizer/execution_plans/part0/stats.sql +++ b/optimizer/execution_plans/part0/stats.sql @@ -1,5 +1,8 @@ +-- +-- Retrieving plan statistics and a useful plan +-- set linesize 210 tab off pagesize 1000 trims on column plan_table_output format a200 SELECT * -FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'ALLSTATS LAST ADVANCED')); +FROM table(DBMS_XPLAN.DISPLAY_CURSOR(FORMAT=>'ALLSTATS LAST ALL +OUTLINE')); diff --git a/optimizer/spm_in_practice/README.md b/optimizer/spm_in_practice/README.md index 5fd2e5f8..c5e0586b 100644 --- a/optimizer/spm_in_practice/README.md +++ b/optimizer/spm_in_practice/README.md @@ -8,25 +8,26 @@ Example output is shown in example.lst. **See also the README in the util directory.** -

example.lst

-* Flush shared pool -* Create a user called SPMTEST -* Call dropu.sql to drop SQL plan baselines for user SPMTEST -* Create a table called TAB1 -* Create index on table and gather stats -* Run a test query on TAB1 and capture the plan as a SQL plan baseline (from the cursor cache) -* Display SQL plan baselines for SPMTEST using listu.sql -* Display the SQL execution plan for the SQL plan baseline - it uses an index -* Execute the test query again and notice that the SQL plan baseline is being used and the plan uses the index -* Run nomatchu.sql and it identifies no "non-matching" SQL plan baselines for SPMTEST - all is well -* Drop the index! This makes it impossible to use the SQL plan baseline because the plan relies on the index! -* Run the test query again and notice that the plan is now a FULL table scan and the SQL plan baseline is NOT being honored (the SQL plan baseline is not shown in the plan "Notes" section). -* We can take a look of the OUTLINES in the SQL plan baseline and you will see it attempts: //INDEX(@"SEL$1" "TAB1"@"SEL$1" ("TAB1"."ID"))// - but the index is gone. -* Run nomatchu.sql and notice that it identifies the query that has an enabled and accepted plan but the SQL plan baseline is NOT being honored (SQL_PLAN_BASELINE is NULL) -* Look at the SQL plan baselines (using listu.sql) and see that there is a new non-accepted plan in the SQL plan history -* Run evou.sql to evolve the new plan (it's the FULl table scan plan) -* Run the test query again and this time a SQL plan baseline is used (look at "Notes" section) -* The script nomatchu.sql no longer identifies a SQL plan baseline not being honored. +*example.lst* + + * Flush shared pool + * Create a user called SPMTEST + * Call dropu.sql to drop SQL plan baselines for user SPMTEST + * Create a table called TAB1 + * Create index on table and gather stats + * Run a test query on TAB1 and capture the plan as a SQL plan baseline (from the cursor cache) + * Display SQL plan baselines for SPMTEST using listu.sql + * Display the SQL execution plan for the SQL plan baseline - it uses an index + * Execute the test query again and notice that the SQL plan baseline is being used and the plan uses the index + * Run nomatchu.sql and it identifies no "non-matching" SQL plan baselines for SPMTEST - all is well + * Drop the index! This makes it impossible to use the SQL plan baseline because the plan relies on the index! + * Run the test query again and notice that the plan is now a FULL table scan and the SQL plan baseline is NOT being honored (the SQL plan baseline is not shown in the plan "Notes" section). + * We can take a look of the OUTLINES in the SQL plan baseline and you will see it attempts: //INDEX(@"SEL$1" "TAB1"@"SEL$1" ("TAB1"."ID"))// - but the index is gone. + * Run nomatchu.sql and notice that it identifies the query that has an enabled and accepted plan but the SQL plan baseline is NOT being honored (SQL_PLAN_BASELINE is NULL) + * Look at the SQL plan baselines (using listu.sql) and see that there is a new non-accepted plan in the SQL plan history + * Run evou.sql to evolve the new plan (it's the FULl table scan plan) + * Run the test query again and this time a SQL plan baseline is used (look at "Notes" section) + * The script nomatchu.sql no longer identifies a SQL plan baseline not being honored. For background, check out https://blogs.oracle.com/optimizer/entry/how_to_use_sql_plan