Skip to content
Permalink
main
Switch branches/tags
Go to file
@cjbj
Latest commit 1dee266 Oct 21, 2021 History
1 contributor

Users who have contributed to this file

18587 lines (14082 sloc) 679 KB

node-oracledb 5.3 Documentation for the Oracle Database Node.js Add-on

Copyright (c) 2015, 2021, Oracle and/or its affiliates. All rights reserved.

You may not use the identified files except in compliance with the Apache License, Version 2.0 (the "License.")

You may obtain a copy of the License at http://www.apache.org/licenses/LICENSE-2.0.

Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.

See the License for the specific language governing permissions and limitations under the License.

===> *** Note: Go to https://oracle.github.io/node-oracledb/doc/api.html for production documentation ***

Manual Sections

This document contains:

For installation information, see the Node-oracledb Installation Instructions.

Contents

  1. Introduction
  2. Errors
  3. Oracledb Class
  4. Connection Class
  5. AqQueue Class
  6. DbObject Class
  7. Lob Class
  8. Pool Class
  9. PoolStatistics Class
  10. ResultSet Class
  11. SodaCollection Class
  12. SodaDatabase Class
  13. SodaDocument Class
  14. SodaDocumentCursor Class
  15. Initializing Node-oracledb
  16. Connection Handling
  17. SQL Execution
  18. PL/SQL Execution
  19. Working with CLOB, NCLOB and BLOB Data
  20. Oracle Database JSON Data Type
  21. Working with XMLType
  22. Bind Parameters for Prepared Statements
  23. Oracle Database Objects and Collections
  24. Batch Statement Execution and Bulk Loading
  25. Transaction Management
  26. Continuous Query Notification (CQN)
  27. Oracle Advanced Queuing (AQ)
  28. Globalization and National Language Support (NLS)
  29. End-to-end Tracing, Mid-tier Authentication, and Auditing
  30. Simple Oracle Document Access (SODA)
  31. Database Start Up and Shut Down
  32. Node-oracledb Tuning
  33. Tracing SQL and PL/SQL Statements
  34. Two-Phase Commits (TPC)
  35. Node.js Programming Styles and node-oracledb
  36. Migrating from Previous node-oracledb Releases
  37. Useful Resources for Node-oracledb

NODE-ORACLEDB API MANUAL

1. Introduction

The node-oracledb add-on for Node.js powers high performance Oracle Database applications. You can use node-oracledb in your Node.js TypeScript or JavaScript code. This lets you easily write complex applications, or build sopisticated web services using REST or GraphQL.

This document shows how to use node-oracledb. The API reference is in the first sections of this document and the user manual in subsequent sections. Also see the installation manual.

The node-oracledb API is a generic Oracle Database access layer. Almost all the functionality described here is common across all current Oracle Databases. However the documentation may describe some database features that are in specific Oracle Database versions, editions, or require additional database options or packs.

Node-oracledb Features

The node-oracledb feature highlights are:

  • Easily installed from npm
  • Support for Node.js 10 and later, and for multiple Oracle Database versions. (Note: older versions of node-oracledb supported older versions of Node.js)
  • Execution of SQL and PL/SQL statements, and access to SODA document-style access APIs.
  • Extensive Oracle data type support, including large objects (CLOB and BLOB) and binding of SQL objects
  • Connection management, including connection pooling
  • Oracle Database High Availability features
  • Full use of Oracle Network Service infrastructure, including encrypted network traffic and security features

A complete list of features can be seen here.

1.1 Node-oracledb Architecture

Node-oracledb is a Node.js add-on that allows Node.js applications to access Oracle Database. Node.js programs call node-oracledb functions. Internally node-oracledb dynamically loads Oracle Client libraries. Connections are made from node-oracledb to Oracle Database so SQL, PL/SQL, and SODA can be used.

node-oracledb Architecture

Node-oracledb is typically installed from the npm registry. The Oracle Client libraries need to be installed separately. The libraries can be obtained from an installation of Oracle Instant Client, from a full Oracle Client installation, or even from an Oracle Database installation (if Node.js is running on the same machine as the database). The versions of Oracle Client and Oracle Database do not have to be the same. Oracle Net is not a separate product: it is how the Oracle Client and Oracle Database communicate.

Some behaviors of the Oracle Client libraries can optionally be configured with an oraaccess.xml file, for example to enable auto-tuning of a statement cache. See Optional Oracle Client Configuration.

The Oracle Net layer can optionally be configured with files such as tnsnames.ora and sqlnet.ora, for example to enable network encryption. See Optional Oracle Net Configuration.

Oracle environment variables that are set before node-oracledb first creates a database connection will affect node-oracledb behavior. Optional variables include NLS_LANG, NLS_DATE_FORMAT and TNS_ADMIN. See Oracle Environment Variables.

1.2 Getting Started with Node-oracledb

Install Node.js from nodejs.org.

Install node-oracledb using the Quick Start Node-oracledb Installation steps. Node-oracledb runs in Node.js, typically as a mid-tier application server or service. Node-oracledb applications will not run directly in a browser.

Download node-oracledb examples or create a script like the one below. As well as Async/Await functions, node-oracledb can also use Callbacks, and Promises.

Locate your Oracle Database user name and password, and the database connection string. The connection string is commonly of the format hostname/servicename, using the host name where the database is running and the Oracle Database service name of the database instance.

Substitute your user name, password and connection string in the code. For downloaded examples, put these in dbconfig.js.

Run the script, for example:

node myscript.js

1.2.1 Example: A SQL SELECT statement in Node.js

// myscript.js
// This example uses Node 8's async/await syntax.

const oracledb = require('oracledb');

oracledb.outFormat = oracledb.OUT_FORMAT_OBJECT;

const mypw = ...  // set mypw to the hr schema password

async function run() {

  let connection;

  try {
    connection = await oracledb.getConnection( {
      user          : "hr",
      password      : mypw,
      connectString : "localhost/XEPDB1"
    });

    const result = await connection.execute(
      `SELECT manager_id, department_id, department_name
       FROM departments
       WHERE manager_id = :id`,
      [103],  // bind value for :id
    );
    console.log(result.rows);

  } catch (err) {
    console.error(err);
  } finally {
    if (connection) {
      try {
        await connection.close();
      } catch (err) {
        console.error(err);
      }
    }
  }
}

run();

With Oracle's sample HR schema, the output is:

[ { MANAGER_ID: 103, DEPARTMENT_ID: 60, DEPARTMENT_NAME: 'IT' } ]

1.2.2 Example: Simple Oracle Document Access (SODA) in Node.js

node-oracledb's SODA API can be used for document-style access with Oracle Database 18 and above, when node-oracledb uses Oracle Client 18.5 or Oracle Client 19.3, or later. Users require the CREATE TABLE privilege and the SODA_APP role.

// mysoda.js
// This example uses Node 8's async/await syntax.

const oracledb = require('oracledb');

const mypw = ...  // set mypw to the hr schema password

oracledb.autoCommit = true;

async function run() {

  let connection;

  try {
    connection = await oracledb.getConnection( {
      user          : "hr",
      password      : mypw,
      connectString : "localhost/orclpdb1"
    });

    // Create a new (or open an existing) document collection
    const soda = connection.getSodaDatabase();
    const collectionName = 'nodb_soda_collection';
    const myCollection = await soda.createCollection(collectionName);

    // Insert a new document
    const myContent = { name: "Sally", address: {city: "Melbourne"} };
    await myCollection.insertOne(myContent);

    // Print names of people living in Melbourne
    const filterSpec = { "address.city": "Melbourne" };
    const myDocuments = await myCollection.find().filter(filterSpec).getDocuments();
    myDocuments.forEach(function(element) {
      const content = element.getContent();
      console.log(content.name + ' lives in Melbourne.');
    });
  } catch(err) {
    console.log('Error in processing:\n', err);
  } finally {
    if (connection) {
      try {
        await connection.close();
      } catch(err) {
        console.log('Error in closing connection:\n', err);
      }
    }
  }
}

run();

Output is:

Sally lives in Melbourne.

2. Errors

The last parameter of each method is a callback, unless Promises or Async/Await are being used. The first parameter of the callback is an Error object that contains error information if the call fails. If the call succeeds, then the object is null.

When using Promises or Async/Await, the catch() error object will contain error information when a failure occurs.

If an invalid value is set for a property, then an error occurs. The same is true for invalid operations on read-only or write-only properties. If an unrecognized property name is used, it will be ignored.

2.1 Error Properties

The Error object contains errorNum, message and offset properties.

2.1.1 errorNum

Number errorNum

The Oracle error number. This value is undefined for non-Oracle errors and for messages prefixed with NJS or DPI.

2.1.2 message

String message

The text of the error message.

The error may be a standard Oracle message with a prefix like ORA or PLS. Alternatively it may be a node-oracledb specific error prefixed with NJS or DPI.

A single line error message may look like this:

ORA-01017: invalid username/password; logon denied

A multi-line error message may look like this:

ORA-06550: line 1, column 7:
PLS-00201: identifier 'TESTPRC' must be declared
ORA-06550: line 1, column 7:
PL/SQL: Statement ignored

2.1.3 offset

Number offset

Generally offset is the character offset into the SQL text that resulted in the Oracle error. The value may be 0 in non-SQL contexts. This value is undefined for non-Oracle errors and for messages prefixed with NJS or DPI.

When batchErrors mode in executeMany() returns an array of Error objects in the callback result parameter, each offset property is a 0-based index corresponding to the executeMany() binds parameter array, indicating which record could not be processed. See Handling Data Errors. In node-oracledb 4.2, the maximum offset value was changed from (2^16)-1 to (2^32)-1.

3. Oracledb Class

The Oracledb object is the factory class for Pool and Connection objects.

The Oracledb object is instantiated by loading node-oracledb:

const oracledb = require("oracledb");

Internally, the add-on creates the Oracledb object as a singleton. Reloading it in the same Node.js process creates a new pointer to the same object.

3.1 Oracledb Constants

These constants are defined in the oracledb module. Usage is described later in this document.

The numeric values for the constants are shown to aid debugging. They may change in future, so use the constant names in applications.

3.1.1 Query outFormat Constants

Constants for the query result outFormat option:

Constant Name Value Description
oracledb.OUT_FORMAT_ARRAY 4001 Fetch each row as array of column values
oracledb.OUT_FORMAT_OBJECT 4002 Fetch each row as an object

The oracledb.OUT_FORMAT_ARRAY and oracledb.OUT_FORMAT_OBJECT constants were introduced in node-oracledb 4.0. The previous constants oracledb.ARRAY and oracledb.OBJECT are deprecated but still usable.

3.1.2 Oracle Database Type Constants

Constants uses for database types in node-oracledb.

These values indicate the Oracle Database type in Extended metadata, DbObject types and in the Lob type property.

Some constants can also be used for:

Constant Name Value Database Data type
oracledb.DB_TYPE_BFILE 2020 BFILE
oracledb.DB_TYPE_BINARY_DOUBLE 2008 BINARY_DOUBLE
oracledb.DB_TYPE_BINARY_FLOAT 2007 BINARY_FLOAT
oracledb.DB_TYPE_BINARY_INTEGER 2009 BINARY_INTEGER, PLS_INTEGER, SMALLINT, etc.
oracledb.DB_TYPE_BLOB 2019 BLOB
oracledb.DB_TYPE_BOOLEAN 2022 PL/SQL BOOLEAN
oracledb.DB_TYPE_CHAR 2003 CHAR
oracledb.DB_TYPE_CLOB 2017 CLOB
oracledb.DB_TYPE_CURSOR 2021 SYS_REFCURSOR, Nested Cursors
oracledb.DB_TYPE_DATE 2011 DATE
oracledb.DB_TYPE_INTERVAL_DS 2015 INTERVAL DAY TO SECOND
oracledb.DB_TYPE_INTERVAL_YM 2016 INTERVAL YEAR TO MONTH
oracledb.DB_TYPE_JSON 2027 JSON (new in node-oracledb 5.1)
oracledb.DB_TYPE_LONG 2024 LONG
oracledb.DB_TYPE_LONG_RAW 2025 LONG RAW
oracledb.DB_TYPE_NCHAR 2004 NCHAR
oracledb.DB_TYPE_NCLOB 2018 NCLOB
oracledb.DB_TYPE_NUMBER 2010 NUMBER or FLOAT
oracledb.DB_TYPE_NVARCHAR 2002 NVARCHAR
oracledb.DB_TYPE_OBJECT 2023 OBJECT
oracledb.DB_TYPE_RAW 2006 RAW
oracledb.DB_TYPE_ROWID 2005 ROWID
oracledb.DB_TYPE_TIMESTAMP 2012 TIMESTAMP
oracledb.DB_TYPE_TIMESTAMP_LTZ 2014 TIMESTAMP WITH LOCAL TIME ZONE
oracledb.DB_TYPE_TIMESTAMP_TZ 2013 TIMESTAMP WITH TIME ZONE
oracledb.DB_TYPE_VARCHAR 2001 VARCHAR2

Note the values for these constants changed in node-oracledb 4.0.

3.1.3 Node-oracledb Type Constants

From node-oracledb 4.0, these constant values changed and became aliases for common Oracle Database Type Constants.

Constant Name Value DB_TYPE_* equivalent Notes
oracledb.BLOB 2019 oracledb.DB_TYPE_BLOB
oracledb.BUFFER 2006 oracledb.DB_TYPE_RAW
oracledb.CLOB 2017 oracledb.DB_TYPE_CLOB
oracledb.CURSOR 2021 oracledb.DB_TYPE_CURSOR
oracledb.DATE 2014 oracledb.DB_TYPE_TIMESTAMP_LTZ
oracledb.DEFAULT 0 n/a Used with fetchInfo to reset the fetch type to the database type
oracledb.NUMBER 2010 oracledb.DB_TYPE_NUMBER
oracledb.NCLOB 2018 oracledb.DB_TYPE_NCLOB Constant added in node-oracledb 4.2
oracledb.STRING 2001 oracledb.DB_TYPE_VARCHAR

3.1.4 Execute Bind Direction Constants

Constants for the dir property of execute() bindParams, queryStream() and executeMany() bindDefs.

These specify whether data values bound to SQL or PL/SQL bind parameters are passed into, or out from, the database:

Constant Name Value Description
oracledb.BIND_IN 3001 Direction for IN binds
oracledb.BIND_INOUT 3002 Direction for IN OUT binds
oracledb.BIND_OUT 3003 Direction for OUT binds

3.1.5 Privileged Connection Constants

Constants for getConnection() privilege properties.

These specify what privilege should be used by the connection that is being established.

Constant Name Value Description
oracledb.SYSASM 32768 SYSASM privileges
oracledb.SYSBACKUP 131072 SYSBACKUP privileges
oracledb.SYSDBA 2 SYSDBA privileges
oracledb.SYSDG 262144 SYSDG privileges
oracledb.SYSKM 524288 SYSKM privileges
oracledb.SYSOPER 4 SYSOPER privileges
oracledb.SYSPRELIM 8 Preliminary privilege required when starting up a database with connection.startup(). Added in node-oracledb 5.0.
oracledb.SYSRAC 1048576 SYSRAC privileges

3.1.6 SQL Statement Type Constants

Constants for connection.getStatementInfo() properties.

Constant Name Value Description
oracledb.STMT_TYPE_ALTER 7 ALTER
oracledb.STMT_TYPE_BEGIN 8 BEGIN
oracledb.STMT_TYPE_CALL 10 CALL
oracledb.STMT_TYPE_COMMIT 21 COMMIT
oracledb.STMT_TYPE_CREATE 5 CREATE
oracledb.STMT_TYPE_DECLARE 9 DECLARE
oracledb.STMT_TYPE_DELETE 3 DELETE
oracledb.STMT_TYPE_DROP 6 DROP
oracledb.STMT_TYPE_EXPLAIN_PLAN 15 EXPLAIN PLAN
oracledb.STMT_TYPE_INSERT 4 INSERT
oracledb.STMT_TYPE_MERGE 16 MERGE
oracledb.STMT_TYPE_ROLLBACK 17 ROLLBACK
oracledb.STMT_TYPE_SELECT 1 SELECT
oracledb.STMT_TYPE_UNKNOWN 0 Unknown statement type
oracledb.STMT_TYPE_UPDATE 2 UPDATE

3.1.7 Subscription Constants

Constants for the Continuous Query Notification message.type.

Constant Name Value Description
oracledb.SUBSCR_EVENT_TYPE_AQ 100 Advanced Queuing notifications are being used
oracledb.SUBSCR_EVENT_TYPE_DEREG 5 A subscription has been closed or the timeout value has been reached
oracledb.SUBSCR_EVENT_TYPE_OBJ_CHANGE 6 Object-level notifications are being used (Database Change Notification)
oracledb.SUBSCR_EVENT_TYPE_QUERY_CHANGE 7 Query-level notifications are being used (Continuous Query Notification)
oracledb.SUBSCR_EVENT_TYPE_SHUTDOWN 2 The database is being shut down
oracledb.SUBSCR_EVENT_TYPE_SHUTDOWN_ANY 3 An instance of Oracle Real Application Clusters (RAC) is being shut down
oracledb.SUBSCR_EVENT_TYPE_STARTUP 1 The database is being started up

Constant for the Continuous Query Notification groupingClass.

Constant Name Value Description
oracledb.SUBSCR_GROUPING_CLASS_TIME 1 Group notifications by time into a single notification

Constants for the Continuous Query Notification groupingType.

Constant Name Value Description
oracledb.SUBSCR_GROUPING_TYPE_LAST 2 The last notification in the group is sent
oracledb.SUBSCR_GROUPING_TYPE_SUMMARY 1 A summary of the grouped notifications is sent

Constants for the Continuous Query Notification qos Quality of Service.

Constant Name Value Description
oracledb.SUBSCR_QOS_BEST_EFFORT 16 When best effort filtering for query result set changes is acceptable. False positive notifications may be received. This behavior may be suitable for caching applications.
oracledb.SUBSCR_QOS_DEREG_NFY 2 The subscription will be automatically unregistered as soon as the first notification is received.
oracledb.SUBSCR_QOS_QUERY 8 Continuous Query Notification will be used instead of Database Change Notification. This means that notifications are only sent if the result set of the registered query changes. By default no false positive notifications are generated. Use oracledb.SUBSCR_QOS_BEST_EFFORT if this is not needed.
oracledb.SUBSCR_QOS_RELIABLE 1 Notifications are not lost in the event of database failure.
oracledb.SUBSCR_QOS_ROWIDS 4 Notifications include the ROWIDs of the rows that were affected

Constants for the Continuous Query Notification namespace.

Constant Name Value Description
oracledb.SUBSCR_NAMESPACE_AQ 1 For Advanced Queuing notifications.
oracledb.SUBSCR_NAMESPACE_DBCHANGE 2 For Continuous Query Notifications.

3.1.8 Advanced Queuing Constants

Refer to Advanced Queuing documentation for more details about attributes.

Constants for AqDeqOptions Class mode.

Constant Name Value Description
oracledb.AQ_DEQ_MODE_BROWSE 1 Read a message without acquiring a lock.
oracledb.AQ_DEQ_MODE_LOCKED 2 Read and obtain write lock on message.
oracledb.AQ_DEQ_MODE_REMOVE 3 Read the message and delete it.
oracledb.AQ_DEQ_MODE_REMOVE_NO_DATA 4 Delete message without returning payload.

Constants for AqDeqOptions Class navigation.

Constant Name Value Description
oracledb.AQ_DEQ_NAV_FIRST_MSG 1 Get the message at the head of queue.
oracledb.AQ_DEQ_NAV_NEXT_TRANSACTION 2 Get first message of next transaction group.
oracledb.AQ_DEQ_NAV_NEXT_MSG 3 Get the next message in the queue.

Constants for AqDeqOptions Class wait.

Constant Name Value Description
oracledb.AQ_DEQ_NO_WAIT 0 Do not wait if no message is available.
oracledb.AQ_DEQ_WAIT_FOREVER 4294967295 Wait forever if no message is available.

Constants for AqEnqOptions Class deliveryMode.

Constant Name Value Description
oracledb.AQ_MSG_DELIV_MODE_PERSISTENT 1 Messages are persistent.
oracledb.AQ_MSG_DELIV_MODE_BUFFERED 2 Messages are buffered.
oracledb.AQ_MSG_DELIV_MODE_PERSISTENT_OR_BUFFERED 3 Messages are either persistent or buffered.

Constants for AqMessage Class state.

Constant Name Value Description
oracledb.AQ_MSG_STATE_READY 0 Consumers can dequeue messages that are in the READY state.
oracledb.AQ_MSG_STATE_WAITING 1 Message is hidden for a given retry delay interval.
oracledb.AQ_MSG_STATE_PROCESSED 2 All intended consumers have successfully dequeued the message.
oracledb.AQ_MSG_STATE_EXPIRED 3 One or more consumers did not dequeue the message before the expiration time.

Constants for AqEnqOptions Class and AqDeqOptions Class visibility.

Constant Name Value Description
oracledb.AQ_VISIBILITY_IMMEDIATE 1 The message is not part of the current transaction. It constitutes a transaction on its own.
oracledb.AQ_VISIBILITY_ON_COMMIT 2 The message is part of the current transaction.

3.1.9 Continuous Query Notification Constants

Constants for the Continuous Query Notification connection.subscribe() option operations, and for the notification message operation properties.

Constant Name Value Description
oracledb.CQN_OPCODE_ALL_OPS 0 Default. Used to request notification of all operations.
oracledb.CQN_OPCODE_ALL_ROWS 1 Indicates that row information is not available. This occurs if the qos quality of service flags do not specify the desire for ROWIDs, or if grouping has taken place and summary notifications are being sent.
oracledb.CQN_OPCODE_ALTER 16 Set if the table was altered in the notifying transaction
oracledb.CQN_OPCODE_DELETE 8 Set if the notifying transaction included deletes on the table
oracledb.CQN_OPCODE_DROP 32 Set if the table was dropped in the notifying transaction
oracledb.CQN_OPCODE_INSERT 2 Set if the notifying transaction included inserts on the table
oracledb.CQN_OPCODE_UPDATE 4 Set if the notifying transaction included updates on the table

3.1.10 Pool Status Constants

Constants for the connection pool.status readonly attribute.

Constant Name Value Description
oracledb.POOL_STATUS_CLOSED 6002 The connection pool has been closed.
oracledb.POOL_STATUS_DRAINING 6001 The connection pool is being drained of in-use connections and will be force closed soon.
oracledb.POOL_STATUS_OPEN 6000 The connection pool is open.
oracledb.POOL_STATUS_RECONFIGURING 6003 A pool.reconfigure() call is processing.

3.1.11 Simple Oracle Document Access (SODA) Constants

Constant Name Value Description
oracledb.SODA_COLL_MAP_MODE 5001 Indicate sodaDatabase.createCollection() should use an externally created table to store the collection

3.1.12 Database Shutdown Constants

Constants for shutting down the Oracle Database with oracledb.shutdown() and connection.shutdown().

These are new in node-oracledb 5.

Constant Name Value Description
oracledb.SHUTDOWN_MODE_ABORT 4 All uncommitted transactions are terminated and not rolled back. This is the fastest way to shut down the database, but the next database start up may require instance recovery.
oracledb.SHUTDOWN_MODE_DEFAULT 0 Further connections to the database are prohibited. Wait for users to disconnect from the database.
oracledb.SHUTDOWN_MODE_FINAL 5 Used with a second connection.shutdown() to conclude the database shut down steps.
oracledb.SHUTDOWN_MODE_IMMEDIATE 3 All uncommitted transactions are terminated and rolled back and all connections to the database are closed immediately.
oracledb.SHUTDOWN_MODE_TRANSACTIONAL 1 Further connections to the database are prohibited and no new transactions are allowed to be started. Wait for active transactions to complete.
oracledb.SHUTDOWN_MODE_TRANSACTIONAL_LOCAL 2 Behaves the same way as SHUTDOWN_MODE_TRANSACTIONAL, but only waits for local transactions to complete.

3.1.12 Two-Phase Commit Constants

Constants for two-phase commit (TPC) functions connection.tpcBegin() and connection.tpcEnd().

These are new in node-oracledb 5.3.

Constant Name Value Description
oracledb.TPC_BEGIN_JOIN 2 Join an existing two-phase commit (TPC) transaction.
oracledb.TPC_BEGIN_NEW 1 Create a new TPC transaction.
oracledb.TPC_BEGIN_RESUME 4 Resume an existing TPC transaction.
oracledb.TPC_BEGIN_PROMOTE 8 Promote a local transaction to a TPC transaction.
oracledb.TPC_END_NORMAL 0 End the TPC transaction participation normally.
oracledb.TPC_END_SUSPEND 1048576 Suspend the TPC transaction.

3.2 Oracledb Properties

The properties of the Oracledb object are used for setting up configuration parameters for deployment.

If required, these properties can be overridden for the Pool or Connection objects.

These properties may be read or modified. If a property is modified, only subsequent invocations of the createPool() or getConnection() methods will be affected. Objects that exist before a property is modified are not altered.

Invalid values, or combinations of values, for pool configuration properties can result in the error ORA-24413: Invalid number of sessions specified.

Each of the configuration properties is described below.

3.2.1 oracledb.autoCommit

Boolean autoCommit

If this property is true, then the transaction in the current connection is automatically committed at the end of statement execution.

The default value is false.

This property may be overridden in an execute() call.

When using an external transaction manager with two-phase commits, autoCommit should be false.

Note prior to node-oracledb 0.5 this property was called isAutoCommit.

Example
const oracledb = require('oracledb');
oracledb.autoCommit = false;

3.2.2 oracledb.connectionClass

String connectionClass

The user-chosen Connection class value defines a logical name for connections. Most single purpose applications should set connectionClass when using a connection pool or DRCP.

When a pooled session has a connection class, Oracle ensures that the session is not shared outside of that connection class.

The connection class value is similarly used by Database Resident Connection Pooling (DRCP) to allow or disallow sharing of sessions.

For example, where two different kinds of users share one pool, you might set connectionClass to 'HRPOOL' for connections that access a Human Resources system, and it might be set to 'OEPOOL' for users of an Order Entry system. Users will only be given sessions of the appropriate class, allowing maximal reuse of resources in each case, and preventing any session information leaking between the two systems.

If connectionClass is set for a non-pooled connection, the driver name is not recorded in V$ views. See End-to-end Tracing, Mid-tier Authentication, and Auditing.

Example
const oracledb = require('oracledb');
oracledb.connectionClass = 'HRPOOL';

3.2.3 oracledb.dbObjectAsPojo

Boolean dbObjectAsPojo

Specify whether Oracle Database named objects or collections that are queried should be returned to the application as "plain old JavaScript objects" or kept as database-backed objects. This option also applies to output BIND_OUT bind variables.

Note that LOBs in objects will be represented as Lob instances and will not be String or Buffer, regardless of any fetchAsString, fetchAsBuffer, or fetchInfo setting.

The default value for dbObjectAsPojo is false.

Setting dbObjectAsPojo to true can avoid overhead if object attributes are repeatedly accessed. It also allows applications to close connections before any attributes are accessed unless LOBs are involved. Regardless of the value, the interface to access objects is the same.

Example
const oracledb = require('oracledb');
oracledb.dbObjectAsPojo = false;

3.2.4 oracledb.edition

String edition

Sets the name used for Edition-Based Redefinition by connections.

See Edition-Based Redefinition for more information.

This property was added in node-oracledb 2.2.

Example
const oracledb = require('oracledb');
oracledb.edition = 'ed_2';

3.2.5 oracledb.errorOnConcurrentExecute

Boolean errorOnConcurrentExecute

This property can be set to throw an error if concurrent operations are attempted on a single connection.

The default value for errorOnConcurrentExecute is false.

Each Oracle connection can only interact with the database for one operation at a time. Attempting to do more than one operation concurrently may be a sign of an incorrectly coded application, for example an await may be missing. Examples of operations that cannot be executed in parallel on a single connection include connection.execute(), connection.executeMany(), connection.queryStream(), connection.getDbObjectClass(), connection.commit(), connection.close(), SODA calls, and streaming from Lobs.

The value of this property does not affect using multiple connections. These may all be in use concurrently, and each can be doing one operation.

Leaving errorOnConcurrentExecute set to false is recommended for production applications. This will avoid unexpected errors. Some frameworks may execute concurrent statements on a connection by design. Also some application modules may have the expectation that node-oracledb will handle any necessary connection usage serialization.

For more discussion, see Parallelism on a Connection.

This property was added in node-oracledb 5.2.

Example
const oracledb = require('oracledb');
oracledb.errorOnConcurrentExecute = false;

3.2.6 oracledb.events

Boolean events

Determines whether Oracle Client events mode should be enabled.

The default value for events is false.

This property can be overridden in the oracledb.createPool() call and when getting a standalone connection from oracledb.getConnection().

Events mode is required for Continuous Query Notification, Fast Application Notification (FAN) and Runtime Load Balancing (RLB).

This property was added in node-oracledb 2.2. In node-oracledb 4.0.0 and 4.0.1 the default value for events was true.

Example
const oracledb = require('oracledb');
oracledb.events = false;

3.2.7 oracledb.extendedMetaData

Boolean extendedMetaData

Determines whether additional metadata is available for queries and for REF CURSORs returned from PL/SQL blocks.

The default value for extendedMetaData is false. With this value, the result.metaData and result.resultSet.metaData objects only include column names.

If extendedMetaData is true then metaData will contain additional attributes. These are listed in Result Object Properties.

This property may be overridden in an execute() call.

This property was added in node-oracledb 1.10.

3.2.8 oracledb.externalAuth

Boolean externalAuth

If this property is true then connections are established using external authentication. See External Authentication for more information.

The default value is false.

The user (or username) and password properties should not be set when externalAuth is true.

This property can be overridden in the oracledb.createPool() call and when getting a standalone connection from oracledb.getConnection().

Note prior to node-oracledb 0.5 this property was called isExternalAuth.

Example
const oracledb = require('oracledb');
oracledb.externalAuth = false;

3.2.9 oracledb.fetchArraySize

Number fetchArraySize

This property sets the size of an internal buffer used for fetching query rows from Oracle Database. Changing it may affect query performance but does not affect how many rows are returned to the application.

The default value is 100.

The property is used during the default direct fetches, during ResultSet getRow() calls, and for queryStream(). It is used for getRows() when no argument (or the value 0) is passed to getRows().

Increasing this value reduces the number of round-trips to the database but increases memory usage for each data fetch. For queries that return a large number of rows, higher values of fetchArraySize may give better performance. For queries that only return a few rows, reduce the value of fetchArraySize to minimize the amount of memory management during data fetches. JavaScript memory fragmentation may occur in some cases, see Fetching Rows with Direct Fetches.

For direct fetches (those using execute() option resultSet: false), the internal buffer size will be based on the lesser of maxRows and fetchArraySize.

This property can be overridden by the execute() option fetchArraySize.

See Tuning Fetch Performance for more information.

The property was introduced in node-oracledb version 2.0.

Example
const oracledb = require('oracledb');
oracledb.fetchArraySize = 100;

3.2.10 oracledb.fetchAsBuffer

Array fetchAsBuffer

Allows query columns to be returned as Buffers.

The property should be an array of type constants. Currently the only valid constant is oracledb.BLOB or its equivalent oracledb.DB_TYPE_BLOB.

When set, and a BLOB column is queried with execute() or queryStream(), then the column data is returned as a Buffer instead of the default Lob instance. Individual query columns in execute() or queryStream() calls can override the fetchAsBuffer global setting by using fetchInfo.

This property was added in node-oracledb 1.13.

Example
const oracledb = require('oracledb');
oracledb.fetchAsBuffer = [ oracledb.BLOB ];

3.2.11 oracledb.fetchAsString

Array fetchAsString

Allows query columns to be returned as Strings instead of the default type.

In node-oracledb, all columns are returned as the closest JavaScript type, or as Lob instances in the case of CLOB and NCLOB types. (See Query Result Type Mapping). The fetchAsString property can override this default type mapping.

The fetchAsString property should be an array of type constants. The valid constants are oracledb.DATE, oracledb.NUMBER, oracledb.BUFFER, oracledb.CLOB, and oracledb.NCLOB. The equivalent DB_TYPE_* constants can also be used.

When any column having one of the types is queried with execute() or queryStream(), the column data is returned as a string instead of the default representation. Individual query columns in execute() or queryStream() calls can override the fetchAsString global setting by using fetchInfo.

Note:

  • specifying oracledb.NUMBER will affect numeric columns. The fetchAsString property helps avoid situations where using JavaScript types can lead to numeric precision loss.
  • specifying oracledb.CLOB will affect both CLOB and NCLOB columns. Similarly, specifying oracledb.NCLOB will also affect both CLOB and NCLOB columns. Using fetchAsString automatically fetches LOB data directly in query output without requiring streaming.
  • specifying oracledb.DATE will affect date and timestamp columns. Using fetchAsString can be helpful to avoid date conversions.

When oracledb.BUFFER is used for RAW data, Oracle returns the data as a hex-encoded string. For dates and numbers returned as a string, the maximum length of a string created by this mapping is 200 bytes. Strings created for CLOB and NCLOB columns will generally be limited by Node.js and V8 memory restrictions.

For non-CLOB types, the conversion is handled by Oracle Client libraries and is often referred to as defining the fetch type.

Example
const oracledb = require('oracledb');
oracledb.fetchAsString = [ oracledb.DATE, oracledb.NUMBER ];

3.2.12 oracledb.lobPrefetchSize

Number lobPrefetchSize

This attribute is temporarily disabled. Setting it has no effect. For best performance, fetch Lobs as Strings or Buffers.

Node-oracledb internally uses Oracle LOB Locators to manipulate long object (LOB) data. LOB Prefetching allows LOB data to be returned early to node-oracledb when these locators are first returned. This allows for efficient use of resources and round-trips between node-oracledb and the database.

Prefetching of LOBs is mostly useful for small LOBs.

The default size is 16384.

Example
const oracledb = require('oracledb');
oracledb.lobPrefetchSize = 16384;

3.2.13 oracledb.maxRows

Number maxRows

The maximum number of rows that are fetched by a query with connection.execute() when not using a ResultSet. Rows beyond this limit are not fetched from the database. A value of 0 means there is no limit.

For nested cursors, the limit is also applied to each cursor.

The default value is 0, meaning unlimited.

This property may be overridden in an execute() call.

To improve database efficiency, SQL queries should use a row limiting clause like OFFSET / FETCH or equivalent. The maxRows property can be used to stop badly coded queries from returning unexpectedly large numbers of rows.

For queries that return a fixed, small number of rows, then set maxRows to that value. For example, for queries that return one row, set maxRows to 1.

When the number of query rows is relatively big, or can not be predicted, it is recommended to use a ResultSet or queryStream(). This allows applications to process rows in smaller chunks or individually, preventing the Node.js memory limit being exceeded or query results being unexpectedly truncated by a maxRows limit.

In version 1, the default value was 100.

Example
const oracledb = require('oracledb');
oracledb.maxRows = 0;

3.2.14 oracledb.oracleClientVersion

readonly Number oracleClientVersion

This readonly property gives a numeric representation of the Oracle client library version which is useful in comparisons. For version a.b.c.d.e, this property gives the number: (100000000 * a) + (1000000 * b) + (10000 * c) + (100 * d) + e

This property was added in node-oracledb 1.3.

From node-oracledb 3.1.0, using oracledb.oracleClientVersion will throw a DPI-1047 error if node-oracledb cannot load Oracle Client libraries. Previous versions threw this error from require('oracledb').

Example
const oracledb = require('oracledb');
console.log("Oracle client library version number is " + oracledb.oracleClientVersion);

3.2.15 oracledb.oracleClientVersionString

readonly String oracleClientVersionString

This readonly property gives a string representation of the Oracle client library version which is useful for display.

This property was added in node-oracledb 2.2.

From node-oracledb 3.1.0, using oracledb.oracleClientVersionString will throw a DPI-1047 error if node-oracledb cannot load Oracle Client libraries. Previous versions threw this error from require('oracledb').

Example
const oracledb = require('oracledb');
console.log("Oracle client library version is " + oracledb.oracleClientVersionString);

3.2.16 oracledb.outFormat

Number outFormat

The format of query rows fetched when using connection.execute() or connection.queryStream(). It affects both ResultSet and non-ResultSet queries. It can be used for top level queries and REF CURSOR output.

This can be either of the Oracledb constants oracledb.OUT_FORMAT_ARRAY or oracledb.OUT_FORMAT_OBJECT. The default value is oracledb.OUT_FORMAT_ARRAY which is more efficient. The older, equivalent constants oracledb.ARRAY and oracledb.OBJECT are deprecated.

If specified as oracledb.OUT_FORMAT_ARRAY, each row is fetched as an array of column values.

If specified as oracledb.OUT_FORMAT_OBJECT, each row is fetched as a JavaScript object. The object has a property for each column name, with the property value set to the respective column value. The property name follows Oracle's standard name-casing rules. It will commonly be uppercase, since most applications create tables using unquoted, case-insensitive names.

From node-oracledb 5.1, when duplicate column names are used in queries, then node-oracledb will append numeric suffixes in oracledb.OUT_FORMAT_OBJECT mode as necessary, so that all columns are represented in the JavaScript object. This was extended in node-oracledb 5.2 to also cover duplicate columns in nested cursors and REF CURSORS.

This property may be overridden in an execute() or queryStream() call.

See Query Output Formats for more information.

Example
const oracledb = require('oracledb');
oracledb.outFormat = oracledb.OUT_FORMAT_ARRAY;

3.2.17 oracledb.poolIncrement

Number poolIncrement

The number of connections that are opened whenever a connection request exceeds the number of currently open connections.

The default value is 1.

With fixed-sized homogeneous pools (where poolMin equals poolMax), and using Oracle Client 18c (or later), you may wish to evaluate setting poolIncrement greater than 0. This can expedite regrowth when the number of connections established has become lower than poolMin, for example if network issues have caused connections to become unusable and they have been dropped from the pool.

This property may be overridden when creating a connection pool.

Example
const oracledb = require('oracledb');
oracledb.poolIncrement = 1;

3.2.18 oracledb.poolMax

Number poolMax

The maximum number of connections to which a connection pool can grow.

The default value is 4.

This property may be overridden when creating a connection pool.

Importantly, if you increase poolMax you should also increase the number of threads available to node-oracledb. See Connections and Number of Threads.

A fixed pool size where poolMin equals poolMax is strongly recommended. This helps prevent connection storms and helps overall system stability.

See Connection Pooling for pool sizing guidelines.

Example
const oracledb = require('oracledb');
oracledb.poolMax = 4;

3.2.19 oracledb.poolMaxPerShard

Number poolMaxPerShard

Sets the maximum number of connection in the pool that can be used for any given shard in a sharded database. This lets connections in the pool be balanced across the shards. A value of zero will not set any maximum number of sessions for each shard.

This property may be overridden when creating a connection pool.

When this property is greater than zero, and a new connection request would cause the number of connections to the target shard to exceed the limit, then that new connection request will block until a suitable connection has been released back to the pool. The pending connection request will consume one worker thread.

See Connecting to Sharded Databases for more information.

This property was added in node-oracledb 4.1. It is available when node-oracledb uses Oracle client libraries 18.3, or later.

Example
const oracledb = require('oracledb');
oracledb.poolMaxPerShard = 0;

3.2.20 oracledb.poolMin

Number poolMin

The number of connections established to the database when a pool is created. Also this is the minimum number of connections that a pool maintains when it shrinks, see poolTimeout.

The default value is 0.

This property may be overridden when creating a connection pool.

A fixed pool size where poolMin equals poolMax is strongly recommended. This helps prevent connection storms and helps overall system stability.

For pools created with External Authentication, with homogeneous set to false, or when using Database Resident Connection Pooling (DRCP), then the number of connections initially created is zero even if a larger value is specified for poolMin. Also in these cases the pool increment is always 1, regardless of the value of poolIncrement. Once the number of open connections exceeds poolMin then the number of open connections does not fall below poolMin.

Example
const oracledb = require('oracledb');
oracledb.poolMin = 0;

3.2.21 oracledb.poolPingInterval

Number poolPingInterval

When a pool getConnection() is called and the connection has been idle in the pool for at least poolPingInterval seconds, node-oracledb internally "pings" the database to check the connection is alive. After a ping, an unusable connection is destroyed and a usable one is returned by getConnection(). Connection pinging improves the chance a pooled connection is valid when it is first used because identified unusable connections will not be returned to the application.

The default poolPingInterval value is 60 seconds. Possible values are:

poolPingInterval Value Behavior of a Pool getConnection() Call
n < 0 Never checks for connection validity
n = 0 Always checks for connection validity. This value is not recommended for most applications because of the overhead in performing each ping
n > 0 Checks validity if the connection has been idle in the pool (not "checked out" to the application by getConnection()) for at least n seconds

This property may be overridden when creating a connection pool.

See Connection Pool Pinging for more discussion.

This property was added in node-oracledb 1.12. It was disabled when using Oracle Client 12.2 (and later) until node-oracledb 3.0.

Example
const oracledb = require('oracledb');
oracledb.poolPingInterval = 60;     // seconds

3.2.22 oracledb.poolTimeout

Number poolTimeout

The poolTimeout property allows the number of open connections in a pool to shrink to poolMin.

If the application returns connections to the pool with connection.close(), and the connections are then unused for more than poolTimeout seconds, then any excess connections above poolMin will be closed. When using Oracle Client prior to version 21, this pool shrinkage is only initiated when the pool is accessed.

If poolTimeout is set to 0, then idle connections are never terminated.

If you wish to change poolTimeout with pool.reconfigure(), then the initial poolTimeout used by oracledb.createPool() must be non-zero.

The default value is 60.

This property may be overridden when creating a connection pool.

Example
const oracledb = require('oracledb');
oracledb.poolTimeout = 60;

3.2.23 oracledb.prefetchRows

Number prefetchRows

This is a query tuning option to set the number of additional rows the underlying Oracle Client library fetches during the internal initial statement execution phase of a query. The prefetch size does not affect when, or how many, rows are returned by node-oracledb to the application.

The prefetchRows attribute can be used in conjunction with oracledb.fetchArraySize to tune query performance, memory use, and to reduce the number of round-trip calls needed to return query results, see Tuning Fetch Performance.

The prefetchRows value is ignored in some cases, such as when the query involves a LOB.

If you fetch a REF CURSOR, retrieve rows from that cursor, and then pass it back to a PL/SQL block, you should set prefetchRows to 0 during the initial statement that gets the REF CURSOR. This ensures that rows are not internally fetched from the REF CURSOR by node-oracledb thus making them unavailable in the final PL/SQL code.

The default value is 2.

This property may be overridden in an connection.execute() call, which is preferred usage if you need to change the value..

This attribute is not used in node-oracledb version 2, 3 or 4. In those versions use only oracledb.fetchArraySize instead.

Example
const oracledb = require('oracledb');
oracledb.prefetchRows = 2;

3.2.24 oracledb.Promise

Promise Promise

The oracledb.Promise property is no longer used in node-oracledb 5 and has no effect.

Node-oracledb supports Promises on all methods. The native Promise library is used. See Promises and node-oracledb for a discussion of using Promises.

Example

Prior to node-oracledb 5, this property could be set to override or disable the Promise implementation.

const mylib = require('myfavpromiseimplementation');
oracledb.Promise = mylib;

Prior to node-oracledb 5, Promises could be completely disabled by setting:

oracledb.Promise = null;

3.2.25 oracledb.queueMax

Number queueMax

The maximum number of pending pool.getConnection() calls that can be queued.

When the number of pool.getConnection() calls that have been queued waiting for an available connection reaches queueMax, then any future pool.getConnection() calls will immediately return an error and will not be queued.

If queueMax is -1, then the queue length is not limited.

The default value is 500.

This property may be overridden when creating a connection pool.

This property was added in node-oracledb 5.0.

Example
const oracledb = require('oracledb');
oracledb.queueMax = 500;

3.2.26 oracledb.queueRequests

This property was removed in node-oracledb 3.0 and queuing was always enabled. In node-oracledb 5.0, set queueMax to 0 to disable queuing. See Connection Pool Queue for more information.

3.2.27 oracledb.queueTimeout

Number queueTimeout

The number of milliseconds after which connection requests waiting in the connection request queue are terminated. If queueTimeout is 0, then queued connection requests are never terminated.

If immediate timeout is desired, set related property queueMax to 0.

The default value is 60000.

This property may be overridden when creating a connection pool.

See Connection Pool Queue for more information.

This property was added in node-oracledb 1.7.

Example
const oracledb = require('oracledb');
oracledb.queueTimeout = 3000; // 3 seconds

3.2.28 oracledb.stmtCacheSize

Number stmtCacheSize

The number of statements that are cached in the statement cache of each connection.

The default value is 30.

This property may be overridden for specific Pool or Connection objects.

In general, set the statement cache to the size of the working set of statements being executed by the application. Statement caching can be disabled by setting the size to 0.

See Statement Caching for examples.

Example
const oracledb = require('oracledb');
oracledb.stmtCacheSize = 30;

3.2.29 oracledb.version

readonly Number version

This readonly property gives a numeric representation of the node-oracledb version. For version x.y.z, this property gives the number: (10000 * x) + (100 * y) + z

Example
const oracledb = require('oracledb');
console.log("Driver version number is " + oracledb.version);

3.2.30 oracledb.versionString

readonly String versionString

This readonly property gives a string representation of the node-oracledb version, including the version suffix if one is present.

This property was added in node-oracledb 2.1.

Example
const oracledb = require('oracledb');
console.log("Driver version is " + oracledb.versionString);

3.2.31 oracledb.versionSuffix

readonly String versionSuffix

This readonly property gives a string representing the version suffix (e.g. "-dev" or "-beta") or an empty string if no version suffix is present.

This property was added in node-oracledb 2.1.

Example
const oracledb = require('oracledb');
console.log("Driver version suffix is " + oracledb.versionSuffix);

3.3 Oracledb Methods

3.3.1 oracledb.createPool()

Prototype

Callback:

createPool(Object poolAttrs, function(Error error, Pool pool){});

Promise:

promise = createPool(Object poolAttrs);
Description

This method creates a pool of connections with the specified user name, password and connection string. A pool is typically created once during application initialization.

Internally, createPool() creates an Oracle Call Interface Session Pool for each Pool object.

The default properties may be overridden by specifying new properties in the poolAttrs parameter.

It is possible to add pools to the pool cache when calling createPool(). This allows pools to later be accessed by name, removing the need to pass the pool object through code. See Connection Pool Cache for more details.

A pool should be terminated with the pool.close() call.

From node-oracledb 3.1.0, the createPool() error callback will return a DPI-1047 error if node-oracledb cannot load Oracle Client libraries. Previous versions threw this error from require('oracledb').

See Connection Pooling for more information about pooling.

3.3.1.1 createPool(): Parameters and Attributes
Object poolAttrs

The poolAttrs parameter object provides connection credentials and pool-specific configuration properties, such as the maximum or minimum number of connections for the pool, or the statement cache size for the connections.

The properties provided in the poolAttrs parameter override the default pooling properties of the Oracledb object. If an attribute is not set, or is null, the value of the related Oracledb property will be used.

Note that the poolAttrs parameter may have configuration properties that are not used by the createPool() method. These are ignored.

The properties of poolAttrs are described below.

3.3.1.1.1 connectString, connectionString
String connectString
String connectionString

The two properties are aliases for each other. Use only one of the properties.

The Oracle database instance used by connections in the pool. The string can be an Easy Connect string, or a Net Service Name from a tnsnames.ora file, or the name of a local Oracle Database instance. See Connection Strings for examples.

The alias connectionString was added in node-oracledb 2.1.

3.3.1.1.2 edition
String edition

Sets the name used for Edition-Based Redefinition by connections in the pool.

This optional property overrides the oracledb.edition property.

This property was added in node-oracledb 2.2.

3.3.1.1.3 enableStatistics
Boolean enableStatistics

Recording of pool statistics can be enabled by setting enableStatistics to true. Statistics can be retrieved with pool.getStatistics(), or pool.logStatistics(). See Connection Pool Monitoring.

The default value is false.

This property was added in node-oracledb 5.2. The obsolete property _enableStats can still be used, but it will be removed in a future version of node-oracledb.

3.3.1.1.3 events
Boolean events

Indicate whether Oracle Call Interface events mode should be enabled for this pool.

This optional property overrides the oracledb.events property.

This property was added in node-oracledb 2.2.

3.3.1.1.5 externalAuth
Boolean externalAuth

Indicate whether pooled connections should be established using External Authentication.

The default is false.

This optional property overrides the oracledb.externalAuth property.

The user (or username) and password properties should not be set when externalAuth is true.

Note prior to node-oracledb 0.5 this property was called isExternalAuth.

3.3.1.1.6 homogeneous
Boolean homogeneous

Indicate whether connections in the pool all have the same credentials (a 'homogeneous' pool), or whether different credentials can be used (a 'heterogeneous' pool).

The default is true.

When set to false, the user name and password can be omitted from the connection.createPool() call, but will need to be given for subsequent pool.getConnection() calls. Different pool.getConnection() calls can provide different user credentials. Alternatively, when homogeneous is false, the user name (the 'proxy' user name) and password can be given, but subsequent pool.getConnection() calls can specify a different user name to access that user's schema.

Heterogeneous pools cannot be used with the connection pool cache. Applications should ensure the pool object is explicitly passed between code modules, or use a homogeneous pool and make use of connection.clientId.

See Heterogeneous Connection Pools and Pool Proxy Authentication for details and examples.

This property was added in node-oracledb 2.3.

3.3.1.1.7 password
String password

The password of the database user used by connections in the pool. A password is also necessary if a proxy user is specified at pool creation.

If homogeneous is false, then the password may be omitted at pool creation but given in subsequent pool.getConnection() calls.

3.3.1.1.8 poolAlias
String poolAlias

The poolAlias is an optional property that is used to explicitly add pools to the connection pool cache. If a pool alias is provided, then the new pool will be added to the connection pool cache and the poolAlias value can then be used with methods that utilize the connection pool cache, such as oracledb.getPool() and oracledb.getConnection().

See Connection Pool Cache for details and examples.

This property was added in node-oracledb 1.11.

3.3.1.1.9 poolIncrement
Number poolIncrement

The number of connections that are opened whenever a connection request exceeds the number of currently open connections.

The default value is 1.

This optional property overrides the oracledb.poolIncrement property.

3.3.1.1.10 poolMax
Number poolMax

The maximum number of connections to which a connection pool can grow.

The default value is 4.

This optional property overrides the oracledb.poolMax property.

Importantly, if you increase poolMax you should also increase the number of threads available to node-oracledb. See Connections and Number of Threads.

See Connection Pooling for other pool sizing guidelines.

3.3.1.1.11 poolMaxPerShard
Number poolMaxPerShard

Sets the maximum number of connections per shard for connection pools. This ensures that the pool is balanced towards each shard.

This optional property overrides the oracledb.poolMaxPerShard property.

This property was added in node-oracledb 4.1.

3.3.1.1.12 poolMin
Number poolMin

The number of connections established to the database when a pool is created. Also this is the minimum number of connections that a pool maintains when it shrinks.

The default value is 0.

This optional property overrides the oracledb.poolMin property.

3.3.1.1.13 poolPingInterval
Number poolPingInterval

When a pool getConnection() is called and the connection has been idle in the pool for at least poolPingInterval seconds, an internal "ping" will be performed first to check the validity of the connection.

The default value is 60.

This optional property overrides the oracledb.poolPingInterval property.

See Connection Pool Pinging for more discussion.

3.3.1.1.14 poolTimeout
Number poolTimeout

The number of seconds after which idle connections (unused in the pool) may be terminated. Idle connections are terminated only when the pool is accessed.

The default value is 60.

This optional property overrides the oracledb.poolTimeout property.

3.3.1.1.15 queueMax
Number queueMax

The maximum number of pending pool.getConnection() calls that can be queued.

When the number of pool.getConnection() calls that have been queued waiting for an available connection reaches queueMax, then any future pool.getConnection() calls will immediately return an error and will not be queued.

If queueMax is -1, then the queue length is not limited.

The default value is 500.

This optional property overrides the oracledb.queueMax property.

This property was added in node-oracledb 5.0.

3.3.1.1.16 queueRequests

This property was removed in node-oracledb 3.0 and queuing was always enabled. In node-oracledb 5.0, set queueMax to 0 to disable queuing. See Connection Pool Queue for more information.

3.3.1.1.17 queueTimeout
Number queueTimeout

The number of milliseconds after which connection requests waiting in the connection request queue are terminated. If queueTimeout is set to 0, then queued connection requests are never terminated.

The default value is 60000.

This optional property overrides the oracledb.queueTimeout property.

3.3.1.1.18 sessionCallback
String sessionCallback | function sessionCallback(Connection connection, String requestedTag, function callback(Error error, Connection connection){})

When sessionCallback is a Node.js function, each pool.getConnection() will select a connection from the pool and may invoke sessionCallback before returning. The sessionCallback function is called:

  • when the pool selects a brand new, never used connection in the pool.

  • if the pool selects a connection from the pool with a given tag but that tag string value does not match the connection's current, actual tag. The tag requested (if any) by pool.getConnection() is available in the requestedTag parameter. The actual tag in the connection selected by the pool is available in connection.tag.

It will not be invoked for other pool.getConnection() calls.

The session callback is called before pool.getConnection() returns so it can be used for logging or to efficiently set session state, such as with ALTER SESSION statements. Make sure any session state is set and connection.tag is updated in the sessionCallback function prior to it calling its own callback() function otherwise the session will not be correctly set when getConnection() returns. The connection passed into sessionCallback should be passed out through callback() so it is returned from the application's pool.getConnection() call.

When node-oracledb is using Oracle Client libraries 12.2 or later, tags are multi-property tags with name=value pairs like "k1=v1;k2=v2".

When using Oracle Client libraries 12.2 or later, sessionCallback can be a string containing the name of a PL/SQL procedure to be called when pool.getConnection() requests a tag, and that tag does not match the connection's actual tag. When the application uses DRCP connections, a PL/SQL callback can avoid the round-trip calls that a Node.js function would require to set session state. For non-DRCP connections, the PL/SQL callback will require a round-trip from the application.

The PL/SQL procedure declaration is:

PROCEDURE mycallback (
  desired_props IN  VARCHAR2,
  actual_props  IN  VARCHAR2
);

See Connection Tagging and Session State for more information.

This property was added in node-oracledb 3.1.

3.3.1.1.19 sodaMetaDataCache
Boolean sodaMetaDataCache

Indicates whether the pool's connections should share a cache of SODA metadata. This improves SODA performance by reducing round-trips to the database when opening collections. It has no effect on non-SODA operations.

The default is false.

There is no global equivalent for setting this attribute. SODA metadata caching is restricted to pooled connections only.

Note: if the metadata of a collection is changed externally, the cache can get out of sync. If this happens, the cache can be cleared by calling pool.reconfigure({ sodaMetadataCache: false }). A second call to reconfigure() should then be made to re-enable the cache.

This property was added in node-oracledb 5.2. It requires Oracle Client 21.3 (or later). The feature is also available in Oracle Client 19c from 19.11 onward.

3.3.1.1.20 stmtCacheSize
Number stmtCacheSize

The number of statements to be cached in the statement cache of each connection in the pool.

This optional property overrides the oracledb.stmtCacheSize property.

3.3.1.1.21 user, username
String user
String username

The two properties are aliases for each other. Use only one of the properties.

The database user name for connections in the pool. Can be a simple user name or a proxy of the form alison[fred]. See the Client Access Through a Proxy section in the Oracle Call Interface manual for more details about proxy authentication.

If homogeneous is false, then the pool user name and password need to be specified only if the application wants that user to proxy the users supplied in subsequent pool.getConnection() calls.

The alias username was added in node-oracledb 5.2.

3.3.1.2 createPool(): Callback Function

Prototype
function(Error error, Pool pool)
Parameters
Callback function parameter Description
Error error If createPool() succeeds, error is NULL. If an error occurs, then error contains the error message.
Pool pool The newly created connection pool. If createPool() fails, pool will be NULL. If the pool will be accessed via the pool cache, this parameter can be omitted. See Pool class for more information.

3.3.2 oracledb.getConnection()

Prototype

Callback:

getConnection([String poolAlias | Object connAttrs], function(Error error, Connection connection){});

Promise:

promise = getConnection([String poolAlias | Object connAttrs]);
Description

Obtains a connection from a pool in the connection pool cache or creates a new, standalone, non-pooled connection.

For situations where connections are used infrequently, creating a standalone connection may be more efficient than creating and managing a connection pool. However, in most cases, Oracle recommends getting connections from a connection pool.

The following table shows the various signatures that can be used when invoking getConnection and describes how the function will behave as a result.

Signature Description
oracledb.getConnection() Gets a connection from the previously created default pool. Returns a promise.
oracledb.getConnection(callback) Gets a connection from the previously created default pool. Invokes the callback.
oracledb.getConnection(poolAlias) Gets a connection from the previously created pool with the specified poolAlias. Returns a promise.
oracledb.getConnection(poolAlias, callback) Gets a connection from the previously created pool with the specified poolAlias. Invokes the callback.
oracledb.getConnection(connAttrs) Creates a standalone, non-pooled connection. Returns a promise.
oracledb.getConnection(connAttrs, callback) Creates a standalone, non-pooled connection. Invokes the callback.

Note if the application opens a number of connections, you should increase the number of threads available to node-oracledb. See Connections and Number of Threads.

From node-oracledb 3.1.0, a non-pooled oracledb.getConnection() call will return a DPI-1047 error if node-oracledb cannot load Oracle Client libraries. Previous versions threw this error from require('oracledb').

See Connection Handling for more information on connections.

3.3.2.1 getConnection(): Parameters
3.3.2.1.1 Pool Alias
String poolAlias

The poolAlias parameter specifies which previously created pool in the connection pool cache to use to obtain the connection.

3.3.2.1.2 getConnection(): Attributes
Object connAttrs

The connAttrs parameter object provides connection credentials and connection-specific configuration properties.

Any connAttrs properties that are not used by the getConnection() method are ignored.

The properties of the connAttrs object are described below.

3.3.2.1.2.1 connectString, connectionString
String connectString
String connectionString

The two properties are aliases for each other. Use only one of the properties.

The Oracle database instance to connect to. The string can be an Easy Connect string, or a Net Service Name from a tnsnames.ora file, or the name of a local Oracle database instance. See Connection Strings for examples.

The alias connectionString was added in node-oracledb 2.1.

3.3.2.1.2.2 edition
String edition

Sets the name used for Edition-Based Redefinition by this connection.

This optional property overrides the oracledb.edition property.

This property was added in node-oracledb 2.2.

3.3.2.1.2.3 events
Boolean events

Determines if the standalone connection is created using Oracle Call Interface events mode.

This optional property overrides the oracledb.events property.

This property was added in node-oracledb 2.2.

3.3.2.1.2.4 externalAuth
Boolean externalAuth

If this optional property is true then the connection will be established using External Authentication.

This optional property overrides the oracledb.externalAuth property.

The user (or username) and password properties should not be set when externalAuth is true.

Note prior to node-oracledb 0.5 this property was called isExternalAuth.

3.3.2.1.2.5 matchAny
Boolean matchAny

Used in conjunction with tag when getting a connection from a connection pool.

Indicates that the tag in a connection returned from a connection pool may not match the requested tag.

See Connection Tagging and Session State.

This property was added in node-oracledb 3.1.

3.3.2.1.2.6 newPassword
String newPassword

The new password to use for the database user. When using newPassword, the password property should be set to the current password.

This allows passwords to be changed at the time of connection, in particular it can be used to connect when the old password has expired.

See Changing Passwords and Connecting with an Expired Password.

This property was added in node-oracledb 2.2.

3.3.2.1.2.7 poolAlias
String poolAlias

Specifies which previously created pool in the connection pool cache to obtain the connection from. See Pool Alias.

3.3.2.1.2.8 password
String password

The password of the database user. A password is also necessary if a proxy user is specified.

3.3.2.1.2.9 privilege
Number privilege

The privilege to use when establishing connection to the database. This optional property should be one of the privileged connection constants. Multiple privileges may be used by when required, for example oracledb.SYSDBA | oracledb.SYSPRELIM.

See Privileged Connections for more information.

Note only non-pooled connections can be privileged.

This property was added in node-oracledb 2.1.

3.3.2.1.2.10 shardingKey
Array shardingKey

Allows a connection to be established directly to a database shard. See Connecting to Sharded Databases.

Array values may be of String type (mapping to VARCHAR2 sharding keys), Number (NUMBER), Date (DATE), or Buffer (RAW). Multiple types may be used in the array. Sharding keys TIMESTAMP type are not supported.

This property was added in node-oracledb 4.1.

3.3.2.1.2.11 stmtCacheSize
Number stmtCacheSize

The number of statements to be cached in the statement cache of each connection. This optional property may be used to override the oracledb.stmtCacheSize property.

3.3.2.1.2.12 superShardingKey
Array superShardingKey

Allows a connection to be established directly to a database shard. See Connecting to Sharded Databases.

Array values may be of String type (mapping to VARCHAR2 sharding keys), Number (NUMBER), Date (DATE), or Buffer (RAW). Multiple types may be used in the array. Sharding keys TIMESTAMP type are not supported.

This property was added in node-oracledb 4.1.

3.3.2.1.2.13 tag
String tag

Used when getting a connection from a connection pool.

Indicates the tag that a connection returned from a connection pool should have. Various heuristics determine the tag that is actually returned, see Connection Tagging and Session State.

This property was added in node-oracledb 3.1.

3.3.2.1.2.14 user, username
String user
String username

The two properties are aliases for each other. Use only one of the properties.

The database user name. Can be a simple user name or a proxy of the form alison[fred]. See the Client Access Through a Proxy section in the Oracle Call Interface manual for more details about proxy authentication.

The alias username was added in node-oracledb 5.2.

3.3.2.2 getConnection(): Callback Function
Prototype
function(Error error, Connection connection)
Parameters
Callback function parameter Description
Error error If getConnection() succeeds, error is NULL. If an error occurs, then error contains the error message.
Connection connection The newly created connection. If getConnection() fails, connection will be NULL. See Connection class for more details.

3.3.3 oracledb.getPool()

Prototype
getPool([String poolAlias]);
Description

Retrieves a previously created pool from the connection pool cache. Note that this is a synchronous method.

3.3.3.1 Parameters
3.3.3.1.1 alias
String poolAlias

The pool alias of the pool to retrieve from the connection pool cache. The default value is 'default' which will retrieve the default pool from the cache.

3.3.4 oracledb.initOracleClient()

Prototype
initOracleClient([Object options]);
Description

This synchronous function loads and initializes the Oracle Client libraries that are necessary for node-oracledb to communicate with Oracle Database. This function is optional. If used, it should be the first node-oracledb call made by an application.

If initOracleClient() is not called, then the Oracle Client libraries are loaded at the time of first use in the application, such as when creating a connection pool. The default values described for options will be used in this case.

If the Oracle Client libraries cannot be loaded, or they have already been initialized, either by a previous call to this function or because another function call already required the Oracle Client libraries, then initOracleClient() raises an exception.

See Initializing Node-oracledb for more information.

This method was added in node-oracledb 5.0.

3.3.4.1 Parameters
3.3.4.1.1 options
Object options

The options parameter and option attributes are optional. If an attribute is set, it should be a string value.

Attribute Description
configDir This specifies the directory in which the Optional Oracle Net Configuration and Optional Oracle Client Configuration files reside. It is equivalent to setting the Oracle environment variable TNS_ADMIN to this value. Any value in that environment variable prior to the call to oracledb.initOracleClient() is ignored. On Windows, remember to double each backslash used as a directory separator. If configDir is not set, Oracle's default configuration file search heuristics are used.
driverName This specifies the driver name value shown in database views, such as V$SESSION_CONNECT_INFO. It can be used by applications to identify themselves for tracing and monitoring purposes. The convention is to separate the product name from the product version by a colon and single space characters. If this attribute is not specified, the value "node-oracledb : version" is used. See Other Node-oracledb Initialization.
errorUrl This specifies the URL that is included in the node-oracledb exception message if the Oracle Client libraries cannot be loaded. This allows applications that use node-oracledb to refer users to application-specific installation instructions. If this attribute is not specified, then the node-oracledb installation instructions URL is used. See Other Node-oracledb Initialization.
libDir This specifies the directory containing the Oracle Client libraries. If libDir is not specified, the default library search mechanism is used. If your client libraries are in a full Oracle Client or Oracle Database installation, such as Oracle Database "XE" Express Edition, then you must have previously set environment variables like ORACLE_HOME before calling initOracleClient(). On Windows, remember to double each backslash used as a directory separator. See Locating the Oracle Client Libraries.

On Linux, ensure a libclntsh.so file exists. On macOS ensure a libclntsh.dylib file exists. Node-oracledb will not directly load libclntsh.*.XX.1 files in libDir. Note other libraries used by libclntsh* are also required.

On Linux, using libDir is only useful for forcing initOracleClient() to immediately load the Oracle Client libraries because those libraries still need to be in the operating system search path, such as from running ldconfig or set in the environment variable LD_LIBRARY_PATH.

3.3.5 oracledb.shutdown()

Prototype

Callback:

shutdown([Object connAttr, [Number shutdownMode, ] ] function(Error error) {});

Promise:

promise = shutdown([Object connAttr [, Number shutdownMode]]);

Description

This is the simplified form of connection.shutdown() used for shutting down a database instance. It accepts connection credentials and shuts the database instance completely down.

Internally it creates, and closes, a standalone connection using the oracledb.SYSOPER privilege.

See Database Start Up and Shut Down.

This method was added in node-oracledb 5.0.

3.3.5.1 Parameters
3.3.5.1.1 connAttr
Object connAttr

Connection credentials similar to oracledb.getConnection() credentials. The properties user, username password, connectString, connectionString, and externalAuth may be specified.

3.3.5.1.2 shutdownMode
Number shutdownMode

One of the constants oracledb.SHUTDOWN_MODE_ABORT, oracledb.SHUTDOWN_MODE_DEFAULT, oracledb.SHUTDOWN_MODE_IMMEDIATE, oracledb.SHUTDOWN_MODE_TRANSACTIONAL, or oracledb.SHUTDOWN_MODE_TRANSACTIONAL_LOCAL.

The default mode is oracledb.SHUTDOWN_MODE_DEFAULT.

3.3.5.2 shutdown(): Callback Function
Parameters
Callback function parameter Description
Error error If shutdown() succeeds, error is NULL. If an error occurs, then error contains the error message.

3.3.6 oracledb.startup()

Prototype

Callback:

startup([Object connAttrs, [Object options, ] ] function(Error error) {});

Promise:

promise = startup([Object connAttrs [, Object options ]]);
Description

This is the simplified form of connection.startup() used for starting a database instance up. It accepts connection credentials and starts the database instance completely.

As part of the start up process, a standalone connection using the oracledb.SYSOPER privilege is internally created and closed.

See Database Start Up and Shut Down.

This method was added in node-oracledb 5.0.

3.3.6.1 Parameters
3.3.6.1.1 connAttr
Object connAttr

Connection credentials similar to oracledb.getConnection() credentials. The properties username, password, connectString, connectionString, and externalAuth may be specified.

3.3.6.1.2 options
Object options

The optional options object can contain one or more of these properties:

Attribute Description
Boolean force Shuts down a running database using oracledb.SHUTDOWN_MODE_ABORT before restarting the database. The database start up may require instance recovery. The default for force is false.
Boolean restrict After the database is started, access is restricted to users who have the CREATE_SESSION and RESTRICTED SESSION privileges. The default is false.
String pfile The path and filename for a text file containing Oracle Database initialization parameters. If pfile is not set, then the database server-side parameter file is used.
3.3.6.2 startup(): Callback Function
Parameters
Callback function parameter Description
Error error If startup() succeeds, error is NULL. If an error occurs, then error contains the error message.

4. Connection Class

A Connection object is obtained by a Pool class getConnection() or Oracledb class getConnection() call.

The connection is used to access an Oracle database.

4.1 Connection Properties

The properties of a Connection object are listed below.

4.1.1 connection.action

writeonly String action

The action attribute for end-to-end application tracing.

This is a write-only property. Displaying a Connection object will show a value of null for this attribute. See End-to-end Tracing, Mid-tier Authentication, and Auditing.

4.1.2 connection.callTimeout

Number callTimeout

Sets the maximum number of milliseconds that each underlying round-trip between node-oracledb and Oracle Database may take on a connection. Each node-oracledb method or operation may make zero or more round-trips. The callTimeout value applies to each round-trip individually, not to the sum of all round-trips. Time spent processing in node-oracledb before or after the completion of each round-trip is not counted.

The callTimeout setting has no effect when using IPC connections, i.e. when node-oracledb is running on the same host as the Oracle Database Network listener.

See Database Call Timeouts for more information about limiting statement execution time, and also about limiting the time taken to open new connections.

The default is 0, meaning that there is no timeout.

This property was added in node-oracledb 3.0. An exception will occur if node-oracledb is not using Oracle client library version 18.1 or later.

4.1.3 connection.clientId

writeonly String clientId

The client identifier for end-to-end application tracing, use with mid-tier authentication, and with Virtual Private Databases.

This is a write-only property. Displaying Connection.clientId will show a value of null. See End-to-end Tracing, Mid-tier Authentication, and Auditing.

4.1.4 connection.clientInfo

writeonly String clientInfo

The client information for end-to-end application tracing.

This is a write-only property. Displaying Connection.clientInfo will show a value of null. See End-to-end Tracing, Mid-tier Authentication, and Auditing.

This property was added in node-oracledb 4.1.

4.1.5 connection.currentSchema

String currentSchema

After setting currentSchema, SQL statements using unqualified references to schema objects will resolve to objects in the specified schema.

This setting does not change the session user or the current user, nor does it give the session user any additional system or object privileges for the session.

The value of currentSchema will be empty until it has been explicitly set.

This property is an efficient alternative to ALTER SESSION SET CURRENT_SCHEMA.

This property was added in node-oracledb 4.0.

4.1.6 connection.dbOp

writeonly String dbOp

The database operation information for end-to-end application tracing.

This is a write-only property. Displaying Connection.dbOp will show a value of null. See End-to-end Tracing, Mid-tier Authentication, and Auditing.

This property was added in node-oracledb 4.1. It is available with Oracle 12c.

4.1.7 connection.ecId

writeonly String ecId

Sets the execution context identifier.

The value is available in the ECID column of the V$SESSION view. It is also shown in audit logs.

This property was added in node-oracledb 5.3.

4.1.8 connection.module

writeonly String module

The module attribute for end-to-end application tracing.

This is a write-only property. Displaying Connection.module will show a value of null. See End-to-end Tracing, Mid-tier Authentication, and Auditing.

4.1.9 connection.oracleServerVersion

readonly Number oracleServerVersion

This readonly property gives a numeric representation of the Oracle database version which is useful in comparisons. For version a.b.c.d.e, this property gives the number: (100000000 * a) + (1000000 * b) + (10000 * c) + (100 * d) + e

Note if you connect to Oracle Database 18, or later, then the version will only be accurate if node-oracledb is also using Oracle Database 18, or later, client libraries. Otherwise it will show the base release such as 1800000000 instead of 1803000000.

This property was added in node-oracledb 1.3.

4.1.10 connection.oracleServerVersionString

readonly String oracleServerVersionString

This readonly property gives a string representation of the Oracle database version which is useful for display.

Note if you connect to Oracle Database 18, or later, then the version will only be accurate if node-oracledb is also using Oracle Database 18, or later, client libraries. Otherwise it will show the base release such as "18.0.0.0.0" instead of "18.3.0.0.0".

This property was added in node-oracledb 2.2.

4.1.11 connection.stmtCacheSize

readonly Number stmtCacheSize

The number of statements to be cached in the statement cache of the connection. The default value is the stmtCacheSize property in effect in the Pool object when the connection is created in the pool.

4.1.12 connection.tag

String tag

Applications can set the tag property on pooled connections to indicate the 'session state' that a connection has. The tag will be retained when the connection is released to the pool. A subsequent pool.getConnection() can request a connection that has a given tag. It is up to the application to set any desired session state and set connection.tag prior to closing the connection.

The tag property is not used for standalone connections.

When node-oracledb is using Oracle Client libraries 12.2 or later, the tag must be a multi-property tag with name=value pairs like "k1=v1;k2=v2".

An empty string represents not having a tag set.

See Connection Tagging and Session State.

This property was added in node-oracledb 3.1.

Getting the tag

After a pool.getConnection() requests a tagged connection:

  • When no sessionCallback is in use, then connection.tag will contain the actual tag of the connection.

  • When a Node.js sessionCallback function is used, then connection.tag will be set to the value of the connection's actual tag prior to invoking the callback. The callback can then set connection state and alter connection.tag, as desired, before the connection is returned from pool.getConnection().

  • When a PL/SQL sessionCallback procedure is used, then after pool.getConnection() returns, connection.tag contains a tag with the same property values as the tag that was requested. The properties may be in a different order. If matchAnyTag is true, then connection.tag may contain other properties in addition to the requested properties. Code after each pool.getConnection() call mirroring the PL/SQL code may be needed so connection.tag can be set to a value representing the session state changed in the PL/SQL procedure.

Setting the tag

A tag can be set anytime prior to closing the connection. If a Node.js sessionCallback function is being used, the best practice recommendation is to set the tag in the callback function.

To clear a connection's tag, set connection.tag = "".

4.1.13 connection.tpcInternalName

readwrite String tpcInternalName

This read-write attribute specifies the internal name that is used by the connection when logging two-phase commit transactions.

This property was added in node-oracledb 5.3.

4.1.14 connection.tpcExternalName

readwrite String tpcExternalName

This read-write attribute specifies the external name that is used by the connection when logging two-phase commit transactions.

This property was added in node-oracledb 5.3.

4.2 Connection Methods

4.2.1 connection.break()

Prototype

Callback:

break(function(Error error){});

Promise:

promise = break();
Description

This call stops the currently running operation on the connection.

If there is no operation in progress or the operation has completed by the time the break is issued, the break() is effectively a no-op.

If the running asynchronous operation is interrupted, its callback will return an error.

In network configurations that drop (or in-line) out-of-band breaks, break() may hang unless you have DISABLE_OOB=ON in a sqlnet.ora file, see Optional Oracle Net Configuration.

If you use use break() with DRCP connections, it is currently recommended to drop the connection when releasing it back to the pool: await connection.close({drop: true}). See Oracle bug 29116892.

Parameters
  • function(Error error)
    

    The parameters of the callback function are:

    Callback function parameter Description
    Error error If break() succeeds, error is NULL. If an error occurs, then error contains the error message.

4.2.2 connection.changePassword()

Prototype

Callback:

changePassword(String user, String oldPassword, String newPassword, function(Error error){});

Promise:

promise = changePassword(String user, String oldPassword, String newPassword);
Description

Changes the password of the specified user.

Only users with the ALTER USER privilege can change passwords of other users.

See Changing Passwords and Connecting with an Expired Password.

This method was added in node-oracledb 2.2.

Parameters
  • String user
    

    The name of the user whose password is to be changed.

  • String oldPassword
    

    The current password of the currently connected user.

    If changePassword() is being used by a DBA to change the password of another user, the value of oldPassword is ignored and can be an empty string.

  • String newPassword
    

    The new password of the user whose password is to be changed.

  • function(Error error)
    

    The parameters of the callback function are:

    Callback function parameter Description
    Error error If changePassword() succeeds, error is NULL. If an error occurs, then error contains the error message.

4.2.3 connection.close()

Prototype

Callback:

close([Object options, ] function(Error error){});

Promise:

promise = close([Object options]);
Description

Releases a connection.

Calling close() as soon as a connection is no longer required is strongly encouraged for system efficiency. Calling close() for pooled connections is required to prevent the pool running out of connections.

When a connection is released, any ongoing transaction on the connection is rolled back.

If an error occurs on a pooled connection and that error is known to make the connection unusable, then close() will drop that connection from the connection pool so a future pooled getConnection() call that grows the pool will create a new, valid connection.

This method was added to node-oracledb 1.9, replacing the obsolete equivalent alias connection.release() which will be removed in a future version of node-oracledb.

Parameters
  • Object options
    

    This parameter only affects pooled connections.

    The only valid option attribute is drop.

    For pooled connections, if drop is false, then the connection is returned to the pool for reuse. If drop is true, the connection will be completely dropped from the connection pool, for example:

    await connection.close({drop: true});

    The default is false.

  • function(Error error)
    

    The parameters of the callback function are:

    Callback function parameter Description
    Error error If close() succeeds, error is NULL. If an error occurs, then error contains the error message.

4.2.4 connection.commit()

Prototype

Callback:

commit(function(Error error){});

Promise:

promise = commit();
Description

This call commits the current transaction in progress on the connection.

Parameters
  • function(Error error)
    

    The parameters of the callback function are:

    Callback function parameter Description
    Error error If commit() succeeds, error is NULL. If an error occurs, then error contains the error message.

4.2.5 connection.createLob()

Prototype

Callback:

createLob(Number type, function(Error error, Lob lob){});

Promise:

promise = createLob(Number type);
Description

Creates a Lob as an Oracle temporary LOB. The LOB is initially empty. Data can be streamed to the LOB, which can then be passed into PL/SQL blocks, or inserted into the database.

When no longer required, Lobs created with createLob() should be closed with lob.destroy() because Oracle Database resources are held open if temporary LOBs are not closed.

Open temporary LOB usage can be monitored using the view V$TEMPORARY_LOBS.

LOBs created with createLob() can be bound for IN, IN OUT and OUT binds.

See Working with CLOB, NCLOB and BLOB Data and LOB Bind Parameters for more information.

Parameters
  • Number type
    

    One of the constants oracledb.CLOB, oracledb.BLOB, or oracledb.NCLOB (or equivalent DB_TYPE_* constants).

  • function(Error error)
    

    The parameters of the callback function are:

    Callback function parameter Description
    Error error If createLob() succeeds, error is NULL. If an error occurs, then error contains the error message.

4.2.6 connection.execute()

Prototype

Callback:

execute(String sql [, Object bindParams [, Object options]], function(Error error, Object result){});

Promise:

promise = execute(String sql [, Object bindParams [, Object options]]);
Description

This call executes a single SQL or PL/SQL statement. See SQL Execution for examples. Also see queryStream() for an alternative way of executing queries.

The statement to be executed may contain IN binds, OUT or IN OUT bind values or variables, which are bound using either an object or an array.

A callback function returns a result object, containing any fetched rows, the values of any OUT and IN OUT bind variables, and the number of rows affected by the execution of DML statements.

Parameters
Parameter Description
String sql The SQL statement that is executed. The statement may contain bind parameters.
Object bindParams This function parameter is needed if there are bind parameters in the SQL statement.
Object options This is an optional parameter to execute() that may be used to control statement execution.
function(Error error, Object result) Callback function with the execution results.

The parameters are discussed in the next sections.

4.2.6.1 execute(): SQL Statement
String sql

The SQL or PL/SQL statement that execute() executes. The statement may contain bind variables.

4.2.6.2 execute(): Bind Parameters
Object bindParams

The execute() function bindParams parameter is needed if there are bind variables in the statement, or if options are used. It can be either an object that associates values or JavaScript variables to the statement's bind variables by name, or an array of values or JavaScript variables that associate to the statement's bind variables by their relative positions. See Bind Parameters for Prepared Statements for more details on binding.

If a bind value is an object it may have the following properties:

Bind Property Description
dir The direction of the bind
maxArraySize The number of array elements to be allocated for a PL/SQL Collection INDEX BY associative array OUT or IN OUT array bind variable
maxSize The maximum number of bytes that an OUT or IN OUT bind variable in a String or Buffer will hold
type The data type to be bound
val The input value or variable to be used for an IN or IN OUT bind variable

These properties are discussed in the following sections.

4.2.6.2.1 dir

The direction of the bind, indicating whether data is being passed into, or out from, the database. The value can be one of the Execute Bind Direction Constants oracledb.BIND_IN, oracledb.BIND_INOUT, or oracledb.BIND_OUT. The default is oracledb.BIND_IN.

4.2.6.2.2 maxArraySize

The number of array elements to be allocated for a PL/SQL Collection INDEX BY associative array OUT or IN OUT array bind variable. For IN binds, the value of maxArraySize is ignored. See PL/SQL Collection Associative Arrays.

4.2.6.2.3 maxSize

The maximum number of bytes that OUT or IN OUT bind variable values of type String or Buffer can use to get data. The default value is 200. The maximum limit depends on the database type, see below. When binding IN OUT, then maxSize refers to the size of the returned value: the input value can be smaller or bigger. For IN binds, maxSize is ignored.

The limit for maxSize when binding a value that is returned as a Buffer is 2000 bytes. For Strings, the limit is 4000 bytes unless you are using Oracle Database 12 or later, and the database initialization parameter MAX_STRING_SIZE has a value of EXTENDED. In this case the limit is 32767 bytes.

When binding Oracle LOBs as oracledb.STRING, oracledb.DB_TYPE_NVARCHAR or oracledb.BUFFER, the data cannot be greater than 1 GB. See LOB Bind Parameters. For larger data, use the Lob Class.

Similarly, when binding LONG as oracledb.STRINGand LONG RAW as oracledb.BUFFER, data cannot be greater than 1 GB.

When binding to get a UR