From 4fe59aa121a534eeb55bb6feee3e89d19fa9481e Mon Sep 17 00:00:00 2001 From: Nirmala Sundarappa Date: Wed, 29 Mar 2017 23:49:15 -0700 Subject: [PATCH 1/5] Checking in files into JDBC and UCP files. --- .gitignore | 4 + java/jdbc/Readme.md | 113 +++++++ java/jdbc/build.xml | 160 +++++++++ .../UCPConnectionHarvestingSample.java | 304 ++++++++++++++++++ .../UCPConnectionLabelingSample.java | 259 +++++++++++++++ .../UCPSample.java | 157 +++++++++ .../UCPWithDRCPSample.java | 97 ++++++ java/ucp/Readme.md | 77 +++++ java/ucp/build.xml | 133 ++++++++ 9 files changed, 1304 insertions(+) create mode 100644 .gitignore create mode 100644 java/jdbc/Readme.md create mode 100644 java/jdbc/build.xml create mode 100644 java/ucp/ConnectionManagementSamples/UCPConnectionHarvestingSample.java create mode 100644 java/ucp/ConnectionManagementSamples/UCPConnectionLabelingSample.java create mode 100644 java/ucp/ConnectionManagementSamples/UCPSample.java create mode 100644 java/ucp/ConnectionManagementSamples/UCPWithDRCPSample.java create mode 100644 java/ucp/Readme.md create mode 100644 java/ucp/build.xml diff --git a/.gitignore b/.gitignore new file mode 100644 index 00000000..e87e1c64 --- /dev/null +++ b/.gitignore @@ -0,0 +1,4 @@ +.DS_Store +*.class +*.jar +classes/ diff --git a/java/jdbc/Readme.md b/java/jdbc/Readme.md new file mode 100644 index 00000000..d8b7fe6a --- /dev/null +++ b/java/jdbc/Readme.md @@ -0,0 +1,113 @@ +# 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. + +============================================================================ +## InternalT2Driver.sql & InternalT2Driver.java: +The server-side Type 2 (T2S) driver (aka KPRB driver) is for Java in the +database. It uses database session directly for accessing local data. +T2S driver is used for better performance because it cuts network traffic +between the Java code and the RDBMS SQL engine. + +## InternalT4Driver.sql & InternalT4Driver.java: +The server side Type 4(T4S) driver (aka thin/T4 driver) is used for code +running Java in database session needing access to another session either on +the same RDBMS instance/server or on a remote RDBMS instance/server. + +## DataSourceSample.java: +This sample shows how to connect to a simple DataSource +(oracle.jdbc.pool.OracleDataSource) and how to set connection related +properties such as `defaultRowPrefetch`, `defaultBatchValue` etc., + +## ProxySessionSample.java and ProxySessionSample.sql: +This sample shows connecting to the Oracle Database using Proxy +authentication or N-tier authentication. Proxy authentication is the +process of using a middle tier for user authentication. Proxy connections +can be created using any one of the following options. +(a) USER NAME: Done by supplying the user name or the password or both. +(b) DISTINGUISHED NAME: This is a global name in lieu of the password of +the user being proxied for. +(c) CERTIFICATE:More encrypted way of passing the credentials of the user, + who is to be proxied, to the database. + +## 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. + +## DRCPSample.java: +DRCP can be used with or without a client side connection pool. +Either UCP or any other third party connection pool (eg., C3P0) can be used as +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. + +============================================================================ + + diff --git a/java/jdbc/build.xml b/java/jdbc/build.xml new file mode 100644 index 00000000..6697a1d4 --- /dev/null +++ b/java/jdbc/build.xml @@ -0,0 +1,160 @@ + + + + + Build and run Oracle Jdbc Samples + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + Connection Management Samples: Commands to Run + ============================================== + (1) ant DataSourceSample + (2) ant ProxySessionSample + (3) ant UCPSample + (4) ant UCPWithDRCPSample + (5) ant DRCPSample + (6) ant UCPInactiveConnectionTimeout + (7) ant UCPConnectionWaitTimeout + (8) ant UCPAbandonedConnectionTimeout + (9) ant UCPAbandonedConnectionTimeout + (10) ant UCPTimeToLiveConnectionTimeout + (11) ant UCPConnectionHarvestingSample + (12) ant UCPConnectionLabelingSample + (13) ant UCPWebSessionAffinitySample + ============================================== + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + diff --git a/java/ucp/ConnectionManagementSamples/UCPConnectionHarvestingSample.java b/java/ucp/ConnectionManagementSamples/UCPConnectionHarvestingSample.java new file mode 100644 index 00000000..0e20187f --- /dev/null +++ b/java/ucp/ConnectionManagementSamples/UCPConnectionHarvestingSample.java @@ -0,0 +1,304 @@ +/* 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 new file mode 100644 index 00000000..18cd5e98 --- /dev/null +++ b/java/ucp/ConnectionManagementSamples/UCPConnectionLabelingSample.java @@ -0,0 +1,259 @@ +/* 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/UCPSample.java b/java/ucp/ConnectionManagementSamples/UCPSample.java new file mode 100644 index 00000000..e0f1423f --- /dev/null +++ b/java/ucp/ConnectionManagementSamples/UCPSample.java @@ -0,0 +1,157 @@ +/* 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:@(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 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 in seconds 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); + + // Set the JDBC connection properties after pool has been created + Properties connProps = new Properties(); + connProps.setProperty("fixedString", "false"); + connProps.setProperty("remarksReporting", "false"); + connProps.setProperty("restrictGetTables", "false"); + connProps.setProperty("includeSynonyms", "false"); + connProps.setProperty("defaultNChar", "false"); + connProps.setProperty("AccumulateBatchResult", "false"); + + // JDBC connection properties will be set on the provided + // connection factory. + pds.setConnectionProperties(connProps); + System.out.println("Available connections before checkout: " + + pds.getAvailableConnectionsCount()); + System.out.println("Borrowed connections before checkout: " + + pds.getBorrowedConnectionsCount()); + // 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/ucp/ConnectionManagementSamples/UCPWithDRCPSample.java new file mode 100644 index 00000000..d696948d --- /dev/null +++ b/java/ucp/ConnectionManagementSamples/UCPWithDRCPSample.java @@ -0,0 +1,97 @@ +/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ + +/* + DESCRIPTION + DRCP should be used in applications where there are multiple middle tiers + and the number of active connections in the middle tiers is fairly + lower than the number of open connections. This sample shows the steps + involved in accessing a Database using Database Resident Connection + Pool(DRCP) as the server side connection pool and Universal Connection + Pool(UCP) as the client side connection pool. DRCP features can be + optimized by front-ending with a client side pooling mechanism in either + middle or client tier. + + The purpose of the client-side pooling mechanism is to maintain liaison + or attachment to Connection Broker. Client-side connection pools must + attach and detach connections to the connection broker through + attachServerConnection() and detachServerConnection(). The benefit of + using UCP over third party client pool is that, UCP transparently takes + care of attaching and detaching server connections. + + Step 1: Enter the Database details in this file. + DB_USER, DB_PASSWORD and DRCP_URL are required. + A Sample DRCP URL is shown below. + DRCP_URL = jdbc:oracle:thin:@(DESCRIPTION=(ADDRESS_LIST=(ADDRESS= + (PROTOCOL=tcp)(HOST=proddbcluster)(PORT=25225))) + (CONNECT_DATA=(SERVICE_NAME=proddb))(server=POOLED)) + Step 2: Run the sample with "ant UCPWithDRCPSample" + + PRIVATE CLASSES + None + + NOTES + Use JDK 1.7 and above + + MODIFIED (MM/DD/YY) + nbsundar 02/17/15 - Creation + */ +import java.sql.Connection; +import java.sql.Statement; +import java.sql.ResultSet; +import java.sql.SQLException; + +import oracle.ucp.jdbc.PoolDataSource; +import oracle.ucp.jdbc.PoolDataSourceFactory; + +public class UCPWithDRCPSample { + final static String DRCP_URL= "jdbc:oracle:thin:@(DESCRIPTION=(ADDRESS=(HOST=myhost)(PORT=1521)(PROTOCOL=tcp))(CONNECT_DATA=(SERVICE_NAME=myorcldbservicename)(server=POOLED)))"; + final static String DB_USER = "hr"; + final static String DB_PASSWORD = "hr"; + final static String UCP_CONNFACTORY = "oracle.jdbc.pool.OracleDataSource"; + + /* + * The sample shows how to use DRCP with UCP. Make sure that correct + * connection URL is used and DRCP is enabled both on the server side + * and on the client side. + */ + static public void main(String args[]) throws SQLException { + PoolDataSource pds = PoolDataSourceFactory.getPoolDataSource(); + pds.setConnectionFactoryClassName(UCP_CONNFACTORY); + pds.setUser(DB_USER); + pds.setPassword(DB_PASSWORD); + // Make sure that DRCP_URL has (SERVER=POOLED) specified + pds.setURL(DRCP_URL); + pds.setConnectionPoolName("DRCP_UCP_Pool"); + + // Set UCP Properties + pds.setInitialPoolSize(1); + pds.setMinPoolSize(4); + pds.setMaxPoolSize(20); + + // Get the Database Connection from Universal Connection Pool. + try (Connection conn = pds.getConnection()) { + System.out.println("\nConnection obtained from UniversalConnectionPool"); + // Perform a database operation + doSQLWork(conn); + System.out.println("Connection returned to the UniversalConnectionPool"); + } + } + + /* + * Displays system date (sysdate). + */ + public static void doSQLWork(Connection connection) throws SQLException { + // Statement and ResultSet are auto-closable by this syntax + try (Statement statement = connection.createStatement()) { + try (ResultSet resultSet = statement + .executeQuery("select SYSDATE from DUAL")) { + while (resultSet.next()) + System.out.print("Today's date is " + resultSet.getString(1) + " "); + } + } + System.out.println("\n"); + } +} + + + diff --git a/java/ucp/Readme.md b/java/ucp/Readme.md new file mode 100644 index 00000000..f0aee486 --- /dev/null +++ b/java/ucp/Readme.md @@ -0,0 +1,77 @@ +# 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/build.xml b/java/ucp/build.xml new file mode 100644 index 00000000..2ddeac03 --- /dev/null +++ b/java/ucp/build.xml @@ -0,0 +1,133 @@ + + + + + + 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 + ============================================== + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + From 8c4c981a78dee9547e8b491d56e05df6bf7c0720 Mon Sep 17 00:00:00 2001 From: Nirmala Sundarappa Date: Thu, 30 Mar 2017 10:05:50 -0700 Subject: [PATCH 2/5] Checking in the JDBC changes. --- java/jdbc/build.xml | 80 +-------------------------------------------- 1 file changed, 1 insertion(+), 79 deletions(-) diff --git a/java/jdbc/build.xml b/java/jdbc/build.xml index 6697a1d4..30c79bc1 100644 --- a/java/jdbc/build.xml +++ b/java/jdbc/build.xml @@ -1,7 +1,7 @@ Build and run Oracle Jdbc Samples @@ -44,7 +39,6 @@ - @@ -66,17 +60,7 @@ ============================================== (1) ant DataSourceSample (2) ant ProxySessionSample - (3) ant UCPSample - (4) ant UCPWithDRCPSample (5) ant DRCPSample - (6) ant UCPInactiveConnectionTimeout - (7) ant UCPConnectionWaitTimeout - (8) ant UCPAbandonedConnectionTimeout - (9) ant UCPAbandonedConnectionTimeout - (10) ant UCPTimeToLiveConnectionTimeout - (11) ant UCPConnectionHarvestingSample - (12) ant UCPConnectionLabelingSample - (13) ant UCPWebSessionAffinitySample ============================================== @@ -90,71 +74,9 @@ - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - From c97a7704d4254968f3eb5d854e54c327acd1bbe5 Mon Sep 17 00:00:00 2001 From: Nirmala Sundarappa Date: Thu, 30 Mar 2017 10:46:42 -0700 Subject: [PATCH 3/5] Checking in the code samples under JDBC --- java/jdbc/Readme.md | 57 ++------------------------------------------- 1 file changed, 2 insertions(+), 55 deletions(-) diff --git a/java/jdbc/Readme.md b/java/jdbc/Readme.md index d8b7fe6a..67b01333 100644 --- a/java/jdbc/Readme.md +++ b/java/jdbc/Readme.md @@ -21,7 +21,7 @@ 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. -============================================================================ +---- ## InternalT2Driver.sql & InternalT2Driver.java: The server-side Type 2 (T2S) driver (aka KPRB driver) is for Java in the database. It uses database session directly for accessing local data. @@ -49,58 +49,6 @@ the user being proxied for. (c) CERTIFICATE:More encrypted way of passing the credentials of the user, who is to be proxied, to the database. -## 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. - ## DRCPSample.java: DRCP can be used with or without a client side connection pool. Either UCP or any other third party connection pool (eg., C3P0) can be used as @@ -108,6 +56,5 @@ 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. -============================================================================ - +---- From 7df487fbe8955e1764f002e89a5be0904f1a3418 Mon Sep 17 00:00:00 2001 From: Nirmala Sundarappa Date: Fri, 31 Mar 2017 14:12:03 -0700 Subject: [PATCH 4/5] Checking in JDBC samples and also Shared Pool examples. --- .../DRCPSample.java | 111 +++++++++++++++++ .../DataSourceSample.java | 100 +++++++++++++++ .../InternalT2Driver.java | 93 ++++++++++++++ .../InternalT2Driver.sql | 37 ++++++ .../InternalT4Driver.java | 86 +++++++++++++ .../InternalT4Driver.sql | 49 ++++++++ java/ucp/12.2Features/UCPSharedPool/Readme.md | 51 ++++++++ .../UCPSharedPool/SharedPoolCodeSample.java | 117 ++++++++++++++++++ .../UCPSharedPool/SharedPoolCodeSample.xml | 117 ++++++++++++++++++ 9 files changed, 761 insertions(+) create mode 100644 java/jdbc/ConnectionManagementSamples/DRCPSample.java create mode 100644 java/jdbc/ConnectionManagementSamples/DataSourceSample.java create mode 100644 java/jdbc/ConnectionManagementSamples/InternalT2Driver.java create mode 100644 java/jdbc/ConnectionManagementSamples/InternalT2Driver.sql create mode 100644 java/jdbc/ConnectionManagementSamples/InternalT4Driver.java create mode 100644 java/jdbc/ConnectionManagementSamples/InternalT4Driver.sql create mode 100644 java/ucp/12.2Features/UCPSharedPool/Readme.md create mode 100644 java/ucp/12.2Features/UCPSharedPool/SharedPoolCodeSample.java create mode 100644 java/ucp/12.2Features/UCPSharedPool/SharedPoolCodeSample.xml diff --git a/java/jdbc/ConnectionManagementSamples/DRCPSample.java b/java/jdbc/ConnectionManagementSamples/DRCPSample.java new file mode 100644 index 00000000..73d89868 --- /dev/null +++ b/java/jdbc/ConnectionManagementSamples/DRCPSample.java @@ -0,0 +1,111 @@ +/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ +/* + DESCRIPTION + The sample code shows how Java applications can connect to the Oracle + Database using Database Resident Connection Pool (DRCP) as the server + side connection pool which can be shared across multiple middle tiers + or clients. DRCP pools database server processes and sessions (the + combination is known as a "pooled server"). A Connection Broker manages + the "pooled servers" in the database instance. Upon a request from + the client, the connection broker picks the appropriate "pooled server" and + hands-off the client to that pooled server. The client directly + communicates with the "pooled server" for all its database activity. + The "pooled server" is handed back to the connection broker when the + client releases it. + + DRCP can be used with any third party client-side connection pool such as + DBCP, C3PO etc., Third party client side connection pools must attach and + detach connections explicitly to the connection broker through + attachServerConnection() and detachServerConnection(). They should also + set Connection Class as shown in the sample. + + Use-case for DRCP: DRCP should be used in applications when multiple middle + tiers are connected to the same database, DRCP allows you to share + server-side resources between the middle-tier's independent connection + pools. For more details on DRCP refer to JDBC Developer's guide + (https://docs.oracle.com/database/121/JJDBC/toc.htm) + + + PRE-REQUISITE: DRCP should be configured at the server side before using DRCP. + Refer to JDBC Developers Reference Guide for more details. The sample DRCP URL + shown below refers to the client side configuration of DRCP. + + Step 1: Enter the Database details in this file. + DB_USER, DB_PASSWORD and DRCP_URL are required. + A Sample DRCP URL is shown below. (server=POOLED) identifies + that DRCP is enabled on the server side. + DRCP_URL = jdbc:oracle:thin:@(DESCRIPTION=(ADDRESS_LIST= + (ADDRESS=(PROTOCOL=tcp)(HOST=proddbcluster)(PORT=5521))) + (CONNECT_DATA=(SERVICE_NAME=proddb)(server=POOLED))) + Step 2: Run the sample with "ant DRCPSample" + + NOTES + Use JDK 1.7 and above + + MODIFIED (MM/DD/YY) + nbsundar 03/02/15 - Creation + */ +import java.sql.Connection; +import java.sql.Statement; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.util.Properties; + +import oracle.jdbc.OracleConnection; +import oracle.jdbc.pool.OracleDataSource; +/* + * The method shows how to use DRCP when a third party client side connection + * pool is used. Make sure that connection URL used is correct and DRCP is + * configured both at the server side and client side. + */ +public class DRCPSample { + final static String DRCP_URL= "jdbc:oracle:thin:@(DESCRIPTION=(ADDRESS=(HOST=myhost)(PORT=1521)(PROTOCOL=tcp))(CONNECT_DATA=(SERVICE_NAME=myorcldbservicename)(server=POOLED)))"; + final static String DB_USER = "hr"; + final static String DB_PASSWORD = "hr"; + + static public void main(String args[]) throws SQLException { + // Create an OracleDataSource instance and set properties + OracleDataSource ods = new OracleDataSource(); + ods.setUser(DB_USER); + ods.setPassword(DB_PASSWORD); + // Make sure to use the correct DRCP URL. Refer to sample DRCP URL. + ods.setURL(DRCP_URL); + // "Connection class" allows dedicating a subset of pooled server to + // a specific application. Several connection classes may be + // used for different applications + Properties connproperty = new Properties(); + connproperty.setProperty("oracle.jdbc.DRCPConnectionClass", + "DRCP_connect_class"); + ods.setConnectionProperties(connproperty); + + // AutoCloseable: Closes a resource that is no longer needed. + // With AutoCloseable, the connection is closed automatically. + try (OracleConnection connection = (OracleConnection) (ods.getConnection())) { + System.out.println("DRCP enabled: " + connection.isDRCPEnabled()); + // Explicitly attaching the connection before its use + // Required when the client side connection pool is not UCP + connection.attachServerConnection(); + // Perform any database operation + doSQLWork(connection); + // Explicitly detaching the connection + // Required when the client side connection pool is not UCP + connection.detachServerConnection((String) null); + } + } + /* + * Displays system date(sysdate). Shows a simple database operation. + */ + public static void doSQLWork(Connection connection) throws SQLException { + // Statement and ResultSet are AutoCloseable by this syntax + try (Statement statement = connection.createStatement()) { + try (ResultSet resultSet = statement + .executeQuery("select SYSDATE from DUAL")) { + while (resultSet.next()) + System.out.print("Today's date is " + resultSet.getString(1) + " "); + } + } + System.out.println("\n"); + } +} + + diff --git a/java/jdbc/ConnectionManagementSamples/DataSourceSample.java b/java/jdbc/ConnectionManagementSamples/DataSourceSample.java new file mode 100644 index 00000000..a1e10e4e --- /dev/null +++ b/java/jdbc/ConnectionManagementSamples/DataSourceSample.java @@ -0,0 +1,100 @@ +/* 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 connection + to the Database. You can specify properties with "setConnectionProperties". + This is the recommended way to create connections to the Database. + + 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 DataSourceSample" + + 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 DataSourceSample { + // The recommended format of a connection URL is the long format with the + // connection descriptor. + 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"; + + /* + * The method gets a database connection using + * oracle.jdbc.pool.OracleDataSource. It also sets some connection + * level properties, such as, + * OracleConnection.CONNECTION_PROPERTY_DEFAULT_ROW_PREFETCH, + * OracleConnection.CONNECTION_PROPERTY_THIN_NET_CHECKSUM_TYPES, etc., + * There are many other connection related properties. 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); + info.put(OracleConnection.CONNECTION_PROPERTY_DEFAULT_ROW_PREFETCH, "20"); + info.put(OracleConnection.CONNECTION_PROPERTY_THIN_NET_CHECKSUM_TYPES, + "(MD5,SHA1,SHA256,SHA384,SHA512)"); + info.put(OracleConnection.CONNECTION_PROPERTY_THIN_NET_CHECKSUM_LEVEL, + "REQUIRED"); + + 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 first_name, last_name from employees")) { + System.out.println("FIRST_NAME" + " " + "LAST_NAME"); + System.out.println("---------------------"); + while (resultSet.next()) + System.out.println(resultSet.getString(1) + " " + + resultSet.getString(2) + " "); + } + } + } +} + + diff --git a/java/jdbc/ConnectionManagementSamples/InternalT2Driver.java b/java/jdbc/ConnectionManagementSamples/InternalT2Driver.java new file mode 100644 index 00000000..df71f4ee --- /dev/null +++ b/java/jdbc/ConnectionManagementSamples/InternalT2Driver.java @@ -0,0 +1,93 @@ +/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ +/* + DESCRIPTION + The server-side Type 2 (T2S) driver (aka KPRB driver) is for Java in the + database. Java running in the database session uses the KPRB driver or + T2S driver to access data, locally. + We furnish the server-side thin JDBC (aka Type 4 server driver) for + accessing data in other session in the same database or a remote Oracle + database. + + Step 1: Connect to SQLPLUS using the database USER/PASSWORD. + Make sure to have InternalT2Driver.sql accessible on the + client side to execute. + Step 2: Run the SQL file after connecting to DB "@InternalT2Driver.sql" + + NOTES + Use JDK 1.6 and above + + MODIFIED (MM/DD/YY) + nbsundar 03/23/15 - Creation (kmensah - Contributor) + */ +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; + +import oracle.jdbc.driver.OracleDriver; +import oracle.jdbc.pool.OracleDataSource; + + +public class InternalT2Driver { + + static public void jrun() throws SQLException { + // For testing InternalT2Driver + // test("jdbc:oracle:kprb:@"); + test("jdbc:default:connection"); + } + /* + * Shows using the server side Type 2 driver a.k.a KPRB driver + */ + static public void test(String url) throws SQLException { + Connection connection = null; + try { + System.out.println("Connecting to URL " + url); + // Method 1: Using OracleDataSource + OracleDataSource ods = new OracleDataSource(); + ods.setURL(url); + connection = ods.getConnection(); + System.out.println("Method 1: Getting Default Connection " + + "using OracleDataSource"); + // Perform database operation + printEmployees(connection); + + // Method 2: Using defaultConnection() method + OracleDriver ora = new OracleDriver(); + connection = ora.defaultConnection(); + System.out.println("Method 2: Getting Default Connection " + + "using OracleDriver"); + // Perform database operation + printEmployees(connection); + } + finally { + if (connection != null) connection.close(); + } + } + + /* + * Displays employee_id and first_name from the employees table. + */ + static public void printEmployees(Connection connection) throws SQLException { + ResultSet resultSet = null; + Statement statement = null; + try { + statement = connection.createStatement(); + resultSet = statement.executeQuery("SELECT employee_id, first_name FROM " + + "employees order by employee_id"); + while (resultSet.next()) { + System.out.println("Emp no: " + resultSet.getInt(1) + " Emp name: " + + resultSet.getString(2)); + } + } + catch (SQLException ea) { + System.out.println("Error during execution: " + ea); + ea.printStackTrace(); + } + finally { + if (resultSet != null) resultSet.close(); + if (statement != null) statement.close(); + } + } +} + + diff --git a/java/jdbc/ConnectionManagementSamples/InternalT2Driver.sql b/java/jdbc/ConnectionManagementSamples/InternalT2Driver.sql new file mode 100644 index 00000000..8f3e2964 --- /dev/null +++ b/java/jdbc/ConnectionManagementSamples/InternalT2Driver.sql @@ -0,0 +1,37 @@ +Rem InternalT2Driver.sql +Rem +Rem Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved. +Rem +Rem NAME +Rem InternalT2Driver.sql +Rem +Rem DESCRIPTION +Rem SQL for invoking the method which gets a server side connection to +Rem internal T2 Driver +Rem +Rem MODIFIED (MM/DD/YY) +Rem nbsundar 03/23/15 - Created +Rem kmensah 03/23/15 - Contributor + +rem Reads the content of the Java source from InternalT2Driver.java +rem then compiles it +connect hr/hr +CREATE OR REPLACE AND COMPILE JAVA SOURCE NAMED InternalT2Driver_src AS +@ InternalT2Driver.java +/ + +show error + +rem A wrapper (a.k.a. Call Spec), to invoke Java +rem function in the database from SQL, PL/SQL, and client applications +CREATE OR REPLACE PROCEDURE InternalT2Driver_proc AS +LANGUAGE JAVA NAME 'InternalT2Driver.jrun ()'; +/ + +rem Running the sample +connect hr/hr +SET SERVEROUTPUT ON SIZE 10000 +CALL dbms_java.set_output (10000); + +execute InternalT2Driver_proc; + diff --git a/java/jdbc/ConnectionManagementSamples/InternalT4Driver.java b/java/jdbc/ConnectionManagementSamples/InternalT4Driver.java new file mode 100644 index 00000000..dcf95369 --- /dev/null +++ b/java/jdbc/ConnectionManagementSamples/InternalT4Driver.java @@ -0,0 +1,86 @@ +/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ +/* + DESCRIPTION + The server side Type 4 driver (T4S) is used for code that runs in database + session and needs access to another session either on + the same RDBMS instance/server or on a remote RDBMS instance/server. + + Step 1: Connect to SQLPLUS using the database USER/PASSWORD. + Make sure to have InternalT4Driver.sql accessible on the + client side to execute. + Step 2: Run the SQL file after connecting to DB "@InternalT4Driver.sql" + + NOTES + Use JDK 1.6 and above + + MODIFIED (MM/DD/YY) + nbsundar 03/31/15 - Creation (kmensah - Contributor) + */ + +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; + +import oracle.jdbc.driver.OracleDriver; +import oracle.jdbc.pool.OracleDataSource; + +public class InternalT4Driver { + /* + * Demonstrates how to get a standard JDBC connection from + * Java running within the database. + */ + static public void jrun() throws SQLException { + // For testing InternalT4Driver + test("jdbc:oracle:thin:hr/hr@(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp) " + +"(HOST=localhost)(PORT=5521))(CONNECT_DATA=" + +"(SERVICE_NAME=proddbcluster)))"); + } + + /* + * Gets a database connection and prints information from + * employees table + */ + static public void test(String url) throws SQLException { + Connection connection = null; + try { + System.out.println("Connecting to URL " + url); + // Using OracleDataSource + OracleDataSource ods = new OracleDataSource(); + ods.setURL(url); + connection = ods.getConnection(); + System.out.println("Getting Default Connection " + + "using OracleDataSource"); + printEmployees(connection); + } + finally { + if (connection != null) connection.close(); + } + + } + + /* + * Displays employee_id and first_name from the employees table. + */ + static public void printEmployees(Connection connection) throws SQLException { + ResultSet resultSet = null; + Statement statement = null; + try { + statement = connection.createStatement(); + resultSet = statement.executeQuery("SELECT employee_id, first_name FROM"+ + "employees order by employee_id"); + while (resultSet.next()) { + System.out.println("Emp no: " + resultSet.getInt(1) + " Emp name: " + + resultSet.getString(2)); + } + } catch (SQLException ea) { + System.out.println("Error during execution: " + ea); + ea.printStackTrace(); + } finally { + if (resultSet != null) resultSet.close(); + if (statement != null) statement.close(); + } + } +} + + diff --git a/java/jdbc/ConnectionManagementSamples/InternalT4Driver.sql b/java/jdbc/ConnectionManagementSamples/InternalT4Driver.sql new file mode 100644 index 00000000..b56a4e71 --- /dev/null +++ b/java/jdbc/ConnectionManagementSamples/InternalT4Driver.sql @@ -0,0 +1,49 @@ +Rem InternalT4Driver.sql +Rem +Rem Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved. +Rem +Rem NAME +Rem InternalT4Driver.sql +Rem +Rem DESCRIPTION +Rem SQL for invoking the method which connects to server side JDBC thin +Rem driver or server side Type 4 sriver. +Rem +Rem MODIFIED (MM/DD/YY) +Rem nbsundar 03/31/15 - Created +Rem kmensah 03/31/15 - Contributor + +connect / as sysdba + +Rem Permissions for Connecting to another DB session via thin-driver in the server +Rem Most of these are network privileges +Rem Make sure to change the host name and IP:Port number +CALL dbms_java.grant_permission( 'HR','SYS:java.net.SocketPermission', +'slc07qwu', 'resolve'); +CALL dbms_java.grant_permission( 'HR','SYS:java.net.SocketPermission', + '10.244.140.89:5521', 'connect,resolve'); +CALL dbms_java.grant_permission( 'HR','SYS:java.sql.SQLPermission', +'setLog', '' ); + + +Rem Compiling the sources in the server +connect hr/hr +CREATE OR REPLACE AND COMPILE JAVA SOURCE NAMED InternalT4Driver_src AS +@ InternalT4Driver.java +/ + +show error + +Rem A wrapper (a.k.a. Call Spec), to invoke Java +Rem function in the database from SQL, PL/SQL, and client applications +CREATE OR REPLACE PROCEDURE InternalT4Driver_proc AS +LANGUAGE JAVA NAME 'InternalT4Driver.jrun ()'; +/ + +Rem Running the sample +connect hr/hr +SET SERVEROUTPUT ON SIZE 10000 +CALL dbms_java.set_output (10000); + +execute InternalT4Driver_proc; + diff --git a/java/ucp/12.2Features/UCPSharedPool/Readme.md b/java/ucp/12.2Features/UCPSharedPool/Readme.md new file mode 100644 index 00000000..e272c06b --- /dev/null +++ b/java/ucp/12.2Features/UCPSharedPool/Readme.md @@ -0,0 +1,51 @@ + +## Pre-requisites for using a 'Shared Pool': +1. Oracle Database 12c Release 2 (12.2) +2. Oracle JDBC driver 12.2 (ojdbc8.jar) +3. UCP 12.2 (ucp.jar) +4. JDK8 + +## Shared pool configuration Steps : + +# Shared pool works ONLY when it is configured with a common user (user starting with C##) and satisfies the following requirements. +1. Common user should have the privileges to create session, alter session and set container. +2. Common user should have execute permission on 'dbms_service_prvt' package. +3. Any specific roles or password for common user should also be specified in the UCP XML config file. + +# The shared pool sample code is using a Multi-tenant database environment with one CDB and two PDBs. +1. The code is using a CDB service name of 'cdb_root_app_service_name' and PDB service names of 'pdb1_app_service_name' and 'pdb2_app_service_name'. +2. You need to create these services in your database on respective CDBs and PDBs. +3. The services configured for tenants must be an application service. Also, services must be homogeneous (should have similar properties wrt AC, TG, DRCP etc.). + +# Create a common user and services as described above in your multi-tenant database and replace them in the SharedPoolCodeSample.xml file. + +# Create the table - tenant1_emp on tenant1 PDB and tenant2_emp on tenat2 PDB using below SQL queries. + +CREATE TABLE tenant1_emp(empno NUMBER(4,0), ename VARCHAR2(10), job VARCHAR2(9), sal NUMBER(7,2), CONSTRAINT pk_emp PRIMARY KEY (empno)); +INSERT INTO tenant1_emp VALUES (7782, 'CLARK', 'MANAGER', 2450); +INSERT INTO tenant1_emp VALUES (8180, 'JONES', 'ANALYST', 2050); +INSERT INTO tenant1_emp VALUES (8543, 'FORD', 'CLERK', 2150); +INSERT INTO tenant1_emp VALUES (8765, 'SMITH', 'MANAGER', 1000); +INSERT INTO tenant1_emp VALUES (9847, 'ALLEN', 'ANALYST', 2000); +COMMIT; + +CREATE TABLE tenant2_emp(empno NUMBER(4,0), ename VARCHAR2(10), job VARCHAR2(9), sal NUMBER(7,2), CONSTRAINT pk_emp PRIMARY KEY (empno)); +INSERT INTO tenant2_emp VALUES (1245, 'WARD', 'SALESMAN', 1450); +INSERT INTO tenant2_emp VALUES (3572, 'MARTIN', 'MANAGER', 2050); +INSERT INTO tenant2_emp VALUES (4533, 'TURNER', 'CLERK', 2150); +INSERT INTO tenant2_emp VALUES (3127, 'ADAMS', 'PRESIDENT', 8000); +INSERT INTO tenant2_emp VALUES (2276, 'JAMES', 'ANALYST', 2000); +COMMIT; + +# Make sure XML configuration file referred in code sample is present in the location specified by the URI. + Update the XML file location URI value in JAVA program to point it to correct location. + Change the user name, password, service names, URL according to your database setup. + +# Compile and Run the SharedPoolSampleCode.java class using JDK8. + +javac SharedPoolSampleCode.java +java SharedPoolSampleCode + + + + diff --git a/java/ucp/12.2Features/UCPSharedPool/SharedPoolCodeSample.java b/java/ucp/12.2Features/UCPSharedPool/SharedPoolCodeSample.java new file mode 100644 index 00000000..c6ce781b --- /dev/null +++ b/java/ucp/12.2Features/UCPSharedPool/SharedPoolCodeSample.java @@ -0,0 +1,117 @@ +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; + +import oracle.ucp.jdbc.PoolDataSource; +import oracle.ucp.jdbc.PoolDataSourceFactory; + +/** + * This sample code demonstrates the functionality of Multi-tenant shared pools. + * With the use of shared pools now it is possible for more than one tenant + * datasources to share a common pool provided they are connecting to the same + * database with a single url. To use shared pool functionality, all the tenant + * datasources accessing shared pools should be defined in UCP XML configuration + * file along with the pool properties. The code example shows how to get a + * connection from a shared pool defined in xml. + * + * The shared pool defined in sample XML config file has only one connection and + * both the tenant datasources -tenat1_ds and tenant2_ds are reusing the same + * connection to get the employee data from respective employee tables + * (tenant1_emp and tenant2_emp) present in tenant1 PDB and tenant2 PDB. + * + * + */ +public class SharedPoolCodeSample { + // UCP XML config file location URI + private static final String xmlFileURI = "file:/test/ucp/config/SharedPoolCodeSample.xml"; + + public static void main(String[] args) throws Exception { + System.out.println("Multi-Tenant shared pool configuration using XML"); + + // Java system property to specify the location of UCP XML configuration + // file which has shared pool, datasource properties defined in it. + System.setProperty("oracle.ucp.jdbc.xmlConfigFile", xmlFileURI); + + // The xml file used in this code example defines a connection pool with + // connection-pool-name -"pool1" and two tenant datasources with + // datasource-name as "tenant1_ds" and "tenant2_ds" which are using this + // shared pool. + + // Get the datasource instance named as "tenant1_ds" in XML config file + PoolDataSource tenant1_DS = PoolDataSourceFactory + .getPoolDataSource("tenant1_ds"); + + // Get a connection using tenant1 datasource + Connection tenant1Conn = tenant1_DS.getConnection(); + + // Run a query on the connection obtained using tenant1 datasource i.e. + // tenant1_ds + runQueryOnTenant1(tenant1Conn); + + // return tenant1 connection to the pool + tenant1Conn.close(); + + // Get the datasource instance named as "tenant2_ds" in XML config file + PoolDataSource tenant2_DS = PoolDataSourceFactory + .getPoolDataSource("tenant2_ds"); + + // Get a connection using tenant2 datasource + Connection tenant2Conn = tenant2_DS.getConnection(); + + // Run a query on the connection obtained using tenant2 datasource i.e. + // tenant2_ds + runQueryOnTenant2(tenant2Conn); + + // return tenant2 connection to the pool + tenant2Conn.close(); + + } + + /** + * Runs a query on the tenant1 table i.e. tenant1_emp to get the employee details + * using the given connection. + */ + private static void runQueryOnTenant1(Connection tenant1Conn) { + try { + String sql = "SELECT empno,ename FROM tenant1_emp"; + Statement st = tenant1Conn.createStatement(); + ResultSet rs = st.executeQuery(sql); + System.out.println("Teant1 Employee Details :"); + while (rs.next()) { + System.out.println("Employee ID = " + rs.getInt("empno") + + " Employee Name = " + rs.getString("ename")); + } + rs.close(); + st.close(); + + } catch (SQLException e) { + e.printStackTrace(); + } + + } + + /** + * Runs a query on the tenant2 table i.e. tenant2_emp to get the employee details + * using the given connection. + */ + private static void runQueryOnTenant2(Connection tenant2Conn) { + try { + String sql = "SELECT empno,ename FROM tenant2_emp"; + Statement st = tenant2Conn.createStatement(); + ResultSet rs = st.executeQuery(sql); + System.out.println("Teant2 Employee Details :"); + while (rs.next()) { + System.out.println("Employee ID = " + rs.getInt("empno") + + " Employee Name = " + rs.getString("ename")); + } + rs.close(); + st.close(); + + } catch (SQLException e) { + e.printStackTrace(); + } + + } + +} diff --git a/java/ucp/12.2Features/UCPSharedPool/SharedPoolCodeSample.xml b/java/ucp/12.2Features/UCPSharedPool/SharedPoolCodeSample.xml new file mode 100644 index 00000000..c6ce781b --- /dev/null +++ b/java/ucp/12.2Features/UCPSharedPool/SharedPoolCodeSample.xml @@ -0,0 +1,117 @@ +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; + +import oracle.ucp.jdbc.PoolDataSource; +import oracle.ucp.jdbc.PoolDataSourceFactory; + +/** + * This sample code demonstrates the functionality of Multi-tenant shared pools. + * With the use of shared pools now it is possible for more than one tenant + * datasources to share a common pool provided they are connecting to the same + * database with a single url. To use shared pool functionality, all the tenant + * datasources accessing shared pools should be defined in UCP XML configuration + * file along with the pool properties. The code example shows how to get a + * connection from a shared pool defined in xml. + * + * The shared pool defined in sample XML config file has only one connection and + * both the tenant datasources -tenat1_ds and tenant2_ds are reusing the same + * connection to get the employee data from respective employee tables + * (tenant1_emp and tenant2_emp) present in tenant1 PDB and tenant2 PDB. + * + * + */ +public class SharedPoolCodeSample { + // UCP XML config file location URI + private static final String xmlFileURI = "file:/test/ucp/config/SharedPoolCodeSample.xml"; + + public static void main(String[] args) throws Exception { + System.out.println("Multi-Tenant shared pool configuration using XML"); + + // Java system property to specify the location of UCP XML configuration + // file which has shared pool, datasource properties defined in it. + System.setProperty("oracle.ucp.jdbc.xmlConfigFile", xmlFileURI); + + // The xml file used in this code example defines a connection pool with + // connection-pool-name -"pool1" and two tenant datasources with + // datasource-name as "tenant1_ds" and "tenant2_ds" which are using this + // shared pool. + + // Get the datasource instance named as "tenant1_ds" in XML config file + PoolDataSource tenant1_DS = PoolDataSourceFactory + .getPoolDataSource("tenant1_ds"); + + // Get a connection using tenant1 datasource + Connection tenant1Conn = tenant1_DS.getConnection(); + + // Run a query on the connection obtained using tenant1 datasource i.e. + // tenant1_ds + runQueryOnTenant1(tenant1Conn); + + // return tenant1 connection to the pool + tenant1Conn.close(); + + // Get the datasource instance named as "tenant2_ds" in XML config file + PoolDataSource tenant2_DS = PoolDataSourceFactory + .getPoolDataSource("tenant2_ds"); + + // Get a connection using tenant2 datasource + Connection tenant2Conn = tenant2_DS.getConnection(); + + // Run a query on the connection obtained using tenant2 datasource i.e. + // tenant2_ds + runQueryOnTenant2(tenant2Conn); + + // return tenant2 connection to the pool + tenant2Conn.close(); + + } + + /** + * Runs a query on the tenant1 table i.e. tenant1_emp to get the employee details + * using the given connection. + */ + private static void runQueryOnTenant1(Connection tenant1Conn) { + try { + String sql = "SELECT empno,ename FROM tenant1_emp"; + Statement st = tenant1Conn.createStatement(); + ResultSet rs = st.executeQuery(sql); + System.out.println("Teant1 Employee Details :"); + while (rs.next()) { + System.out.println("Employee ID = " + rs.getInt("empno") + + " Employee Name = " + rs.getString("ename")); + } + rs.close(); + st.close(); + + } catch (SQLException e) { + e.printStackTrace(); + } + + } + + /** + * Runs a query on the tenant2 table i.e. tenant2_emp to get the employee details + * using the given connection. + */ + private static void runQueryOnTenant2(Connection tenant2Conn) { + try { + String sql = "SELECT empno,ename FROM tenant2_emp"; + Statement st = tenant2Conn.createStatement(); + ResultSet rs = st.executeQuery(sql); + System.out.println("Teant2 Employee Details :"); + while (rs.next()) { + System.out.println("Employee ID = " + rs.getInt("empno") + + " Employee Name = " + rs.getString("ename")); + } + rs.close(); + st.close(); + + } catch (SQLException e) { + e.printStackTrace(); + } + + } + +} From 4f50b449450d95448663b693388609c3f0bd05b6 Mon Sep 17 00:00:00 2001 From: Nirmala Sundarappa Date: Fri, 31 Mar 2017 14:18:01 -0700 Subject: [PATCH 5/5] Removed the "jdbc-ucp" folder --- java/jdbc-ucp | 1 - .../ProxySessionSample.java | 154 ++++++++++++++++++ .../ProxySessionSample.sql | 68 ++++++++ 3 files changed, 222 insertions(+), 1 deletion(-) delete mode 160000 java/jdbc-ucp create mode 100644 java/jdbc/ConnectionManagementSamples/ProxySessionSample.java create mode 100644 java/jdbc/ConnectionManagementSamples/ProxySessionSample.sql diff --git a/java/jdbc-ucp b/java/jdbc-ucp deleted file mode 160000 index 5e5c9270..00000000 --- a/java/jdbc-ucp +++ /dev/null @@ -1 +0,0 @@ -Subproject commit 5e5c92704bcd08ef6f655606b84848b5f20297bc diff --git a/java/jdbc/ConnectionManagementSamples/ProxySessionSample.java b/java/jdbc/ConnectionManagementSamples/ProxySessionSample.java new file mode 100644 index 00000000..99535d5d --- /dev/null +++ b/java/jdbc/ConnectionManagementSamples/ProxySessionSample.java @@ -0,0 +1,154 @@ +/* Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved.*/ + +/* + DESCRIPTION + The code sample demonstrates how to connect to the Oracle Database using + Proxy authentication or N-tier authentication. Proxy authentication is the + process of using a middle tier for user authentication. Proxy connections + can be created using any one of the following options. + (a) USER NAME: Done by supplying the user name or the password or both. + (b) DISTINGUISHED NAME: This is a global name in lieu of the password of + the user being proxied for. + (c) CERTIFICATE:More encrypted way of passing the credentials of the user, + who is to be proxied, to the database. + + Step 1: Connect to SQLPLUS using the database USER/PASSWORD. + Make sure to have ProxySessionSample.sql accessible to + execute from sqlplus. Update ProxySessionSample.sql with correct + SYSTEM username and password. + Step 2: Run the SQL file after connecting to DB "@ProxySessionSample.sql" + Step 3: Enter the Database details in this file. DB_URL is required. + Step 4: Run the sample with "ant ProxySessionSample" + + NOTES + Use JDK 1.7 and above + + MODIFIED (MM/DD/YY) + nbsundar 04/10/15 - creation + */ + +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; +import java.util.Properties; + +import oracle.jdbc.OracleConnection; +import oracle.jdbc.pool.OracleDataSource; + +class ProxySessionSample { + final static String DB_URL= "jdbc:oracle:thin:@(DESCRIPTION=(ADDRESS=(HOST=myhost)(PORT=1521)(PROTOCOL=tcp))(CONNECT_DATA=(SERVICE_NAME=myorcldbservicename)))"; + + /* + * The code sample shows how to connect to an Oracle Database + * using Proxy Session. The sample has the following: + * (a) A shared table, PROXY_ACCOUNT owned by user PROXY. + * (b) Users JEFF and SMITH have necessary roles for performing a SELECT, + * INSERT and DELETE on table PROXY_ACCOUNT owned by PROXY user, + * through the roles select_role, insert_role and delete_role. + * Note that select_role has SELECT, insert_role has INSERT and delete_role + * has DELETE privileges granted. + * + * The control flow in the sample is as follows: + * (1) Obtain a database connection of user PROXY. + * (2) Provide required privileges to users JEFF and SMITH to connect to the + * database through user PROXY. + * (3) Open a proxy session for users JEFF and SMITH. This does not open a + * new connection to the database instead uses the pre-existing connection + *(as user PROXY). The proxy session is established with the roles specified + * while opening the connection. + */ + public static void main(String args[]) throws SQLException { + OracleDataSource ods = new OracleDataSource(); + + // retrieve a database connection of user "proxy" + OracleConnection proxyConn = getConnection("proxy", "proxy", DB_URL, ods); + + // isProxySession is false before opening a proxy session + System.out.println("Before a proxy session is open, isProxySession: " + + proxyConn.isProxySession()); + // check if the user is "proxy" + checkUser(proxyConn); + + // open a proxy session for the user "jeff". + // This session reuses existing proxy session to connect as user, "jeff". + // There is no need to authenticate the user "jeff". + demoProxySession(proxyConn, "jeff"); + + // open a proxy session for the user "smith". + // This session reuses existing proxy session to connect as user "smith" + // There is no need to authenticate the user "smith". + demoProxySession(proxyConn, "smith"); + + // Close the proxy connection + proxyConn.close(); + } + /* + * Demonstrates the following: + * (1) Start a Proxy Session: Starts the proxy Session with corresponding + * roles and authenticates the users "jeff" or "smith". + * (2) Access Proxy user's table: The users "jeff" or "smith" can access + * the "proxy" user table, 'proxy_account' through the proxy session. + * (3) Close the Proxy Session: Close the proxy session for the user "jeff" + * or "smith". + */ + private static void demoProxySession(OracleConnection conn, String proxyUser) + throws SQLException { + Properties prop = new Properties(); + prop.put(OracleConnection.PROXY_USER_NAME, proxyUser); + // corresponds to the alter sql statement (select, insert roles) + String[] roles = { "select_role", "insert_role" }; + prop.put(OracleConnection.PROXY_ROLES, roles); + conn.openProxySession(OracleConnection.PROXYTYPE_USER_NAME, prop); + System.out.println("======= demoProxySession BEGIN ======="); + System.out.println("After the proxy session is open, isProxySession: " + + conn.isProxySession()); + // proxy session can act as users "jeff" & "smith" to access the + // user "proxy" tables + try (Statement stmt = conn.createStatement()) { + // Check who is the database user + checkUser(conn); + // play insert_role into proxy.proxy_account, go through + stmt.execute("insert into proxy.proxy_account values (1)"); + System.out.println("insert into proxy.proxy_account, allowed"); + // play select_role from proxy.proxy_account, go through + try (ResultSet rset = stmt.executeQuery("select * from " + + " proxy.proxy_account")) { + while (rset.next()) { + // display the execution results of a select query. + System.out.println(rset.getString(1)); + } + System.out.println("select * from proxy.proxy_account, allowed"); + // play delete_role from proxy.proxy_account, SQLException + stmt.execute("delete from proxy.proxy_account where purchase=1"); + } catch(Exception e) { + System.out.println("delete from proxy.proxy_account, not allowed"); + } + System.out.println("======= demoProxySession END ======="); + // Close the proxy session of user "jeff" + conn.close(OracleConnection.PROXY_SESSION); + } + } + /* + * Gets a database connection using a proxy user. + */ + private static OracleConnection getConnection(String user, String password, + String url, OracleDataSource ods) throws SQLException { + ods.setUser(user); + ods.setPassword(password); + ods.setURL(url); + return ((OracleConnection) ods.getConnection()); + } + /* + * Checks the database user. Note that the user will be proxy. + */ + private static void checkUser(Connection conn) throws SQLException { + try (Statement stmt = conn.createStatement()) { + try (ResultSet rset = stmt.executeQuery("select user from dual")) { + while (rset.next()) { + System.out.println("User is: " + rset.getString(1)); + } + } + } + } +} diff --git a/java/jdbc/ConnectionManagementSamples/ProxySessionSample.sql b/java/jdbc/ConnectionManagementSamples/ProxySessionSample.sql new file mode 100644 index 00000000..46c9aa96 --- /dev/null +++ b/java/jdbc/ConnectionManagementSamples/ProxySessionSample.sql @@ -0,0 +1,68 @@ +Rem ProxySessionSample.sql +Rem +Rem Copyright (c) 2015, Oracle and/or its affiliates. All rights reserved. +Rem +Rem NAME +Rem ProxySessionSample.sql - Complimentory SQL file for ProxySessionSample.java +Rem +Rem DESCRIPTION +Rem The sample shows connecting to the Oracle Database using Proxy authentication +Rem or N-tier authentication. +Rem +Rem MODIFIED (MM/DD/YY) +Rem nbsundar 04/10/15 - Created +Rem + +Rem This sample requires connecting as a system user that has the ability to +Rem create user and grant necessary privileges +connect system/manager + +Rem Clean up before creating necesary schema +drop role select_role; +drop role insert_role; +drop role delete_role; + +drop user jeff cascade; +drop user smith cascade; +drop user proxy cascade; + +Rem Create new database users "jeff", "smith" and "proxy" +create user proxy identified by proxy; +create user jeff identified by jeffpasswd; +create user smith identified by smithpasswd; + +Rem Grant necessary privileges to DB users "proxy", "jeff" and "smith" +grant create session, connect, resource, unlimited tablespace to proxy; +grant create session, connect, resource, unlimited tablespace to jeff; +grant create session, connect, resource, unlimited tablespace to smith; + +Rem Create roles and grant necessary roles to users "jeff" and "smith" +create role select_role; +create role insert_role; +create role delete_role; + +Rem Connect as a proxy user +connect proxy/proxy + +Rem Create the table which will be shared with the users "jeff" and "smith" +create table proxy_account (purchase number); +insert into proxy_account values(11); +insert into proxy_account values(13); + +Rem Grant the required privileges +grant select on proxy_account to select_role; +grant insert on proxy_account to insert_role; +grant delete on proxy_account to delete_role; + +Rem Connect as system user to grant necessary roles to the DB users "jeff" and "smith" +connect system/manager +grant select_role, insert_role, delete_role to jeff; +grant select_role, insert_role, delete_role to smith; + +Rem grant the users "jeff" and "smith" to connect through proxy with specified roles +alter user jeff grant connect through proxy with role select_role, insert_role; +alter user smith grant connect through proxy with role select_role, insert_role; + +commit; +exit +