Copyright (c) 2015, 2020, 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.
This document contains:
For installation information, see the Node-oracledb Installation Instructions.
outFormat
Constants
DB_TYPE_BFILE
, DB_TYPE_BINARY_DOUBLE
, DB_TYPE_BINARY_FLOAT
, DB_TYPE_BINARY_INTEGER
, DB_TYPE_BLOB
, DB_TYPE_BOOLEAN
,
DB_TYPE_CHAR
, DB_TYPE_CLOB
, DB_TYPE_CURSOR
,
DB_TYPE_DATE
, DB_TYPE_INTERVAL_DS
, DB_TYPE_INTERVAL_YM
, DB_TYPE_JSON
, DB_TYPE_LONG
, DB_TYPE_LONG_RAW
, DB_TYPE_NCHAR
, DB_TYPE_NCLOB
, DB_TYPE_NUMBER
, DB_TYPE_NVARCHAR
, DB_TYPE_OBJECT
, DB_TYPE_RAW
, DB_TYPE_ROWID
, DB_TYPE_TIMESTAMP
, DB_TYPE_TIMESTAMP_LTZ
, DB_TYPE_TIMESTAMP_TZ
, DB_TYPE_VARCHAR
SUBSCR_EVENT_TYPE_AQ
, SUBSCR_EVENT_TYPE_DEREG
, SUBSCR_EVENT_TYPE_OBJ_CHANGE
, SUBSCR_EVENT_TYPE_QUERY_CHANGE
, SUBSCR_EVENT_TYPE_SHUTDOWN
, SUBSCR_EVENT_TYPE_SHUTDOWN_ANY
, SUBSCR_EVENT_TYPE_STARTUP
, SUBSCR_GROUPING_CLASS_TIME
, SUBSCR_GROUPING_TYPE_LAST
, SUBSCR_GROUPING_TYPE_SUMMARY
, SUBSCR_QOS_BEST_EFFORT
, SUBSCR_QOS_DEREG_NFY
, SUBSCR_QOS_QUERY
, SUBSCR_QOS_RELIABLE
, SUBSCR_QOS_ROWIDS
, SUBSCR_NAMESPACE_AQ
, SUBSCR_NAMESPACE_DBCHANGE
AQ_DEQ_MODE_BROWSE
, AQ_DEQ_MODE_LOCKED
, AQ_DEQ_MODE_REMOVE
, AQ_DEQ_MODE_REMOVE_NO_DATA
, AQ_DEQ_NAV_FIRST_MSG
, AQ_DEQ_NAV_NEXT_TRANSACTION
, AQ_DEQ_NAV_NEXT_MSG
, AQ_DEQ_NO_WAIT
, AQ_DEQ_WAIT_FOREVER
, AQ_MSG_DELIV_MODE_PERSISTENT
, AQ_MSG_DELIV_MODE_BUFFERED
, AQ_MSG_DELIV_MODE_PERSISTENT_OR_BUFFERED
, AQ_MSG_STATE_READY
, AQ_MSG_STATE_WAITING
, AQ_MSG_STATE_PROCESSED
, AQ_MSG_STATE_EXPIRED
, AQ_VISIBILITY_IMMEDIATE
, AQ_VISIBILITY_ON_COMMIT
autoCommit
connectionClass
dbObjectAsPojo
edition
events
extendedMetaData
externalAuth
fetchArraySize
fetchAsBuffer
fetchAsString
lobPrefetchSize
maxRows
oracleClientVersion
oracleClientVersionString
outFormat
poolIncrement
poolMax
poolMaxPerShard
poolMin
poolPingInterval
poolTimeout
prefetchRows
Promise
queueMax
queueRequests
queueTimeout
stmtCacheSize
version
versionString
versionSuffix
createPool()
createPool()
: Parameters and Attributes
connectString
, connectionString
edition
events
externalAuth
homogeneous
password
poolAlias
poolIncrement
poolMax
poolMaxPerShard
poolMin
poolPingInterval
poolTimeout
queueMax
queueRequests
queueTimeout
sessionCallback
stmtCacheSize
user
createPool()
: Callback FunctiongetConnection()
getConnection()
: Parameters
getConnection()
: Attributes
connectString
, connectionString
edition
events
externalAuth
matchAny
newPassword
poolAlias
password
privilege
shardingKey
stmtCacheSize
superShardingKey
tag
user
getConnection()
: Callback FunctiongetPool()
getPool()
: Parameters
poolAlias
initOracleClient()
initOracleClient()
: Parameters
options
shutdown()
shutdown()
: Parameters
connAttr
shutdownMode
shutdown()
: Callback Functionstartup()
startup()
: Parameters
startup()
: Callback Functionaction
callTimeout
clientId
clientInfo
currentSchema
dbOp
module
oracleServerVersion
oracleServerVersionString
stmtCacheSize
tag
break()
changePassword()
close()
commit()
createLob()
execute()
execute()
: SQL Statementexecute()
: Bind Parameters
dir
maxArraySize
maxSize
type
val
execute()
: Options
autoCommit
dbObjectAsPojo
extendedMetaData
fetchArraySize
fetchInfo
maxRows
outFormat
prefetchRows
resultSet
execute()
: Callback Function
implicitResults
lastRowid
metaData
outBinds
resultSet
rows
rowsAffected
executeMany()
executeMany()
: SQL StatementexecuteMany()
: BindsexecuteMany()
: Options
autoCommit
batchErrors
bindDefs
dmlRowCounts
executeMany()
: Callback Function
batchErrors
dmlRowCounts
outBinds
rowsAffected
getDbObjectClass()
getQueue()
getSodaDatabase()
getStatementInfo()
ping()
queryStream()
release()
rollback()
shutdown()
shutdown()
: shutdownModeshutdown()
: Callback Functionsubscribe()
subscribe()
: Namesubscribe()
: Options
binds
callback
clientInitiated
groupingClass
groupingType
groupingValue
ipAddress
namespace
operations
port
qos
sql
timeout
subscribe()
: Callback Functionstartup()
startup()
: Options
startup()
: Callback Functionunsubscribe()
name
deqOptions
enqOptions
payloadType
payloadTypeClass
payloadTypeName
deqMany()
deqOne()
enqMany()
enqOne()
attributes
elementType
elementTypeClass
elementTypeName
fqn
isCollection
length
name
schema
connectionsInUse
connectionsOpen
poolAlias
poolIncrement
poolMax
poolMin
poolPingInterval
poolTimeout
queueMax
queueRequests
queueTimeout
sessionCallback
status
stmtCacheSize
close()
getConnection()
terminate()
metaData
close()
getRow()
getRows()
toQueryStream()
createIndex()
createIndex()
: Parameters
indexSpec
createIndex()
: Callback Functiondrop()
drop()
: Callback FunctiondropIndex()
dropIndex()
: Parameters
dropIndex()
: Callback Functionfind()
count()
getCursor()
getDocuments()
getOne()
remove()
replaceOne()
replaceOneAndGet()
getDataGuide()
insertMany()
insertManyAndGet()
insertOne()
insertOne()
: Parameters
newDocumentContent
, newSodaDocument
insertOne()
: Callback FunctioninsertOneAndGet()
insertOneAndGet()
: Parameters
newDocumentContent
, newSodaDocument
insertOneAndGet()
: Callback Functionsave()
saveAndGet()
truncate()
truncate()
: Callback FunctioncreateCollection()
createCollection(): collectionName
createCollection(): options
createCollection()
: Callback FunctioncreateDocument()
createDocument(): content
createDocument(): options
getCollectionNames()
getCollectionNames()
: Parameters
options
getCollectionNames()
: Callback FunctionopenCollection()
openCollection()
: Parameters
collectionName
openCollection()
: Callback FunctiongetContent()
getContentAsBuffer()
getContentAsString()
The node-oracledb add-on for Node.js powers high performance Oracle Database applications.
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.
The node-oracledb feature highlights are:
A complete list of features can be seen here.
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 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.
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
// 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' } ]
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.
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.
The Error object contains errorNum
, message
and offset
properties.
errorNum
Number errorNum
The Oracle error number. This value is undefined for non-Oracle errors and for messages prefixed with NJS or DPI.
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
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.
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.
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.
outFormat
ConstantsConstants 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.
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:
execute()
bindParams
type
and the executeMany()
bindDefs
type
propertiescreateLob()
type
parameterfetchAsBuffer
, fetchAsString
, and fetchInfo
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.
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 |
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 |
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 |
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 |
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. |
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. |
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 |
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. |
Constant Name | Value | Description |
---|---|---|
oracledb.SODA_COLL_MAP_MODE |
5001 | Indicate sodaDatabase.createCollection() should use an externally created table to store the collection |
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. |
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.
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.
Note prior to node-oracledb 0.5 this property was called
isAutoCommit
.
const oracledb = require('oracledb');
oracledb.autoCommit = false;
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.
const oracledb = require('oracledb');
oracledb.connectionClass = 'HRPOOL';
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.
const oracledb = require('oracledb');
oracledb.dbObjectAsPojo = false;
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.
const oracledb = require('oracledb');
oracledb.edition = 'ed_2';
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.
const oracledb = require('oracledb');
oracledb.events = false;
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.
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
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
.
const oracledb = require('oracledb');
oracledb.externalAuth = false;
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 not used for
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
.
The property was introduced in node-oracledb version 2.0.
const oracledb = require('oracledb');
oracledb.fetchArraySize = 100;
oracledb.fetchAsBuffer
Array fetchAsBuffer
An array of types. Currently the only valid type 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.
const oracledb = require('oracledb');
oracledb.fetchAsBuffer = [ oracledb.BLOB ];
oracledb.fetchAsString
Array fetchAsString
An array of types. The valid types are
oracledb.DATE
,
oracledb.NUMBER
,
oracledb.BUFFER
,
oracledb.CLOB
, and
oracledb.NCLOB
.
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.
Note:
oracledb.DATE
will affect date and timestamp columnsoracledb.NUMBER
will affect numeric columnsoracledb.CLOB
will affect both CLOB and NCLOB columnsBy default in node-oracledb, all columns are returned as JavaScript types or as
Lob instances, in the case of CLOB and NCLOB types. The
fetchAsString
property helps avoid situations where using JavaScript types
can lead to numeric precision loss, or where date conversion is unwanted. See
Query Result Type Mapping for more discussion.
For raw data returned as a string, 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.
Individual query columns in execute()
or queryStream()
calls can override the
fetchAsString
global setting by
using fetchInfo
.
For non-CLOB types, the conversion to string is handled by Oracle client libraries and is often referred to as defining the fetch type.
const oracledb = require('oracledb');
oracledb.fetchAsString = [ oracledb.DATE, oracledb.NUMBER ];
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.
const oracledb = require('oracledb');
oracledb.lobPrefetchSize = 16384;
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.
const oracledb = require('oracledb');
oracledb.maxRows = 0;
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')
.
const oracledb = require('oracledb');
console.log("Oracle client library version number is " + oracledb.oracleClientVersion);
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')
.
const oracledb = require('oracledb');
console.log("Oracle client library version is " + oracledb.oracleClientVersionString);
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 property may be overridden in
an execute()
or queryStream()
call.
See Query Output Formats for more information.
const oracledb = require('oracledb');
oracledb.outFormat = oracledb.OUT_FORMAT_ARRAY;
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.
This property may be overridden when creating a connection pool.
const oracledb = require('oracledb');
oracledb.poolIncrement = 1;
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.
const oracledb = require('oracledb');
oracledb.poolMax = 4;
oracledb.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 property may be overridden when creating a connection pool.
When this property is set, 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.
This property was added in node-oracledb 4.1. It is available when node-oracledb uses Oracle client libraries 18.3, or later.
const oracledb = require('oracledb');
oracledb.poolMaxPerShard = 0;
oracledb.poolMin
Number poolMin
The minimum number of connections a connection pool maintains, even when there is no activity to the target database.
The default value is 0.
This property may be overridden when creating a connection pool.
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
and connections are idle for more
than the poolTimeout
seconds, then the number of open
connections does not fall below poolMin
.
A fixed pool size where poolMin
equals poolMax
is strongly
recommended. This helps prevent connection storms and helps
overall system stability.
const oracledb = require('oracledb');
oracledb.poolMin = 0;
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.
const oracledb = require('oracledb');
oracledb.poolPingInterval = 60; // seconds
oracledb.poolTimeout
Number poolTimeout
The number of seconds after which idle connections (unused in the
pool) are terminated. Idle connections are terminated only when the
pool is accessed. If the poolTimeout
is set to 0, then idle
connections are never terminated.
The default value is 60.
This property may be overridden when creating a connection pool.
const oracledb = require('oracledb');
oracledb.poolTimeout = 60;
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.
const oracledb = require('oracledb');
oracledb.prefetchRows = 2;
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.
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;
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.
const oracledb = require('oracledb');
oracledb.queueMax = 500;
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.
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.
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.
const oracledb = require('oracledb');
oracledb.queueTimeout = 3000; // 3 seconds
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.
const oracledb = require('oracledb');
oracledb.stmtCacheSize = 30;
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
const oracledb = require('oracledb');
console.log("Driver version number is " + oracledb.version);
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.
const oracledb = require('oracledb');
console.log("Driver version is " + oracledb.versionString);
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.
const oracledb = require('oracledb');
console.log("Driver version suffix is " + oracledb.versionSuffix);
oracledb.createPool()
Callback:
createPool(Object poolAttrs, function(Error error, Pool pool){});
Promise:
promise = createPool(Object poolAttrs);
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.
createPool()
: Parameters and AttributesObject 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.
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.
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.
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.
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
and password
properties should not be set when
externalAuth
is true.
Note prior to node-oracledb 0.5 this property was called
isExternalAuth
.
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.
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.
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.
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.
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.
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.
poolMin
Number poolMin
The minimum number of connections a connection pool maintains, even when there is no activity to the target database.
The default value is 0.
This optional property overrides the
oracledb.poolMin
property.
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.
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.
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.
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.
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.
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.
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.
user
String user
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.
createPool()
: Callback Functionfunction(Error error, Pool pool)
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. |
oracledb.getConnection()
Callback:
getConnection([String poolAlias | Object connAttrs], function(Error error, Connection connection){});
Promise:
promise = getConnection([String poolAlias | Object connAttrs]);
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.
getConnection()
: ParametersString poolAlias
The poolAlias
parameter specifies which previously created pool in
the connection pool cache to use to obtain the
connection.
getConnection()
: AttributesObject 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.
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.
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.
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.
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
and password
properties should not be set when
externalAuth
is true.
Note prior to node-oracledb 0.5 this property was called
isExternalAuth
.
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.
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.
poolAlias
String poolAlias
Specifies which previously created pool in the connection pool cache to obtain the connection from. See Pool Alias.
password
String password
The password of the database user. A password is also necessary if a proxy user is specified.
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.
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.
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.
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.
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.
user
String user
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.
getConnection()
: Callback Functionfunction(Error error, Connection connection)
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. |
oracledb.getPool()
getPool([String poolAlias]);
Retrieves a previously created pool from the connection pool cache. Note that this is a synchronous method.
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.
oracledb.initOracleClient()
initOracleClient([Object options]);
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.
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
.
oracledb.shutdown()
Callback:
shutdown([Object connAttr, [Number shutdownMode, ] ] function(Error error) {});
Promise:
promise = shutdown([Object connAttr [, Number shutdownMode]]);
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.
connAttr
Object connAttr
Connection credentials similar to oracledb.getConnection()
credentials. The properties user
,
password
, connectString
, connectionString
, and externalAuth
may be
specified.
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
.
shutdown()
: Callback FunctionCallback function parameter | Description |
---|---|
Error error | If shutdown() succeeds, error is NULL. If an error occurs, then error contains the error message. |
oracledb.startup()
Callback:
startup([Object connAttrs, [Object options, ] ] function(Error error) {});
Promise:
promise = startup([Object connAttrs [, Object options ]]);
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.
connAttr
Object connAttr
Connection credentials similar to oracledb.getConnection()
credentials. The properties username
,
password
, connectString
, connectionString
, and externalAuth
may be
specified.
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. |
startup()
: Callback FunctionCallback function parameter | Description |
---|---|
Error error | If startup() succeeds, error is NULL. If an error occurs, then error contains the error message. |
A Connection object is obtained by a Pool class
getConnection()
or
Oracledb class getConnection()
call.
The connection is used to access an Oracle database.
The properties of a Connection object are listed below.
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.
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.
See Database Call Timeouts for more information about limiting statement execution time, and also about limiting the time taken to open new connections.
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.
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.
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.
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.
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.
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.
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.
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.
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.
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.
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.
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 = ""
.
connection.break()
Callback:
break(function(Error error){});
Promise:
promise = break();
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.
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. |
connection.changePassword()
Callback:
changePassword(String user, String oldPassword, String newPassword, function(Error error){});
Promise:
promise = changePassword(String user, String oldPassword, String newPassword);
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.
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. |
connection.close()
Callback:
close([Object options, ] function(Error error){});
Promise:
promise = close([Object options]);
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 equivalent
alias connection.release()
.
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. |
connection.commit()
Callback:
commit(function(Error error){});
Promise:
promise = commit();
This call commits the current transaction in progress on the connection.
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. |
connection.createLob()
Callback:
createLob(Number type, function(Error error, Lob lob){});
Promise:
promise = createLob(Number type);
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.
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. |
connection.execute()
Callback:
execute(String sql [, Object bindParams [, Object options]], function(Error error, Object result){});
Promise:
promise = execute(String sql [, Object bindParams [, Object options]]);
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.
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.
execute()
: SQL StatementString sql
The SQL or PL/SQL statement that execute()
executes. The statement
may contain bind variables.
execute()
: Bind ParametersObject 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.
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
.
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.
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.STRING
and LONG RAW as
oracledb.BUFFER
, data cannot be greater than 1 GB.
When binding to get a UROWID value from the database, note that
UROWIDs can take up to 5267 bytes when fetched from the database so
maxSize
should be set to at least this value.
type
The type
indicates to the database how data should be handled.
If type
is not set for IN or IN OUT binds its value will be derived from the
type of the input data. It is recommended to explicitly set the type because
null data will be assumed to be oracledb.STRING
. With OUT binds, type
defaults to oracledb.STRING
.
Commonly, type
is set to a node-oracledb Type
Constant that matches the JavaScript type.
Node-oracledb and the underlying Oracle client libraries then do a mapping to,
or from, the actual database data type. Since Oracle Database does not provide
actual database type information prior to binding, some special cases need
type
set explicitly to avoid data conversion issues. For example, binding a
String to an NVARCHAR needs type
set to oracledb.DB_TYPE_NVARCHAR
.
For each JavaScript and database type combination, the type
property can be
one of the values in the following table. For example, if you are inserting
data from a String into an Oracle Database CHAR column, then set type
to
oracledb.DB_TYPE_CHAR
.
This table does not cover implicit data type conversions that will take place in
Oracle libraries. In particular many Oracle types will allow JavaScript values
to be bound as oracledb.STRING
. For example, you can bind the string “1234”
to insert into a NUMBER column. Another example is that the string “31-01-2019”
can be bound for insert into a DATE column (if the
NLS_DATE_FORMAT is “DD-MM-YYYY”).
Similarly when binding a JavaScript Date, type
can be set to oracledb.DATE
for all date and timestamp database types. This bind type is the default for
Date IN and IN OUT binds. Using the date or timestamp type constant
corresponding to the database type may be preferred when binding in
node-oracledb 4.2. This reduces type conversions and it may be useful in cases
such as when calling overloaded PL/SQL procedures, or to ensure the correct
index is used by a query.
Node.js Type | Database Type | Bind type value |
Notes |
---|---|---|---|
String | VARCHAR2 | oracledb.STRING or oracledb.DB_TYPE_VARCHAR |
Default type for String IN and IN OUT binds |
String | CHAR | oracledb.DB_TYPE_CHAR |
This combination is supported from node-oracledb 4.2 |
String | NVARCHAR | oracledb.DB_TYPE_NVARCHAR |
This combination is supported from node-oracledb 4.2 |
String | NCHAR | oracledb.DB_TYPE_NCHAR |
This combination is supported from node-oracledb 4.2 |
String | LONG | oracledb.STRING or oracledb.DB_TYPE_VARCHAR |
Not available for PL/SQL binds |
Number | NUMBER | oracledb.NUMBER or oracledb.DB_TYPE_NUMBER |
Default type for Number IN and IN OUT binds |
Number | BINARY_DOUBLE | oracledb.DB_TYPE_BINARY_DOUBLE |
This combination is supported from node-oracledb 4.2 |
Number | BINARY_FLOAT | oracledb.DB_TYPE_BINARY_FLOAT |
This combination is supported from node-oracledb 4.2 |
Number | BINARY_INTEGER | oracledb.DB_TYPE_BINARY_INTEGER |
This combination is supported from node-oracledb 4.2. Only supported for PL/SQL binds |
Date | DATE | oracledb.DB_TYPE_DATE |
This combination is supported from node-oracledb 4.2. It is not the default for Date IN and IN OUT binds |
Date | TIMESTAMP | oracledb.DB_TYPE_TIMESTAMP |
This combination is supported from node-oracledb 4.2 |
Date | TIMESTAMP WITH TIME ZONE | oracledb.DB_TYPE_TIMESTAMP_TZ |
This combination is supported from node-oracledb 4.2 |
Date | TIMESTAMP WITH LOCAL TIME ZONE | oracledb.DATE or oracledb.DB_TYPE_TIMESTAMP_LTZ |
Default type for Date IN and IN OUT binds |
Buffer | RAW | oracledb.BUFFER or oracledb.DB_TYPE_RAW |
Default type for Buffer IN and IN OUT binds |
Buffer | LONG RAW | oracledb.BUFFER or oracledb.DB_TYPE_RAW |
Not available for PL/SQL binds |
Lob | CLOB | oracledb.CLOB or oracledb.DB_TYPE_CLOB |
Default type for CLOB Lob IN and IN OUT binds. Binding a String as oracledb.DB_TYPE_VARCHAR will generally be preferred |
Lob | BLOB | oracledb.BLOB or oracledb.DB_TYPE_BLOB |
Default type for BLOB Lob IN and IN OUT binds. Binding a Buffer as oracledb.DB_TYPE_RAW will generally be preferred |
Lob | NCLOB | oracledb.NCLOB or oracledb.DB_TYPE_NCLOB |
This combination is supported from node-oracledb 4.2. Binding a String with type of oracledb.DB_TYPE_NVARCHAR will generally be preferred |
String | ROWID | oracledb.STRING or oracledb.DB_TYPE_VARCHAR |
|
String | UROWID | oracledb.STRING or oracledb.DB_TYPE_VARCHAR |
|
Object | JSON | oracledb.DB_TYPE_JSON |
See Oracle Database JSON Data Type |
String | XMLType | oracledb.STRING or oracledb.DB_TYPE_VARCHAR |
Size is limited to the maximum database VARCHAR length |
Boolean | BOOLEAN | oracledb.DB_TYPE_BOOLEAN |
This combination is supported from node-oracledb 4.2. Only supported for PL/SQL binds |
ResultSet | CURSOR | oracledb.CURSOR or oracledb.DB_TYPE_CURSOR |
Only supported for OUT binds |
DbObject | Named type or collection | A string with the name of the Oracle Database object or collection, or a DbObject | This combination is supported from node-oracledb 4.0 |
When binding LONG, LONG RAW, CLOB, NCLOB, and BLOB database types using string or buffer bind types, then data is limited to a maxium size of 1 GB.
Binding Oracle Database INTERVAL types or BFILE not supported.
val
The input value or variable to be used for an IN or IN OUT bind variable.
execute()
: OptionsObject options
This is an optional parameter to execute()
that may be used to
control statement execution.
If there are no bind variables in the SQL statement, then a null
bindParams
, for example {}
, must be specified before options
otherwise you will get an error like ORA-01036: Illegal variable
name/number or NJS-012: encountered invalid bind data type in parameter.
The following properties can be set or overridden for the execution of a statement.
autoCommit
Boolean autoCommit
Overrides oracledb.autoCommit
.
dbObjectAsPojo
Boolean dbObjectAsPojo
Overrides oracledb.dbObjectAsPojo
.
extendedMetaData
Boolean extendedMetaData
Overrides oracledb.extendedMetaData
.
fetchArraySize
Number fetchArraySize
Overrides oracledb.fetchArraySize
.
fetchInfo
Object fetchInfo
Object defining how query column data should be represented in
JavaScript. It can be used in conjunction with, or instead of, the
global settings fetchAsString
and fetchAsBuffer
.
For example:
fetchInfo: {
"HIRE_DATE": { type: oracledb.STRING }, // return the date as a string
"HIRE_DETAILS": { type: oracledb.DEFAULT } // override fetchAsString or fetchAsBuffer
}
Each column is specified by name, using Oracle’s standard naming convention.
The type
property can be set to one of:
oracledb.STRING
for number, date and raw
columns in a query to indicate they should be returned as Strings instead of
their native format. For CLOB and NCLOB columns, data will be returned as
Strings instead of Lob instances.
Raw columns returned as strings will be returned as hex-encoded
strings. The maximum length of a string created by type mapping
number and date columns is 200 bytes. If a database column that is
already being fetched as type oracledb.STRING
is specified in
fetchInfo
, then the actual database metadata will be used to
determine the maximum length.
oracledb.BUFFER
for a BLOB column,
each BLOB item will be returned as a Buffer instead of a
Lob instance.
oracledb.DEFAULT
overrides any
global mapping given by fetchAsString
or
fetchAsBuffer
. The column data is
returned in native format.
Strings and Buffers created for LOB columns will generally be limited by Node.js and V8 memory restrictions.
See Query Result Type Mapping for more information on query type mapping.
maxRows
Number maxRows
Overrides oracledb.maxRows
.
outFormat
Number outFormat
Overrides oracledb.outFormat
.
prefetchRows
Number prefetchRows
Overrides oracledb.prefetchRows
.
This attribute is not used in node-oracledb version 2, 3 or 4.
resultSet
Boolean resultSet
Determines whether query results, Implicit Results, and nested cursors should be returned as ResultSet objects or directly. The default is false.
execute()
: Callback Functionfunction(Error error, Object result)
The parameters of the execute()
callback function are:
Callback function parameter | Description |
---|---|
Error error | If execute() succeeds, error is NULL. If an error occurs, then error contains the error message. |
Object result | The result object, described below. The result parameter can be omitted for DDL and DML statements where the application only checks error for success or failure. |
The properties of result
object from the execute()
callback are described below.
implicitResults
This property will be defined if the executed statement returned
Implicit Results. Depending on the value of
resultSet
it will either be an array, each
element containing an array of rows from one query, or an array of
ResultSets each corresponding to a query.
See Implicit Results for examples.
This property was added in node-oracledb 4.0. Implicit Results requires Oracle Database 12.1 or later, and Oracle Client 12.1 or later.
lastRowid
readonly String lastRowid
The ROWID of a row affected by an INSERT, UPDATE, DELETE or MERGE statement. For other statements, or if no row was affected, it is not set. If more than one row was affected, only the ROWID of the last row is returned.
This property was added in node-oracledb 4.2.
metaData
readonly Array metaData
For SELECT
statements, this contains an array of objects describing
details of columns for the select list. For non queries, this property is undefined.
Each column’s name
is always given. If the column is a nested
cursor, then the column’s object will also contain a metaData
attribute which is an array describing each column in the nested query.
If the oracledb.extendedMetaData
or execute()
option extendedMetaData
are true then
additional information is included.
byteSize
: the database byte size. This is only set for oracledb.DB_TYPE_VARCHAR
, oracledb.DB_TYPE_CHAR
and oracledb.DB_TYPE_RAW
column types.dbType
: one of the Oracle Database Type Constant values.dbTypeClass
: the class associated with the database type. This is only set if the database type is an object type.dbTypeName
: the name of the database type, such as “NUMBER” or “VARCHAR2”. For object types, this will be the object name.fetchType
: one of the Node-oracledb Type Constant values.name
: The column name follows Oracle’s standard name-casing rules. It will commonly be uppercase, since most applications create tables using unquoted, case-insensitive names.nullable
: indicates whether NULL
values are permitted for this column.precision
: set only for oracledb.DB_TYPE_NUMBER
, oracledb.DB_TYPE_TIMESTAMP
, oracledb.DB_TYPE_TIMESTAMP_TZ
and oracledb.DB_TYPE_TIMESTAMP_LTZ
columns.scale
: set only for oracledb.DB_TYPE_NUMBER
columns.For numeric columns: when precision
is 0
, then the column is
simply a NUMBER. If precision
is nonzero and scale
is -127
,
then the column is a FLOAT. Otherwise, it is a NUMBER(precision,
scale).
Metadata for ResultSets and REF CURSORS is available in a ResultSet property. For Lobs, a Lob type property also indicates whether the object is a BLOB or CLOB.
To get query metadata without fetching rows, use a
ResultSet. Access
resultset.metaData
and then close the ResultSet. Do
not call getRow()
or getRows()
. Preferably use a query clause
such as WHERE 1 = 0
so the database does minimal work.
If you wish to change the case of name
, then use a column alias in your query.
For example, the query select mycol from mytab
will return the name
as
‘MYCOL’. However, executing select mycol as "myCol" from mytab
will return
the name ‘myCol’.
See Query Column Metadata for examples.
outBinds
Array/object outBinds
This contains the output values of OUT and IN OUT binds.
If bindParams
is passed as an array, then
outBinds
is returned as an array. If bindParams
is passed as an
object, then outBinds
is returned as an object. If there are no OUT
or IN OUT binds, the value is undefined.
resultSet
Object resultSet
For SELECT
statements when the resultSet
option
is true, use the resultSet
object to fetch rows.
See ResultSet Class
and Fetching Rows with Result Sets.
When using this option, resultSet.close()
must be called
when the ResultSet is no longer needed. This is true whether or not
rows have been fetched from the ResultSet.
rows
Array rows
For SELECT
statements using direct fetches, rows
contains an array of fetched rows. It will be NULL if there is an
error or the SQL statement was not a SELECT statement. By default,
the rows are in an array of column value arrays, but this can be
changed to arrays of objects by setting
outFormat
to oracledb.OUT_FORMAT_OBJECT
. If a single
row is fetched, then rows
is an array that contains one single row.
The number of rows returned is limited by
oracledb.maxRows
or the
maxRows
option in an execute()
call. If
maxRows
is 0, then the number of rows is limited by Node.js memory
constraints.
If the query contains nested cursors, then each nested cursor
is returned as an array of rows fetched from that cursor. The number of rows
returned for each cursor is limited by maxRows
.
rowsAffected
Number rowsAffected
For DML statements this contains the number of rows affected, for example
the number of rows inserted. For non-DML statements such as queries and PL/SQL
statements, rowsAffected
is undefined.
Due to Node.js type limitations, the largest value shown will be 232 - 1, even if more rows were affected. Larger values will wrap.
connection.executeMany()
Callback:
executeMany(String sql, Array binds [, Object options], function(Error error, Object result) {});
executeMany(String sql, Number numIterations [, Object options], function(Error error, Object result) {});
Promise:
promise = executeMany(String sql, Array binds [, Object options]);
promise = executeMany(String sql, Number numIterations [, Object options]);
This method allows sets of data values to be bound to one DML or
PL/SQL statement for execution. It is like calling
connection.execute()
multiple times but requires fewer
round-trips. This is an efficient way to handle batch
changes, for example when inserting or updating multiple rows. The
method cannot be used for queries.
The executeMany()
method supports IN, IN OUT and OUT binds for most
data types except PL/SQL Collection Associative
Arrays.
The version of this function which accepts a number of iterations should be used when no bind parameters are required or when all bind parameters are OUT binds.
See Batch Statement Execution and Bulk Loading for more information.
This method was added in node-oracledb 2.2.
executeMany()
: SQL StatementString sql
The SQL or PL/SQL statement that executeMany()
executes. The
statement should contain bind variable names.
executeMany()
: BindsThe binds
parameter contains the values or variables to be bound to
the executed statement. It must be an array of arrays (for ‘bind by
position’) or an array of objects whose keys match the bind variable
names in the SQL statement (for ‘bind by name’). Each sub-array or
sub-object should contain values for the bind variables used in the
SQL statement. At least one such record must be specified.
If a record contains fewer values than expected, NULL values will be
used. For bind by position, empty values can be specified using
syntax like [a,,c,d]
.
By default, the direction of binds is oracledb.BIND_IN
. The first
data record determines the number of bind variables, each bind
variable’s data type, and its name (when binding by name). If a
variable in the first record contains a null, this value is ignored
and a subsequent record is used to determine that variable’s
characteristics. If all values in all records for a particular bind
variable are null, the type of that bind is oracledb.STRING
with a
maximum size of 1.
The maximum sizes of strings and buffers are determined by scanning all records
unless a bindDefs
property is used. This property
explicitly specifies the characteristics of each bind variable.
executeMany()
: OptionsThe options
parameter is optional. It can contain the following
properties.
autoCommit
Boolean autoCommit
This optional property overrides
oracledb.autoCommit
.
Note batchErrors
can affect autocommit
mode.
batchErrors
Boolean batchErrors
This optional property allows invalid data records to be rejected while still letting valid data be processed. It can only be set true for INSERT, UPDATE, DELETE or MERGE statements.
When false, the executeMany()
call will stop when the first error
occurs. The callback error object will be set.
When batchErrors
is true, processing will continue even if there are data
errors. The executeMany()
callback error parameter is not set. Instead, a
property (also called batchErrors
) will be returned in the callback result
parameter. The property holds an array of Error objects. Each Error
offset
indicates the row number of a data record that could not be
processed. All other valid data records will be processed and a transaction
will be started but not committed, even if autoCommit
is true. The
application can examine the errors, take action, and explicitly commit or
rollback as desired. In node-oracledb 4.2, the maximum offset
value
was changed from (2^16)-1 to (2^32)-1.
Note that some classes of error will always return via the
executeMany()
callback error object, not as batch errors. No
transaction is created in this case.
The default value is false.
See Handling Data Errors with executeMany()
for examples.
bindDefs
Object bindDefs
The bindDefs
object defines the bind variable types, sizes and
directions. This object is optional in some cases but it is more
efficient to set it.
It should be an array or an object, depending on the structure of the
binds parameter
.
Each value in the bindDefs
array or object should be an object
containing the keys dir
, maxSize
, and type
for one bind
variable, similar to how execute() bind
parameters
are identified.
BindDef Property | Description |
---|---|
dir |
The direction of the bind. One of the Execute Bind Direction Constants oracledb.BIND_IN , oracledb.BIND_INOUT or oracledb.BIND_OUT . The default is oracledb.BIND_IN . |
maxSize |
Required for Strings and Buffers. Ignored for other types. Specifies the maximum number of bytes allocated when processing each value of this bind variable. When data is being passed into the database, maxSize should be at least the size of the longest value. When data is being returned from the database, maxSize should be the size of the longest value. If maxSize is too small, executeMany() will throw an error that is not handled by batchErrors . |
type |
Specifies the mapping between the node-oracledb and database data type. See the execute() type table. |
dmlRowCounts
Boolean dmlRowCounts
When true, this optional property enables output of the number of rows affected by each input data record. It can only be set true for INSERT, UPDATE, DELETE or MERGE statements.
The default value is false.
This feature works when node-oracledb is using version 12, or later, of the Oracle client library, and using Oracle Database 12, or later.
executeMany()
: Callback Functionfunction(Error error, Object result)
If executeMany()
succeeds, error
is NULL. If an error occurs,
then error
contains the error message.
The result
object may contain:
result.batchErrors
Array batchErrors
This property is an array of error objects that were
reported during execution. The offset
property of each error object
corresponds to the 0-based index of the executeMany()
binds
parameter array, indicating which record could not
be processed.
It will be present only if batchErrors
was true in the executeMany()
options
parameter and there are data errors to report. Some classes of
execution error will always return via the executeMany()
callback
error object, not in batchErrors
.
result.dmlRowCounts
Array dmlRowCounts
This is an array of integers identifying the number of rows affected
by each record of the binds parameter. It is
present only if dmlRowCounts
was
true in the executeMany()
options parameter
and a DML statement was executed.
result.outBinds
Object outBinds
This contains the value of any returned IN OUT or OUT binds. It is an
array of arrays, or an array of objects, depending on the binds
parameters
structure. The length of the array
will correspond to the length of the array passed as the binds
parameter. It will be present only if there is at
least one OUT bind variable identified.
result.rowsAffected
Number rowsAffected
This is an integer identifying the total number of database rows affected by the processing of all records of the binds parameter. It is only present if a DML statement was executed.
Due to Node.js type limitations, the largest value shown will be 232 - 1, even if more rows were affected. Larger values will wrap.
connection.getDbObjectClass()
Callback:
getDbObjectClass(String className, function(error, DbObject obj) {})
Promise:
promise = getDbObjectClass(String className)
Returns a DbObject prototype object representing the named Oracle Database object or collection.
When the definition of a type changes in the database, such as might
occur in a development environment, you should fully close connections
to clear the object caches used by node-oracledb and the Oracle client
libraries. For example, when using a pool you could use await
connection.close({drop: true})
, or restart the
pool. Then getDbObjectClass()
can be called again to get the
updated type information.
See Oracle Database Objects and Collections.
This method was added in node-oracledb 4.0.
String className
The name of the Oracle object or collection.
function(Error error, DbObject obj)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If getDbObjectClass() succeeds, error is NULL. If an error occurs, then error contains the error message. |
DbObject obj | A DbObject representing an Oracle Database object or collection. |
connection.getQueue()
Callback:
getQueue(String name, [Object options,] function(Error error, AqQueue queue){})
Promise:
promise = getQueue(String name [, Object options])
This method returns an AqQueue Class object.
This method returns a queue for enqueuing and dequeuing Oracle Advanced Queuing (AQ) messages.
String name
The name of the Advanced Queue to use. This queue should have
been created previously, for example with the
DBMS_AQADM.CREATE_QUEUE()
function.
If the Advanced Queue does not exist in the database, an error will occur when the queue is attempted to be used.
Object options
This optional argument can be used to specify the payload type. If the argument is not passed, then the database queue must be a RAW queue.
The options
object has the following attributes:
Attribute Name | Description |
---|---|
payloadType |
A string containing the name of an Oracle Database object type, or a DbObject Class earlier acquired from connection.getDbObjectClass() . If the name of an object type is used, it is recommended that a fully qualified name be used. |
function(Error error, AqQueue queue)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If queue() succeeds, error is NULL. If an error occurs, then error contains the error message. |
connection.getSodaDatabase()
getSodaDatabase();
This synchronous method returns a SodaDatabase.
Returns a parent SodaDatabase object for use with Simple Oracle Document Access (SODA).
SODA can be used with Oracle Database 18.3 and above, when node-oracledb uses
Oracle Client 18.5 or Oracle Client 19.3, or later. The SODA bulk insert methods
sodaCollection.insertMany()
and
sodaCollection.insertManyAndGet()
are in Preview status.
See Simple Oracle Document Access (SODA) for more information about using SODA in node-oracledb.
This method was added in node-oracledb 3.0.
connection.getStatementInfo()
Callback:
getStatementInfo(String sql, function(Error error, Object information){});
Promise:
promise = getStatementInfo(String sql);
Parses a SQL statement and returns information about it. This is most useful for finding column names of queries, and for finding the names of bind variables used.
This method performs a round-trip to the database, so unnecessary calls should be avoided.
The information is provided by lower level APIs that have some
limitations. Some uncommon statements will return the statement type
as oracledb.STMT_TYPE_UNKNOWN
. DDL statements are not parsed, so
syntax errors in them will not be reported. The direction and types
of bind variables cannot be determined.
This method was added in node-oracledb 2.2.
String sql
The SQL statement to parse.
function(Error error, Object information)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If getStatementInfo() succeeds, error is NULL. If an error occurs, then error contains the error message. |
Object information | The information object, described below. |
Depending on the statement type, the information
object may contain:
bindNames
: an array of strings corresponding to the unique names
of the bind variables used in the SQL statement.
metaData
: containing properties equivalent to those given by
execute()
extendedMetaData. This property exists
only for queries.
statementType
: an integer corresponding to one of the SQL
Statement Type Constants.
connection.ping()
Callback:
ping(function(Error error){});
Promise:
promise = ping();
This method checks that a connection is currently usable and the network to the database is valid. This call can be useful for system health checks. A ping only confirms that a single connection is usable at the time of the ping.
Pinging does not replace error checking during statement execution,
since network or database failure may occur in the interval between
ping()
and execute()
calls.
Pinging requires a round-trip to the database so unnecessary ping calls should be avoided.
If ping()
returns an error, the application should close the
connection.
This method was added in node-oracledb 2.2.
function(Error error)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If ping() succeeds, error is NULL. If an error occurs, then error contains the error message. |
connection.queryStream()
queryStream(String sql [, Object bindParams, [Object options]]);
This method will return a Readable Stream for queries.
This function provides query streaming support. The parameters are
the same as execute()
except a callback is not used.
Instead this function returns a stream used to fetch data.
Each row is returned as a data
event. Query metadata is available via a
metadata
event. The end
event indicates the end of the query results.
After the end
event has been received, the Stream destroy() function
should be called to clean up resources properly. Any further end-of-fetch
logic, in particular the connection release, should be in the close
event.
Alternatively the Stream destroy()
method can be used to terminate a
stream early.
For tuning, adjust the values of the connection.execute()
options
fetchArraySize
and
prefetchRows
, see Tuning Fetch
Performance.
See Query Streaming for more information.
Support for Node.js version 8 Stream destroy()
method was added in
node-oracledb 2.1.
This method was added in node-oracledb 1.8.
See execute().
connection.release()
An alias for connection.close().
connection.rollback()
Callback:
rollback(function(Error error){});
Promise:
promise = rollback();
This call rolls back the current transaction in progress on the connection.
function(Error error)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If rollback() succeeds, error is NULL. If an error occurs, then error contains the error message. |
connection.shutdown()
Callback:
shutdown([Number shutdownMode,] function(Error error) {});
Promise:
promise = shutdown([Number shutdownMode])
Used to shut down a database instance. This is the flexible version of
oracledb.shutdown()
, allowing more control over behavior.
This method must be called twice. The first call blocks new connections. SQL
statements such as await ALTER DATABASE CLOSE NORMAL
and ALTER DATABASE
DISMOUNT
can then be used to close and unmount the database instance.
Alternatively database administration can be performed. Finally, a second call
connection.shutdown(oracledb.SHUTDOWN_MODE_FINAL)
is required to fully close
the database instance.
If the initial connection.shutdown()
shutdownMode
mode
oracledb.SHUTDOWN_MODE_ABORT
is used, then connection.shutdown()
does not
need to be called a second time.
See Database Start Up and Shut Down.
This method was added in node-oracledb 5.0.
shutdown()
: shutdownModeNumber shutdownMode
One of the constants
oracledb.SHUTDOWN_MODE_ABORT
,
oracledb.SHUTDOWN_MODE_DEFAULT
,
oracledb.SHUTDOWN_MODE_FINAL
,
oracledb.SHUTDOWN_MODE_IMMEDIATE
,
oracledb.SHUTDOWN_MODE_TRANSACTIONAL
, or
oracledb.SHUTDOWN_MODE_TRANSACTIONAL_LOCAL
.
If oracledb.SHUTDOWN_MODE_ABORT
is used, then connection.shutdown()
does not
need to be called a second time.
Only the second invocation of connection.shutdown()
should use
oracledb.SHUTDOWN_MODE_FINAL
.
shutdown()
: Callback Functionfunction(Error error)
Callback function parameter | Description |
---|---|
Error error | If shutdown() succeeds, error is NULL. If an error occurs, then error contains the error message. |
connection.subscribe()
Callback:
subscribe(String name, Object options, function(Error error, Object result){});
Promise:
promise = subscribe(String name, Object options);
Register a JavaScript callback method to be invoked when data is changed in the database by any committed transaction, or when there are Advanced Queuing messages to be dequeued.
For notification to work, the connection must be created with
events
mode true.
The database must be able to connect to the node-oracledb machine for notifications to be received. Typically this means that the machine running node-oracledb needs a fixed IP address. If there is any problem sending a notification, then the callback method will not be invoked.
The connection.subscribe()
method may be called multiple times with the same
name
, as long as the same connection is used. In this case, the second and
subsequent invocations ignore all options
properties other than
sql
and binds
. Instead, the
new SQL statement is registered to the same subscription, and the same
JavaScript notification callback is used. For performance reasons this can be
preferable to creating a new subscription for each query.
See Continuous Query Notification (CQN) and Advanced Queuing Notifications for more information.
This method was added in node-oracledb 2.3. AQ notifications were added in node-oracledb 4.0
The result
callback parameter was added in node-oracledb 4.0.
subscribe()
: NameString name
For Continuous Query Notification this is an arbitrary name given to the subscription. For Advanced Queuing notifications this must be the queue name.
subscribe()
: OptionsObject options
The options that control the subscription. The following properties can be set.
binds
Object binds
An array (bind by position) or object (bind by name) containing the
bind values to use in the sql
property.
callback
function callback(Object message)
The notification callback that will be called whenever notifications are sent by the database. It accepts one parameter which contains details of the notification.
Callback function parameter | Description |
---|---|
Object message | Information about the notification. Described below. |
The message
parameter in the notification callback is an object containing the following properties:
dbName
- the name of the database which sent a notification. This property is only defined for CQN. It is not defined when type
is oracledb.SUBSCR_EVENT_TYPE_DEREG
.queueName
- the name of the Advanced Queue. Undefined for CQN. This was added in node-oracledb 4.0.queries
- an array of objects specifying the queries which were affected by the Query Change notification. This is only defined if the type
key is the value oracledb.SUBSCR_EVENT_TYPE_QUERY_CHANGE
. It contains the following key:
tables
- an array of objects identical to the objects created for Database Change Notification (see the tables
property below).registered
- a Boolean indicating whether the subscription is registered with the database. Will be false if type
is oracledb.SUBSCR_EVENT_TYPE_DEREG
or if the subscription was created with the qos
property set to oracledb.SUBSCR_QOS_DEREG_NFY
.tables
- an array of objects specifying the tables which were affected by the notification. This is only defined if type
is oracledb.SUBSCR_EVENT_TYPE_OBJ_CHANGE
. It contains the following properties:
name
- the name of the table which was modified in some way.operation
- an integer mask composed of one or more values of the following constants:
oracledb.CQN_OPCODE_ALL_ROWS
- if 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. This may also be set when too many rows are returned.oracledb.CQN_OPCODE_ALTER
- if the table was altered in the notifying transaction.oracledb.CQN_OPCODE_DELETE
- if the notifying transaction included deletes on the table.oracledb.CQN_OPCODE_DROP
- if the table was dropped in the notifying transaction.oracledb.CQN_OPCODE_INSERT
- if the notifying transaction included inserts on the table.oracledb.CQN_OPCODE_UPDATE
- if the notifying transaction included updates on the table.rows
- an array of objects specifying the rows which were changed. This will only be defined if the qos
quality of service used when creating the subscription indicated the desire for ROWIDs and no summary grouping took place. It contains the following properties:
operation
- an integer which is one of oracledb.CQN_OPCODE_INSERT
, oracledb.CQN_OPCODE_UPDATE
, oracledb.CQN_OPCODE_DELETE
as described earlierrowid
- a string containing the ROWID of the row that was affectedtxId
- a buffer containing the identifier of the CQN transaction which spawned the notification.type
- the type of notification sent. This will be the value of one of the following constants:
oracledb.SUBSCR_EVENT_TYPE_AQ
- One or more Advanced Queuing messages are available to be dequeued.oracledb.SUBSCR_EVENT_TYPE_DEREG
- the subscription has been closed or the timeout value has been reached.oracledb.SUBSCR_EVENT_TYPE_OBJ_CHANGE
- object-level notifications are being used (Database Change Notification).oracledb.SUBSCR_EVENT_TYPE_QUERY_CHANGE
- query-level notifications are being used (Continuous Query Notification).clientInitiated
Boolean clientInitiated
This property enables CQN “client initiated” connections which internally use the same approach as normal connections to the database, and do not require the database to be able to connect back to the application. Since client initiated connections do not need additional network configuration, they have ease-of-use and security advantages.
The default is false.
This property was added in node-oracledb 4.2. It is available when Oracle Database and the Oracle client libraries are version 19.4 or higher.
groupingClass
Number groupingClass
An integer mask which currently, if set, can only contain the value
oracledb.SUBSCR_GROUPING_CLASS_TIME
. If
this value is set then notifications are grouped by time into a single
notification.
groupingType
Number groupingType
Either
oracledb.SUBSCR_GROUPING_TYPE_SUMMARY
(the default) indicating notifications should be grouped in a summary,
or
oracledb.SUBSCR_GROUPING_TYPE_LAST
indicating the last notification in the group should be sent.
groupingValue
Number groupingValue
If groupingClass
contains
oracledb.SUBSCR_GROUPING_CLASS_TIME
then groupingValue
can be used to set the number of seconds over
which notifications will be grouped together, invoking callback
once. If groupingClass
is not set, then groupingValue
is ignored.
ipAddress
String ipAddress
A string containing an IPv4 or IPv6 address on which the subscription should listen to receive notifications. If not specified, then the Oracle Client library will select an IP address.
namespace
Number namespace
One of the
oracledb.SUBSCR_NAMESPACE_AQ
or
oracledb.SUBSCR_NAMESPACE_DBCHANGE
(the default) constants.
You can use oracledb.SUBSCR_NAMESPACE_AQ
to get notifications that
Advanced Queuing messages are available to be dequeued, see
Advanced Queuing Notifications.
operations
Number operations
An integer mask containing one or more of the operation type
oracledb.CQN_OPCODE_*
constants to indicate
what types of database change should generation notifications.
port
Number port
The port number on which the subscription should listen to receive notifications. If not specified, then the Oracle Client library will select a port number.
qos
Number qos
An integer mask containing one or more of the quality of service
oracledb.SUBSCR_QOS_*
constants.
sql
String sql
The SQL query string to use for notifications.
timeout
The number of seconds the subscription should remain active. Once this length of time has been reached, the subscription is automatically unregistered and a deregistration notification is sent.
subscribe()
: Callback Functionfunction(Error error, Object result)
Callback function parameter | Description |
---|---|
Error error | If subscribe() succeeds, error is NULL. If an error occurs, then error contains the error message. |
Object result | For CQN oracledb.SUBSCR_NAMESPACE_DBCHANGE subscriptions this contains a single property regId corresponding the value of REGID in the database view USER_CHANGE_NOTIFICATION_REGS or the value of REG_ID in USER_SUBSCR_REGISTRATIONS . For AQ oracledb.SUBSCR_NAMESPACE_AQ subscriptions, regId is undefined. Due to Node.js type limitations, the largest regId shown will be 232 - 1. Larger values will wrap. |
The result
callback parameter was added in node-oracledb 4.0.
connection.startup()
Callback:
startup ([Object options,] function(Error error) {});
Promise:
promise = startup([Object options]);
Used to start up a database instance. This is the flexible version of
oracledb.startup()
, allowing more control over behavior.
The connection must be a standalone connection, not a pooled connection.
This function starts the database in an unmounted state. SQL statements such as
ALTER DATABASE MOUNT
and ALTER DATABASE OPEN
can then be executed to
completely open the database instance. Database recovery commands could also be
executed at this time.
The connection used must have the privilege
set to
oracledb.SYSPRELIM
, along with either
oracledb.SYSDBA
or
oracledb.SYSOPER
. For example oracledb.SYSDBA
| oracledb.SYSPRELIM
.
See Database Start Up and Shut Down.
This method was added in node-oracledb 5.0.
startup()
: optionsforce
Shuts down a running database using
oracledb.SHUTDOWN_MODE_ABORT
before restarting
the database instance. The next database start up may require instance recovery.
The default for force
is false.
pfile
After the database is started, access is restricted to users who have the CREATE_SESSION and RESTRICTED SESSION privileges. The default is false.
restrict
The path and filename for a local text file containing Oracle Database initialization parameters. If pfile
is not set, then the database server-side parameter file is used.
startup()
: Callback Functionfunction(Error error)
Callback function parameter | Description |
---|---|
Error error | If startup() succeeds, error is NULL. If an error occurs, then error contains the error message. |
connection.unsubscribe()
Callback:
unsubscribe(String name, function(Error error){});
Promise:
promise = unsubscribe(String name);
Unregister a Continuous Query Notification (CQN) subscription
previously created with connection.subscribe()
. No
further notifications will be sent. The notification callback does
not receive a notification of the deregistration event.
A subscription can be unregistered using a different connection to the initial subscription, as long as the credentials are the same.
If the subscription timeout
was reached and
the subscription was automatically unregistered, you will get an error
if you call connection.unsubscribe()
.
This method was added in node-oracledb 2.3.
String name
The name of the subscription used in connection.subscribe()
.
function(Error error)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If unsubscribe() succeeds, error is NULL. If an error occurs, then error contains the error message. |
An AqQueue object is created by connection.getQueue()
. It
is used for enqueuing and dequeuing Oracle Advanced Queuing messages.
Each AqQueue can be used for enqueuing, dequeuing, or for both.
See Oracle Advanced Queuing (AQ) for usage.
The AqQueue class was added in node-oracledb 4.0.
aqQueue.name
readonly String name
A string containing the name of the queue specified in the
connection.getQueue()
call.
aqQueue.deqOptions
AqDeqOptions deqOptions
An object specifying the Advanced Queuing options to use when
dequeuing messages. Attributes can be set before each
queue.deqOne()
or
queue.deqMany()
, see Changing AQ
options.
When a queue is created, the queue.deqOptions
property is
an AqDeqOptions object. AqDeqOptions objects
cannot be created independently.
Attribute Name | Description |
---|---|
condition |
A String that defines the condition that must be satisfied in order for a message to be dequeued. |
consumerName |
A String that defines the name of the consumer that is dequeuing messages. |
correlation |
A String that defines the correlation to use when dequeuing. |
mode |
An integer value that defines the mode to use for dequeuing messages. It can be one of the following constants: oracledb.AQ_DEQ_MODE_BROWSE , oracledb.AQ_DEQ_MODE_LOCKED , oracledb.AQ_DEQ_MODE_REMOVE , oracledb.AQ_DEQ_MODE_REMOVE_NO_DATA . |
msgId |
A Buffer containing a unique identifier specifying the message to be dequeued. |
navigation |
An integer value that defines the position in the queue of the message that is to be dequeued. It can be one of the following constants: oracledb.AQ_DEQ_NAV_FIRST_MSG , oracledb.AQ_DEQ_NAV_NEXT_TRANSACTION , oracledb.AQ_DEQ_NAV_NEXT_MSG . |
transformation |
A String that defines the transformation that will take place on messages when they are dequeued. |
visibility |
An integer value that defines whether the dequeue occurs in the current transaction or as a separate transaction. It can be one of the following constants: oracledb.AQ_VISIBILITY_IMMEDIATE , oracledb.AQ_VISIBILITY_ON_COMMIT . |
wait |
An integer defining the number of seconds to wait for a message matching the search criteria to become available. It can alternatively be one of the following constants: oracledb.AQ_DEQ_NO_WAIT , oracledb.AQ_DEQ_WAIT_FOREVER. |
See Oracle Advanced Queuing Documentation for more information about attributes.
aqQueue.enqOptions
AqEnqOptions enqOptions
An object specifying the Advanced Queuing options to use when
enqueuing messages. Attributes can be set before each
queue.enqOne()
or
queue.enqMany()
call to change the behavior
of message delivery, see Changing AQ options.
When a queue is created, the queue.enqOptions
property is
an AqEnqOptions object. AqEnqOptions objects
cannot be created independently.
Attribute Name | Description |
---|---|
deliveryMode |
An integer defining the delivery mode when enqueuing messages. It can be one of the following constants: oracledb.AQ_MSG_DELIV_MODE_PERSISTENT , oracledb.AQ_MSG_DELIV_MODE_BUFFERED , oracledb.AQ_MSG_DELIV_MODE_PERSISTENT_OR_BUFFERED |
transformation |
A string defining the transformation that will take place when messages are enqueued. |
visibility |
An integer value that defines whether the enqueue occurs in the current transaction or as a separate transaction. It can be one of the following constants: oracledb.AQ_VISIBILITY_IMMEDIATE , oracledb.AQ_VISIBILITY_ON_COMMIT . |
See Oracle Advanced Queuing Documentation for more information about attributes.
aqQueue.payloadType
readonly Number payloadType
One of oracledb.DB_TYPE_RAW
or oracledb.DB_TYPE_OBJECT
constants.
aqQueue.payloadTypeClass
readonly DbObject payloadTypeClass
The DbObject Class corresponding to the payload type specified when the queue was created.
This is defined only if payloadType
has the value oracledb.DB_TYPE_OBJECT
.
aqQueue.payloadTypeName
readonly String payloadTypeName
Either the string “RAW” or the name of the Oracle Database object type identified when the queue was created.
aqQueue.deqMany()
Callback:
deqMany(Number maxMessages, function(Error error, Array messages));
Promise:
promise = deqMany(Number maxMessages);
Dequeues up to the specified number of messages from an Oracle Advanced Queue.
Number maxMessages
Dequeue at most this many messages. Depending on the dequeue
options, the number of messages returned will be between zero and
maxMessages
.
function(Array messages, Error error)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Array messages | An array of AqMessage objects. |
Error error | If deqMany() succeeds, error is NULL. If an error occurs, then error contains the error message. |
aqQueue.deqOne()
Callback:
deqOne(function(Error error, AqMessage message));
Promise:
promise = deqOne();
Dequeues a single message from an Oracle Advanced Queue. Depending on the dequeue options, the message may also be returned as undefined if no message is available.
function(Error error, AqMessage message)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If deqOne() succeeds, error is NULL. If an error occurs, then error contains the error message. |
AqMessage message | The message that is dequeued. See AqMessage Class. |
Dequeued messages are returned as AqMessage objects. Note AqMessage objects are not used for enqueuing.
Attribute Name | Description |
---|---|
correlation |
A String containing the correlation that was used during enqueue. |
delay |
An integer containing the number of seconds the message was delayed before it could be dequeued. |
deliveryMode |
An integer containing the delivery mode the messages was enqueued with. |
exceptionQueue |
A String containing the name of the exception queue defined when the message was enqueued. |
expiration |
The number of seconds until expiration defined when the message was enqueued. |
msgId |
A Buffer containing the unique identifier of the message. |
numAttempts |
An integer containing the number of attempts that were made to dequeue the message. |
originalMsgId |
A Buffer containing the unique identifier of the message in the last queue that generated it. |
payload |
A Buffer or DbObject containing the payload of the message, depending on the value of queue.payloadType . Note that enqueued Strings are returned as UTF-8 encoded Buffers. |
priority |
An integer containing the priority of the message when it was enqueued. |
state |
An integer representing the state of the message. It is one of the following constants: oracledb.AQ_MSG_STATE_READY , oracledb.AQ_MSG_STATE_WAITING , oracledb.AQ_MSG_STATE_PROCESSED , oracledb.AQ_MSG_STATE_EXPIRED |
See Oracle Advanced Queuing Documentation for more information about attributes.
aqQueue.enqMany()
Callback:
enqMany(Array messages, function(Error error));
Promise:
promise = enqMany();
Enqueues multiple messages to an Oracle Advanced Queue.
Warning: calling enqMany()
in parallel on different connections
acquired from the same pool may fail due to Oracle bug 29928074.
Ensure that enqMany()
is not run in parallel, use standalone
connections, or make multiple calls to
enqOne()
. The deqMany()
method is not affected.
Array messages
Each element of the array must be a String, a Buffer, a DbObject, or a JavaScript Object
as used by enqOne()
.
function(Error error)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If enqMany() succeeds, error is NULL. If an error occurs, then error contains the error message. |
aqQueue.enqOne()
Callback:
enqOne(String message, function(Error error));
enqOne(Buffer message, function(Error error));
enqOne(DbObject message, function(Error error));
enqOne(Object message, function(Error error));
Promise:
promise = enqOne();
Enqueues a single message to an Oracle Advanced Queue. The message may be a String, or a Buffer, or a DbObject. It may also be a JavaScript Object containing the actual message and some attributes controlling the behavior of the queued message.
String | Buffer | DbObject | Object message
The message can be one of the following four types.
String message
If the message is a String, it will be converted to a buffer using the UTF-8 encoding.
Buffer message
If the message is a Buffer, it will be transferred as it is.
DbObject message
An object of the DbObject Class.
Object message
A JavaScript object can be used to
alter the message properties. It must contain a payload
property with the actual message content. It may contain
other attributes as noted below.
Message Attribute | Description |
---|---|
correlation |
A string containing the correlation of the message to be enqueued. |
delay |
The number of seconds to delay the message before it can be dequeued. |
exceptionQueue |
A string containing the name of an exception queue in which to place the message if an exception takes place. |
expiration |
The number of seconds the message is available to be dequeued before it expires. |
payload |
A String, Buffer or DbObject that is the actual message to be queued. This property must be specified. |
priority |
An integer priority of the message. |
See Oracle Advanced Queuing Documentation for more information about attributes.
function(Error error)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If enqOne() succeeds, error is NULL. If an error occurs, then error contains the error message. |
Calling connection.getDbObjectClass()
returns a
prototype object representing a named Oracle Database object or
collection. Use dbObject.prototype
on the class to see the
available attributes.
Objects of a named DbObject type are:
new()
See Oracle Database Objects and Collections for more information.
The DbObject class was added in node-oracledb 4.0.
The properties of a DbObject object are listed below.
dbObject.attributes
Object attributes
When dbObject.isCollection
is false, this will be an object
containing attributes corresponding to the Oracle Database object
attributes. The name of each attribute follows normal Oracle casing
semantics.
Each attribute will have an object that contains:
type
: the value of one of the Oracle Database Type Constants, such as 2010 for oracledb.DB_TYPE_NUMBER
and 2023 for oracledb.DB_TYPE_OBJECT
.typeName
: a string corresponding to the type, such as “VARCHAR2” or “NUMBER”. When the attribute is a DbObject, it will contain the name of the object.typeClass
: set if the value of type
is a DbObject. It is the DbObject class for the attribute.For example:
attributes: {
STREET_NUMBER: { type: 2, typeName: 'NUMBER' },
LOCATION: {
type: 2023,
typeName: 'MDSYS.SDO_POINT_TYPE',
typeClass: [Function]
}
}
dbObject.elementType
readonly Number elementType
When dbObject.isCollection
is true, this will have a value
corresponding to one of the Oracle Database Type
Constants.
dbObject.elementTypeClass
readonly Object elementTypeClass
dbObject.elementTypeName
readonly String elementTypeName
When dbObject.isCollection
is true, this will have the name of the
element type, such as “VARCHAR2” or “NUMBER”.
dbObject.fqn
readonly String fqn
The fully qualified name of the Oracle Database object or collection.
dbObject.isCollection
readonly Boolean isCollection
This is true if the Oracle object is a collection, false otherwise.
dbObject.length
readonly Number length
When dbObject.isCollection
is true, this will have the number of
elements in the collection. It is undefined for non-collections.
dbObject.name
readonly String name
The name of the Oracle Database object or collection.
dbObject.schema
readonly String schema
The schema owning the Oracle Database object or collection.
These methods can be used on Oracle Database collections, identifiable
when dbObject.isCollection
is
true. When collections are fetched from the database, altered, and
then passed back to the database, it may be more efficient to use
these methods directly on the retrieved DbObject than it is to convert
that DbObject to and from a JavaScript object.
Method Name | Description |
---|---|
dbObject.append(value) |
Add the given value to the end of the collection. |
dbObject.deleteElement(Number index) |
Deletes the value from collection at the given index. |
dbObject.getElement(Number index) |
Return the value associated with the given index. |
dbObject.getFirstIndex() |
Returns the first index for later use to obtain the value. |
dbObject.getKeys() |
Returns a JavaScript array containing the ‘index’ keys. |
dbObject.getLastIndex() |
To obtain the last index for later use to obtain a value. |
dbObject.getNextIndex(Number index) |
Returns the next index value for later use to obtain a value. |
dbObject.getPrevIndex(Number index) |
Returns the previous index for later use to obtain the value. |
dbObject.hasElement(Number index) |
Returns true if an element exists in the collection at the given index. Returns false otherwise. |
dbObject.setElement(Number index, value) |
To set the given value at the position of the given index. |
dbObject.getValues() |
Returns an array of element values as a JavaScript array in key order. |
dbObject.trim(count) |
Trims the specified number of elements from the end of the collection. |
Lob objects can be used to access Oracle Database CLOB and BLOB data.
A Lob object implements the Node.js Stream interface.
See Working with CLOB, NCLOB and BLOB Data and LOB Bind Parameters for more information.
The properties of a Lob object are listed below.
lob.chunkSize
readonly Number chunkSize
This corresponds to the size used by the Oracle LOB layer when accessing or modifying the LOB value.
lob.length
readonly Number length
Length of a queried LOB in bytes (for BLOBs) or characters (for CLOBs and NCLOBs).
lob.pieceSize
Number pieceSize
The number of bytes (for BLOBs) or characters (for CLOBs and NCOBs) to read for
each Stream data
event of a queried LOB.
The default value is chunkSize
.
For efficiency, it is recommended that pieceSize
be a multiple of
chunkSize
.
The property should not be reset in the middle of streaming since data will be lost when internal buffers are resized.
The maximum value for pieceSize
is limited to the value of UINT_MAX.
lob.type
readonly Number type
This read-only attribute shows the type of Lob being used. It will have the
value of one of the constants oracledb.BLOB
,
oracledb.CLOB
or
oracledb.NCLOB
. The value is derived from the
bind type when using LOB bind variables, or from the column type when a LOB is
returned by a query.
lob.close()
Note: this method is deprecated and lob.destroy()
should be
used instead.
Callback:
close(function(Error error){});
Promise:
promise = close();
Explicitly closes a Lob.
Lobs created with createLob()
should be explicitly
closed when no longer needed. This frees resources in node-oracledb and in
Oracle Database.
Persistent or temporary Lobs returned from the database may also be closed as long as streaming is not currently happening. Note these Lobs are automatically closed when streamed to completion or used as the source for an IN OUT bind. If you try to close a Lob being used for streaming you will get the error NJS-023: concurrent operations on a Lob are not allowed.
The lob.close()
method emits the Node.js Stream close
event unless the
Lob has already been explicitly or automatically closed.
The connection must be open when calling lob.close()
on a temporary
LOB, such as those created by createLob()
.
Once a Lob is closed, it cannot be bound.
See Closing Lobs for more discussion.
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. |
lob.destroy()
destroy([Error error]);
This synchronous method explicitly destroys a Lob.
Lobs created with createLob()
should be
explicitly closed with lob.destroy()
when no longer
needed. This frees resources in node-oracledb and in Oracle Database.
Persistent or temporary Lobs returned from the database may also be
closed with lob.destroy()
. Note these Lobs are automatically closed when streamed to
completion or used as the source for an IN OUT bind.
The lob.destroy()
method emits the Node.js Stream close
event.
Once a Lob is destroyed, it cannot be used.
See Closing Lobs for more discussion.
Error error
Parameter | Description |
---|---|
Error error | This optional parameter is used for the error emitted in an error event. |
lob.getData()
Callback:
getData(function(Error error, String data));
getData(function(Error error, Buffer data));
Promise:
promise = getData();
Return all the LOB data. CLOBs and NCLOBs will be returned as strings. BLOBs will be returned as a Buffer. This method is usable for LOBs up to 1 GB in length.
For queries returning LOB columns, it can be more efficient to use
fetchAsString
,
fetchAsBuffer
, or
fetchInfo
instead of lob.getData()
.
Note it is an asynchronous method and requires a round-trip to the database:
const data = await myLob.getData();
This method was added in node-oracledb 4.0.
function(Error error)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If getData() succeeds, error is NULL. If an error occurs, then error contains the error message. |
String data or Buffer data | The value of the LOB. |
A connection Pool object is created by calling the
oracledb.createPool()
method.
The Pool object obtains connections to the Oracle database using the
getConnection()
method to “check them out” from the pool. Internally
Oracle Call Interface Session Pooling is used.
After the application finishes using a connection pool, it should
release all connections and terminate the connection pool by calling
the close()
method on the Pool object.
See Connection Pooling for more information.
The Pool object properties may be read to determine the current values.
pool.connectionsInUse
readonly Number connectionsInUse
The number of currently active connections in the connection pool
i.e. the number of connections currently “checked out” using
getConnection()
.
pool.connectionsOpen
readonly Number connectionsOpen
The number of currently open connections in the underlying connection pool.
pool.poolAlias
readonly Number poolAlias
The alias of this pool in the connection pool cache. An alias cannot be changed once the pool has been created. This property will be undefined for the second and subsequent pools that were created without an explicit alias specified.
pool.poolIncrement
readonly Number poolIncrement
The number of connections that are opened whenever a connection request exceeds the number of currently open connections.
pool.poolMax
readonly Number poolMax
The maximum number of connections that can be open in the connection pool.
See oracledb.poolMax
.
pool.poolMin
readonly Number poolMin
The minimum number of connections a connection pool maintains, even when there is no activity to the target database.
See oracledb.poolMin
.
pool.poolPingInterval
readonly Number poolPingInterval
The maximum number of seconds that a connection can remain idle in a
connection pool (not “checked out” to the application by
getConnection()
) before node-oracledb pings the database prior to
returning that connection to the application.
See oracledb.poolPingInterval
.
pool.poolTimeout
readonly Number poolTimeout
The time (in seconds) after which the pool terminates idle connections (unused in the pool). The number of connections does not drop below poolMin.
See oracledb.poolTimeout
.
pool.queueMax
readonly Number queueMax
The maximum number of pending pool.getConnection()
calls that can be
queued.
See oracledb.queueMax
.
This property was added in node-oracledb 5.0.
pool.queueRequests
This property was removed in node-oracledb 3.0. See Connection Pool Queue for more information.
pool.queueTimeout
readonly Number queueTimeout
The time (in milliseconds) that a connection request should wait in the queue before the request is terminated.
pool.sessionCallback
readonly Function sessionCallback
readonly String sessionCallback
The Node.js or PL/SQL function that is invoked by pool.getConnection()
when the connection is brand new.
See Connection Tagging and Session State.
pool.status
readonly Number status
One of the oracledb.POOL_STATUS_OPEN
,
POOL_STATUS_DRAINING
, or
POOL_STATUS_CLOSED
constants indicating whether the
pool is open, being drained of in-use connections, or has been closed.
See Connection Pool Closing and Draining.
pool.stmtCacheSize
readonly Number stmtCacheSize
The number of statements to be cached in the statement cache of each connection.
pool.close()
Callback:
close([Number drainTime,] function(Error error){});
Promise:
promise = close([Number drainTime]);
This call closes connections in the pool and terminates the connection pool.
If a drainTime
is not given, then any open connections should be
released with connection.close()
before
pool.close()
is called, otherwise the pool close will fail and the
pool will remain open.
If a drainTime
is specified, then any new pool.getConnection()
calls will fail. If connections are in use by the application, they
can continue to be used for the specified number of seconds, after
which the pool and all open connections are forcibly closed. Prior to
this time limit, if there are no connections currently “checked out”
from the pool with getConnection()
, then the pool and any
connections that are idle in the pool are immediately closed.
Non-zero drainTime
values are strongly recommended so applications
have the opportunity to gracefully finish database operations. A
drainTime
of 0 may be used to close a pool and its connections
immediately.
In network configurations that drop (or in-line) out-of-band breaks,
forced pool termination may hang unless you have
DISABLE_OOB=ON
in a sqlnet.ora
file, see Optional Oracle
Net Configuration.
When the pool is closed, it will be removed from the connection pool cache.
This method was added to node-oracledb 1.9, replacing the equivalent
alias pool.terminate()
.
The drainTime
parameter was added in node-oracledb 3.0.
Number drainTime
The number of seconds before the pool and connections are force closed.
If drainTime
is 0, the pool and its connections are closed immediately.
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. |
pool.getConnection()
Callback:
getConnection([Object poolAttrs,] function(Error error, Connection connection){});
Promise:
promise = getConnection([Object poolAttrs]);
This method obtains a connection from the connection pool.
If a previously opened connection is available in the pool, that
connection is returned. If all connections in the pool are in use, a
new connection is created and returned to the caller, as long as the
number of connections does not exceed the specified maximum for the
pool. If the pool is at its maximum limit, the getConnection()
call
results in an error, such as ORA-24418: Cannot open further sessions.
By default pools are created with
homogeneous
set to true. The
user name and password are supplied when the pool is created. Each
time pool.getConnection()
is called, a connection for that user is
returned:
const connection = await pool.getConnection();
If a heterogeneous pool was created by setting
homogeneous
to false during
creation and credentials were omitted, then the user name and password
may be used in pool.getConnection()
like:
const connection = await pool.getConnection(
{
user : 'hr',
password : mypw, // mypw contains the hr schema password
}
);,
In this case, different user names may be used each time
pool.getConnection()
is called. Proxy users may also be specified.
See Connection Handling for more information on connections.
See Heterogeneous Connection Pools and Pool Proxy Authentication for more information on heterogeneous pools.
Object poolAttrs
This parameter can contain a tag
property when connection
tagging is in use. It can also contain
shardingKey
and
superShardingKey
properties, when
using database sharding.
When getting connections from heterogeneous pools, this parameter can
contain user
and password
properties for true heterogeneous pool usage,
or it can contain a user
property when a pool proxy user is desired.
See Connection Attributes for discussion of these attributes.
function(Error error, Connection connection)
The parameters of the callback function are:
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. |
pool.terminate()
An alias for pool.close().
ResultSets allow query results to fetched from the database one at a time, or in groups of rows. They can also be converted to Readable Streams. ResultSets enable applications to process very large data sets.
ResultSets should also be used where the number of query rows cannot be predicted and may be larger than Node.js can handle in a single array.
A ResultSet object is obtained by setting resultSet: true
in the
options
parameter of the Connection execute()
method
when executing a query. A ResultSet is also returned to
node-oracledb when binding as type oracledb.CURSOR
to a
PL/SQL REF CURSOR bind parameter.
See Fetching Rows with Result Sets for more information on ResultSets.
The properties of a ResultSet object are listed below.
resultset.metaData
readonly Array metaData
Contains an array of objects with metadata about the query or REF CURSOR columns.
Each column’s name
is always given. If the
oracledb.extendedMetaData
or execute()
option
extendedMetaData
are true then
additional information is included.
See result.metaData
for the available attributes.
resultset.close()
Callback:
close(function(Error error){});
Promise:
promise = close();
Closes a ResultSet. Applications should always call this at the end of fetch or when no more rows are needed. It should also be called if no rows are ever going to be fetched from the ResultSet.
resultset.getRow()
Callback:
getRow(function(Error error, Object row){});
Promise:
promise = getRow();
This call fetches one row of the ResultSet as an object or an array of column values, depending on the value of outFormat.
At the end of fetching, the ResultSet should be freed by calling
close()
.
For tuning, adjust the values of the connection.execute()
options
fetchArraySize
and
prefetchRows
, see Tuning Fetch
Performance.
resultset.getRows()
Callback:
getRows(Number numRows, function(Error error, Array rows){});
Promise:
promise = getRows(Number numRows);
This call fetches numRows
rows of the ResultSet as an object or an
array of column values, depending on the value of outFormat.
At the end of fetching, the ResultSet should be freed by calling close()
.
Different values of numRows
may alter the time needed for fetching data from
Oracle Database. The value of fetchArraySize
has
no effect on getRows()
performance or internal buffering. The
prefetchRows
can have an effect.
resultset.toQueryStream()
toQueryStream();
This method will return a Readable Stream.
This synchronous method converts a ResultSet into a stream.
It can be used to make ResultSets from top-level queries or from REF
CURSOR bind variables streamable. To make top-level queries
streamable, the alternative connection.queryStream()
method may be easier to use.
To change the behavior of toQueryStream()
, such as setting the
query output Format or the internal buffer sizes
for performance, adjust global attributes such as
oracledb.outFormat
,
oracledb.fetchArraySize
, and
oracledb.prefetchRows
before calling
execute()
.
See Query Streaming for more information.
The toQueryStream()
method was added in node-oracledb 1.9. Support
for Node.js 8’s Stream destroy()
method was added in node-oracledb 2.1.
SODA can be used with Oracle Database 18.3 and above, when node-oracledb uses
Oracle Client 18.5 or Oracle Client 19.3, or later. The SODA bulk insert
methods sodaCollection.insertMany()
and
sodaCollection.insertManyAndGet()
are in Preview
status.
Each SodaCollection object contains read-only properties:
sodaCollection.metaData
readonly Object metaData
Metadata of the current collection. See SODA Client-Assigned Keys and Collection Metadata.
This property was added in node-oracledb 3.0. Its type was changed to Object in node-oracledb 4.0.
sodaCollection.name
readonly String name
Name of the current collection.
This property was added in node-oracledb 3.0.
sodaCollection.createIndex()
Callback:
createIndex(Object indexSpec, function(Error error){});
Promise:
promise = createIndex(Object indexSpec);
Creates an index on a SODA collection, to improve the performance of SODA query-by-examples (QBE) or enable text searches. An index is defined by a specification, which is a JSON object that specifies how particular QBE patterns are to be indexed for quicker matching.
Note that a commit should be performed before attempting to create an index.
Different index types can be used:
filter()
searches.$contains
operator in QBEs. Also improves QBE filter operation performance. Note a B-tree index will perform better for non-text searches.If oracledb.autoCommit
is true, and
createIndex()
succeeds, then any open user transaction is committed.
Note SODA DDL operations do not commit an open transaction the way that
SQL always does for DDL statements.
See Overview of SODA Indexing.
This method was added in node-oracledb 3.0.
As an example, if a collection has these documents:
{"name": "Chris"}
{"name": "Venkat"}
{"name": "Srinath"}
Then a B-tree index could be created with:
indexSpec = {name: "myIndex", fields: [{path: "name"}]};
await collection.createIndex(indexSpec);
This index would improve the performance of QBEs like:
d = await collection.find().filter({name: "Venkat"}).getOne();
createIndex()
ParametersindexSpec
Object indexSpec
An object with fields as shown in the SODA Index Specifications (Reference) manual.
createIndex()
: Callback Functionfunction(Error error)
Callback function parameter | Description |
---|---|
Error error | If createIndex() succeeds, error is NULL. If an error occurs, then error contains the error message. |
sodaCollection.drop()
Callback:
drop(function(Error error, Object result){});
Promise:
promise = drop();
Drops the current collection.
An error such as ORA-40626 will be returned and the collection will not be dropped if there are uncommitted writes to the collection in the current transaction.
If the collection was created with mode
oracledb.SODA_COLL_MAP_MODE
, then drop()
will not physically delete the database storage containing the
collection, and won’t drop SODA indexes. Instead it will simply unmap
the collection, making it inaccessible to SODA operations.
If oracledb.autoCommit
is true, and drop()
succeeds, then any open user transaction is committed. Note SODA
operations do not commit an open transaction the way that SQL always
does for DDL statements.
If the collection was created with custom metadata changing the key
assignment method to SEQUENCE, the drop()
method will not delete the
underlying Oracle sequence. This is in case it was created outside
SODA. To drop the sequence, use the SQL command DROP SEQUENCE after
drop()
has completed.
Note you should never use SQL DROP TABLE command on the database table
underlying a collection. This will not clean up SODA’s metadata. If
you do accidentally execute DROP SQL, you should cleanup the metadata
with drop()
or execute the SQL statement: SELECT
DBMS_SODA.DROP_COLLECTION('myCollection') FROM DUAL;
.
This method was added in node-oracledb 3.0.
drop()
: Callback Functionfunction(Error error, Object result)
Callback function parameter | Description |
---|---|
Error error | If drop() succeeds, error is NULL. It is not an error if the collection does not exist. If an error occurs, then error contains the error message. |
Object result | See below. |
The result
object contains one attribute:
Boolean dropped
If the drop operation succeeded, dropped
will be true. If no
collection was found, dropped
will be false.
sodaCollection.dropIndex()
Callback:
dropIndex(String indexName [, Object options], function(Error error, Object result){});
Promise:
promise = dropIndex(String indexName [, Object options]);
Drops the specified index.
If oracledb.autoCommit
is true,
and dropIndex()
succeeds, then any open user transaction is
committed. Note SODA operations do not commit an open transaction the
way that SQL always does for DDL statements.
This method was added in node-oracledb 3.0.
dropIndex()
: ParametersindexName
String indexName
Name of the index to be dropped.
options
Object options
The options
parameter can have the following attribute:
Boolean force
Setting force
to true forces dropping of a JSON Search index or
Spatial index if the underlying Oracle Database domain index does not
permit normal dropping. See DROP INDEX.
dropIndex()
Callback Functionfunction(Error error, Object result)
Callback function parameter | Description |
---|---|
Error error | If dropIndex() succeeds, error is NULL. It is not an error if the index does not exist. If an error occurs, then error contains the error message. |
Boolean dropped | If dropping the index succeeded, dropped will be true. If no index was found, dropped will be false. |
sodaCollection.find()
find()
The synchronous find()
method is used to locate and order a set of
SODA documents for retrieval, replacement, or removal. It creates and
returns a SodaOperation object which is used
via method chaining with non-terminal and terminal methods described
below. Note that SodaOperation is an internal object whose attributes
should not be accessed directly.
This method was added in node-oracledb 3.0.
Returns a SodaOperation object.
documents = await collection.find().filter({"address.city": "Melbourne", "salary": {"$gt": 500000}}).getDocuments();
See Simple Oracle Document Access (SODA) for more examples.
You can chain together SodaOperation methods, to specify read or write operations against a collection.
Non-terminal SodaOperation methods return the same object on which they are invoked, allowing them to be chained together.
A terminal SodaOperation method always appears at the end of a method chain to execute the operation.
A SodaOperation object is an internal object. You should not directly modify its properties.
Non-terminal SodaOperation methods are chained together to set criteria that documents must satisfy. At the end of the chain, a single terminal method specifies the operation to be performed on the matching documents.
When a non-terminal method is repeated, the last one overrides the
earlier one. For example if find().key("a").key("b")...
was used,
then only documents with the key “b” are matched. If
find().keys(["a","b"]).key("c")...
is used, then only the document
with the key “c” is matched.
sodaOperation.fetchArraySize()
fetchArraySize(Number size)
This property sets the size of an internal buffer used for fetching documents
from a collection with the terminal SodaOperation methods
getCursor()
and
getDocuments()
. Changing size
may affect
performance but does not affect how many documents are returned.
If fetchArraySize()
is not used, the size defaults to the current value of
oracledb.fetchArraySize
.
For node-oracledb examples, see SODA Query-by-Example Searches for JSON Documents
This method was added in node-oracledb 5.0. It requires Oracle Client 19.5 or later, and Oracle Database 18.3 or later.
sodaOperation.filter()
filter(Object filterSpec)
Sets a filter specification for the operation, allowing for complex document queries and ordering of JSON documents. Filter specifications can include comparisons, regular expressions, logical, and spatial operators, among others. See Overview of SODA Filter Specifications (QBEs) and SODA Filter Specifications (Reference).
For node-oracledb examples, see SODA Query-by-Example Searches for JSON Documents
This method was added in node-oracledb 3.0.
sodaOperation.key()
key(String value)
Sets the key value to be used to match a document for the operation.
Any previous calls made to this method or
keys()
will be ignored.
SODA document keys are unique.
This method was added in node-oracledb 3.0.
sodaOperation.keys()
keys(Array value)
Sets the keys to be used to match multiple documents for the
operation. Any previous calls made to this method or
key()
will be ignored.
SODA document keys are unique.
A maximum of 1000 keys can be used.
This method was added in node-oracledb 3.0.
sodaOperation.limit()
limit(Number n)
Sets the maximum number of documents that a terminal method will apply
to. The value of n
must be greater than 0. The limit is applied to
documents that match the other SodaOperation criteria. The limit()
method only applies to SodaOperation read operations like
getCursor()
and getDocuments()
. If a filter $orderby
is not
used, the document order is internally defined.
The limit()
method cannot be used in conjunction with
count()
.
This method was added in node-oracledb 3.0.
sodaOperation.skip()
skip(Number n)
Sets the number of documents that will be skipped before the terminal
method is applied. The value of n
must be greater or equal to 0. The
skip applies to documents that match the other SodaOperation criteria.
If a filter $orderby
is not used, the document order (and hence which
documents are skipped) is internally defined.
The skip()
method only applies to SodaOperation read operations like
getDocuments()
. It cannot be used with
count()
.
This method was added in node-oracledb 3.0.
sodaOperation.version()
version(String value)
Sets the document version that documents must have.
This is typically used in conjunction with a key, for example
collection.find().key("k").version("v").replaceOne(doc)
.
Using version()
allows for optimistic locking, so that the
subsequent SodaOperation terminal method does not affect a document
that someone else has already modified. If the requested document
version is not matched, then your terminal operation will not impact
any document. The application can then query to find the latest
document version and apply any desired change.
This method was added in node-oracledb 3.0.
A terminal SodaOperation method operates on the set of documents that satisfy the criteria specified by previous non-terminal methods in the method chain. Only one terminal method can be used in each chain.
sodaOperation.count()
Callback
count(function Error error, Object result){});
Promise
promise = count();
Finds the number of documents matching the given SodaOperation query criteria.
If skip()
or limit()
are set, then count()
will return an error.
If oracledb.autoCommit
is true, and
count()
succeeds, then any open transaction on the connection is
committed.
This method was added in node-oracledb 3.0.
function(Error error, Object result)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If count() succeeds, error is NULL. If an error occurs, then error contains the error message. |
Object result | See below. |
The result
object contains one attribute:
Number count
The number of documents matching the SodaOperation criteria.
Due to Node.js type limitations, the largest count
value will be
232 - 1, even if more rows exist. Larger values will wrap.
sodaOperation.getCursor()
Callback
getCursor(function(Error error, SodaDocumentCursor cursor){});
Promise
promise = getCursor()
Returns a SodaDocumentCursor for documents
that match the SodaOperation query criteria. The cursor can be
iterated over with
sodaDocumentCursor.getNext()
to access each
SodaDocument.
When the application has completed using the cursor it must be closed
with sodaDocumentCursor.close()
.
If the number of documents is known to be small, it is recommended to
use sodaOperation.getDocuments()
instead.
If oracledb.autoCommit
is true, and
getCursor()
succeeds, then any open transaction on the connection is
committed.
This method was added in node-oracledb 3.0.
function(Error error, SodaDocumentCursor cursor)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If getCursor() succeeds, error is NULL. If an error occurs, then error contains the error message. |
SodaDocumentCursor cursor | A cursor that can be iterated over to access SodaDocument objects matching the SodaOperation search criteria. |
sodaOperation.getDocuments()
Callback
getDocuments(function(Error error, Array documents){});
Promise
promise = getDocuments();
Gets an array of SodaDocuments matching the SodaOperation query criteria. An empty array will be returned when no documents match.
Where the number of matching documents is known to be small, this API
should be used in preference to
sodaOperation.getCursor()
.
If oracledb.autoCommit
is true, and
getDocuments()
succeeds, then any open transaction on the connection
is committed.
This method was added in node-oracledb 3.0.
function(Error error, Array documents)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If getDocuments() succeeds, error is NULL. If an error occurs, then error contains the error message. |
Array documents | An array of SodaDocuments that match the SodaOperation query criteria. |
sodaOperation.getOne()
Callback
getOne(function(Error error, SodaDocument document){});
Promise
promise = getOne();
Obtains one document matching the SodaOperation query criteria. If the criteria match more than one document, then only the first is returned.
Typically getone()
should be used with key(k)
or
key(k).version(v)
to ensure only one document is matched.
If oracledb.autoCommit
is true, and
getOne()
succeeds, then any open transaction on the connection is
committed.
This method was added in node-oracledb 3.0.
function(Error error, SodaDocument document)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If getOne() succeeds, error is NULL. If an error occurs, then error contains the error message. |
SodaDocument document | One SodaDocument that matches the sodaOperation query criteria. If no document is found, then document will be undefined. |
sodaOperation.remove()
Callback
remove(function(Error error, Object result){});
Promise
promise = remove();
Removes a set of documents matching the SodaOperation query criteria.
Note settings from skip()
and limit()
non-terminals are ignored because they only apply to read operations.
If oracledb.autoCommit
is true, and
remove()
succeeds, then removal and any open transaction on the
connection is committed.
This method was added in node-oracledb 3.0.
function(Error error, Object result)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If remove() succeeds, error is NULL. If an error occurs, then error contains the error message. |
Object result | See below. |
The result
object contains one attribute:
result.count
The number of documents removed from the collection.
Due to Node.js type limitations, the largest count
value will be
232 - 1, even if Oracle Database removed more rows. Larger values will wrap.
sodaOperation.replaceOne()
Callback
replaceOne(Object newDocumentContent, function(Error error, Object result){});
replaceOne(SodaDocument newSodaDocument, function(Error error, Object result){});
Promise
promise = replaceOne(Object newDocumentContent);
promise = replaceOne(SodaDocument newSodaDocument);
Replaces a document in a collection. The input document can be either a JavaScript object representing the data content, or it can be an existing SodaDocument.
The mediaType
document component and content of the document that
matches the SodaOperation query criteria will be replaced by the
content and any mediaType
document component of the new document.
Any other document components will not be affected. The
lastModified
and version
document components of the replaced
document will be updated.
The key()
non-terminal must be used when using replaceOne()
.
No error is reported if the operation criteria do not match any document.
Note settings from skip()
and limit()
non-terminals are ignored
because they only apply to read operations.
If oracledb.autoCommit
is true, and
replaceOne()
succeeds, then any open transaction on the connection
is committed.
This method was added in node-oracledb 3.0.
Object newDocumentContent
SodaDocument newSodaDocument
The new document. See sodaCollection.insertOne(), which has the same semantics for the document.
function(Error error, Object result)
Callback function parameter | Description |
---|---|
Error error | If replaceOne() succeeds, error is NULL. It is not an error if no document is replaced. If an error occurs, then error contains the error message. |
Object result | See below. |
The result
object contains one attribute:
result.replaced
This attribute will be true if the document was successfully replaced, false otherwise.
sodaOperation.replaceOneAndGet()
Callback
replaceOneAndGet(Object newDocumentContent, function(Error error, SodaDocument updatedDocument){});
replaceOneAndGet(SodaDocument newSodaDocument, function(Error error, SodaDocument updatedDocument){});
Promise
promise = replaceOneAndGet(Object newDocumentContent);
promise = replaceOneAndGet(SodaDocument newSodaDocument);
Replaces a document in a collection similar to
replaceOne()
, but also returns the
result document which contains all SodaDocument
components (key, version, etc.) except for content. Content itself is not
returned for performance reasons. The result document has new values
for components that are updated as part of the replace operation (such
as version, last-modified timestamp, and media type)
If oracledb.autoCommit
is true, and
replaceOneAndGet()
succeeds, then any open transaction on the
connection is committed.
This method was added in node-oracledb 3.0.
Object newDocumentContent
SodaDocument newSodaDocument
The new document. See sodaCollection.insertOne(), which has the same semantics for the document.
function(Error error, SodaDocument updatedDocument)
Callback function parameter | Description |
---|---|
Error error | If replaceOneAndGet() succeeds, error is NULL. It is not an error if no document is replaced. If an error occurs, then error contains the error message. |
SodaDocument updatedDocument | The updated SodaDocument if replacement was successful, otherwise updatedDocument will be undefined. The lastModified and version attributes of the stored SodaDocument will be updated. The mediaType attribute and the content will be replaced. Other attributes of newSodaDocument are ignored. Note for performance reasons, updatedDocument will not have document content and cannot itself be passed directly to SODA insert or replace methods. |
sodaCollection.getDataGuide()
Callback:
getDataGuide(function(Error error, SodaDocument document){});
Promise:
promise = getDataGuide();
Infers the schema of a collection of JSON documents at the current time. A JSON data guide shows details like the JSON property names, data types and lengths. It is useful for exploring the schema of a collection. The data guide is represented as JSON content in a SodaDocument.
This method is supported for JSON-only collections which have a JSON Search index where the “dataguide” option is “on”. An error will be returned if a data guide cannot be created.
A data guide is a best effort heuristic and should not be used as a schema to validate new JSON documents. The data guide is always additive, and does not update itself when documents are deleted. There are some limits such as the maximum number of children under one node, and the maximum length of a path.
If oracledb.autoCommit
is true, and
getDataGuide()
succeeds, then any open user transaction is
committed.
This method was added in node-oracledb 3.0.
function(Error error, SodaDocument document)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If getDataGuide() succeeds, error is NULL. If an error occurs, then error contains the error message. |
SodaDocument document | The SodaDocument containing JSON content which can be accessed from the document as normal with sodaDocument.getContent() , sodaDocument.getContentAsString() or sodaDocument.getContentAsBuffer() . |
sodaCollection.insertMany()
Callback:
insertMany(Array newDocumentContentArray, function(Error error){});
insertMany(Array newSodaDocumentArray, function(Error error){});
Promise:
promise = insertMany(Array newDocumentContentArray);
promise = insertMany(Array newSodaDocumentArray);
This is similar to insertOne()
however it
accepts an array of the Objects or SodaDocuments that insertOne()
accepts. When inserting multiple documents, using insertMany()
is
recommended in preference to insertOne()
.
If an error occurs, the offset attribute on the Error objects will contain the number of documents that were successfully inserted. Subsequent documents in the input array will not be inserted.
This method is in Preview status and should not be used in production.
This method was added in node-oracledb 4.0. It requires Oracle Client 18.5 or higher.
sodaCollection.insertManyAndGet()
Callback
insertManyAndGet(Array newDocumentContentArray, function(Error error, Array SodaDocuments){});
insertManyAndGet(Array newSodaDocumentArray, function(Error error, Array SodaDocuments){});
Promise
promise = insertManyAndGet(Array newDocumentContentArray);
promise = insertManyAndGet(Array newSodaDocumentArray);
Similar to sodaCollection.insertMany() but also returns
an array of the inserted documents so system managed properties, such as the
keys (in default collections), can be found. Content itself is not returned for
performance reasons. When inserting multiple documents, using
insertManyAndGet()
is recommended in preference to insertOneAndGet()
.
This method is in Preview status and should not be used in production.
This method was added in node-oracledb 4.0. It requires Oracle Client 18.5 or higher.
sodaCollection.insertOne()
Callback:
insertOne(Object newDocumentContent, function(Error error){});
insertOne(SodaDocument newSodaDocument, function(Error error){});
Promise:
promise = insertOne(Object newDocumentContent);
promise = insertOne(SodaDocument newSodaDocument);
Inserts a given document to the collection. The input document can be either a JavaScript object representing the data content, or it can be an existing SodaDocument.
Note SodaDocuments returned from
sodaCollection.insertOneAndGet()
,
sodaOperation.replaceOneAndGet()
, and
sodaCollection.insertManyAndGet()
cannot be
passed to SODA insert methods, since they do not contain any document content.
Instead, create a JavaScript object using the desired attribute values, or use
sodaDatabase.createDocument()
, or use a SodaDocument
returned by a sodaCollection.find()
query.
If oracledb.autoCommit
is true, and
insertOne()
succeeds, then the new document and any open transaction
on the connection is committed.
This method was added in node-oracledb 3.0.
The following examples are equivalent:
newDocumentContent = {name: "Alison"};
await sodaCollection.insertOne(newDocumentContent);
and
newDocumentContent = {name: "Alison"};
doc = sodaDatabase.createDocument(newDocumentContent);
await sodaCollection.insertOne(doc);
insertOne()
: ParametersnewDocumentContent
, newSodaDocument
Object newDocumentContent
SodaDocument newSodaDocument
The document to insert.
Passed as a simple JavaScript object, the value is interpreted as JSON document content. Other document components (key, version, etc.) will be auto-generated by SODA during insert. The media type will be set to “application/json”.
Alternatively, a SodaDocument can be passed.
The content
and mediaType
supplied in the SodaDocument will be
used. The key
, if set, will also be used if collection has
client-assigned keys. Other components in the input SodaDocument,
such as version and last-modified, will be ignored and auto-generated
values will be used instead.
insertOne()
Callback Functionfunction(Error error)
Callback function parameter | Description |
---|---|
Error error | If insertOne() succeeds, error is NULL. If an error occurs, then error contains the error message. |
sodaCollection.insertOneAndGet()
Callback
insertOneAndGet(Object newDocumentContent, function(Error error, SodaDocument document){});
insertOneAndGet(SodaDocument newSodaDocument, function(Error error, SodaDocument document){});
Promise
promise = insertOneAndGet(Object newDocumentContent);
promise = insertOneAndGet(SodaDocument newSodaDocument);
Inserts a document in a collection similar to
sodaCollection.insertOne()
, but also returns the result
document which contains all SodaDocument components (key,
version, etc.) except for content. Content itself is not returned for
performance reasons.
If you want to insert the document again, use the original newDocumentContent
or newSodaDocument
. Alternatively construct a new object from the returned
document and add content.
If oracledb.autoCommit
is true, and
insertOneAndGet()
succeeds, then any open transaction on the
connection is committed.
This method was added in node-oracledb 3.0.
insertOneAndGet()
: ParametersnewDocumentContent
, newSodaDocument
Object newDocumentContent
SodaDocument newSodaDocument
The document to insert.
For related documentation, see sodaCollection.insertOne()
insertOneAndGet()
Callback Functionfunction(Error error, SodaDocument document)
Callback function parameter | Description |
---|---|
Error error | If insertOne() succeeds, error is NULL. If an error occurs, then error contains the error message. |
SodaDocument document | A result SodaDocument that is useful for finding the system generated key and other metadata of the newly inserted document. Note for performance reasons, document will not have document content and cannot itself be passed directly to SODA insert or replace methods. |
sodaCollection.save()
Callback:
save(SodaDocument newSodaDocument, function(Error error){});
Promise:
promise = save(SodaDocument newSodaDocument);
This method behaves like sodaCollection.insertOne()
with
the exception that if a document with the same key already exists, then it is
updated instead.
The collection must use client-assigned keys keys, which is
why save()
accepts only a SodaDocument, unlike
insertOne()
. If the collection is not configured with client-assigned keys,
then the behavior is exactly the same as sodaCollection.insertOne()
.
This method was added in node-oracledb 5.0. It requires Oracle Client 20 or later, and Oracle Database 18.3 or later.
sodaCollection.saveAndGet()
Callback
saveAndGet(SodaDocument newSodaDocument, function(Error error, SodaDocument document){});
Promise
promise = saveAndGet(SodaDocument newSodaDocument);
This method behaves like
sodaCollection.insertOneAndGet()
with the
exception that if a document with the same key already exists, then it is
updated instead.
The collection must use client-assigned keys keys, which is
why saveAndGet()
accepts only a SodaDocument, unlike
insertOneAndGet()
. If the collection is not configured with client-assigned
keys, then the behavior is exactly the same as
sodaCollection.insertOneAndGet()
.
This method was added in node-oracledb 5.0. It requires Oracle Client 20 or later, and Oracle Database 18.3 or later.
sodaCollection.truncate()
Callback
truncate(function(Error error) {});
Promise
promise = truncate();
This method truncates a collection, removing all documents. The collection will not be deleted.
This method was added in node-oracledb 5.0. It requires Oracle Client 20 or later, and Oracle Database 18.3 or later.
truncate()
Callback Functionfunction(Error error)
Callback function parameter | Description |
---|---|
Error error | If truncate() succeeds, error is NULL. If an error occurs, then error contains the error message. |
The SodaDatabase class is the top level object for node-oracledb SODA operations. A ‘SODA database’ is an abstraction, allowing access to SODA collections in that ‘SODA database’, which then allow access to documents in those collections.
SODA can be used with Oracle Database 18.3 and above, when node-oracledb uses
Oracle Client 18.5 or Oracle Client 19.3, or later. The SODA bulk insert
methods sodaCollection.insertMany()
and
sodaCollection.insertManyAndGet()
are in Preview
status.
A SODA database is equivalent to an Oracle Database user, see Overview of SODA in the Introduction to SODA manual.
A SODA database object is created by calling
connection.getSodaDatabase()
.
See Simple Oracle Document Access (SODA) for more information.
sodaDatabase.createCollection()
Callback:
createCollection(String collectionName [, Object options], function(Error error, SodaCollection collection){});
Promise:
promise = createCollection(String collectionName [, Object options]);
Creates a SODA collection of the given name. If you try to create a collection, and a collection with the same name already exists, then that existing collection is opened without error.
Optional metadata allows collection customization. If metadata is not supplied, a default collection will be created
By default, createCollection()
first attempts to create the Oracle Database
table used internally to store the collection. If the table exists already, it
will attempt to use it as the table underlying the collection. Most users will
use this default behavior.
If the optional mode
parameter is
oracledb.SODA_COLL_MAP_MODE
, SODA will
attempt to use a pre-existing table as the table underlying the
collection.
If oracledb.autoCommit
is true, and
createCollection()
succeeds, then any open transaction on the
connection is committed. Note SODA operations do not commit an open
transaction the way that SQL always does for DDL statements.
This method was added in node-oracledb 3.0.
createCollection(): collectionName
Name of the collection to be created.
createCollection(): options
Object options
The options that specify the collection. The following properties can be set.
metaData
Object metaData
Metadata specifying various details about the collection, such as its database storage, whether it should track version and time stamp document components, how such components are generated, and what document types are
If undefined or null, then a default collection metadata description will be used. The default metadata specifies that the collection contains only JSON documents, and is recommend for most SODA users.
For more discussion see SODA Client-Assigned Keys and Collection Metadata. Also see SODA Collection Metadata Components.
mode
Number mode
If mode
is oracledb.SODA_COLL_MAP_MODE
, the
collection will be stored in an externally, previously created table.
A future sodaCollection.drop()
will not drop the collection table.
It will simply unmap it, making it inaccessible to SODA operations.
Most users will leave mode
undefined.
createCollection()
: Callback Functionfunction(Error error, SodaCollection collection)
Callback function parameter | Description |
---|---|
Error error | If createCollection() succeeds, error is NULL. If an error occurs, then error contains the error message. |
SodaCollection collection | The SodaCollection containing zero or more SODA documents, depending whether it is a new or existing collection. |
sodaDatabase.createDocument()
sodaDatabase.createDocument(String content [, Object options])
sodaDatabase.createDocument(Buffer content [, Object options])
sodaDatabase.createDocument(Object content [, Object options])
A synchronous method that constructs a proto
SodaDocument object usable for SODA insert and
replace methods. SodaDocument attributes like createdOn
will not be
defined, and neither will attributes valid in options
but not
specified. The document will not be stored in the database until an
insert or replace method is called.
You only need to call createDocument()
if your collection requires
client-assigned keys or has non-JSON content, otherwise you can pass
your JSON content directly to the SODA insert and replace methods.
This method was added in node-oracledb 3.0.
myDoc = soda.createDocument({name: "Chris", city: "Melbourne"}, {key: "123"}); // assuming client-assigned keys
newDoc = await collection.insertOneAndGet(myDoc);
console.log("The key of the new document is: ", newDoc.key); // 123
createDocument(): content
String content
Buffer content
Object content
The document content.
When a Buffer is used, and if the collection mediaType
is (or will
be) ‘application/json’ (which is the default media type), then the
JSON must be encoded in UTF-8, UTF-16LE or UTF-16BE otherwise you will
get a SODA error on a subsequent write operation.
createDocument(): options
Object options
The following properties can be set.
key
String key
Must be supplied if the document in intended to be inserted into a collection with client-assigned keys. It should be undefined, otherwise.
mediaType
String mediaType
If the document has non-JSON content, then mediaType
should be set
to the desired media type. Using a MIME type is recommended.
The default is ‘application/json’.
sodaDatabase.getCollectionNames()
Callback:
getCollectionNames([Object options,] function(Error error, Array collectionNames){});
Promise:
promise = getCollectionNames([Object options]);
Gets an array of collection names in alphabetical order.
If oracledb.autoCommit
is true, and
getCollectionNames()
succeeds, then any open transaction on the
connection is committed.
This method was added in node-oracledb 3.0.
getCollectionNames()
: Parametersoptions
Object options
If options
is undefined, then all collection names will be returned. Otherwise, it can have the following attributes:
Attribute | Description |
---|---|
Number limit | Limits the number of names returned. If limit is 0 or undefined, then all collection names are returned. |
String startsWith | Returns names that start with the given string, and all subsequent names, in alphabetic order. For example, if collections with names “cat”, “dog”, and “zebra” exist, then using startsWith of “d” will return “dog” and “zebra”. If startsWith is an empty string or undefined, all collection names are returned, subject to the value of limit . |
getCollectionNames()
: Callback Functionfunction(Error error, Array collectionNames)
Callback function parameter | Description |
---|---|
Error error | If getCollectionNames() succeeds, error is NULL. If an error occurs, then error contains the error message. |
Array collectionNames | An array of Strings, each containing the name of a SODA collection in this SODA database. The array is in alphabetical order. |
sodaDatabase.openCollection()
Callback:
openCollection(String collectionName, function(Error error, SodaCollection collection){});
Promise:
promise = openCollection(String collectionName);
Opens an existing SodaCollection of the given name. The collection can then be used to access documents.
If the requested collection does not exist, it is not an error. Instead, the returned collection value will be undefined.
If oracledb.autoCommit
is true, and
openCollection()
succeeds, then any open transaction on the
connection is committed.
This method was added in node-oracledb 3.0.
openCollection()
: ParameterscollectionName
String collectionName
Name of the collection to open.
openCollection()
: Callback Functionfunction(Error error, SodaCollection collection)
Callback function parameter | Description |
---|---|
Error error | If openCollection() succeeds, error is NULL. It is not an error if the requested collection does not exist. If an error occurs, then error contains the error message. |
SodaCollection collection | The requested collection, if one is found. Otherwise it will be undefined. |
SodaDocuments represents the document for SODA read and write operations.
SODA can be used with Oracle Database 18.3 and above, when node-oracledb uses
Oracle Client 18.5 or Oracle Client 19.3, or later. The SODA bulk insert
methods sodaCollection.insertMany()
and
sodaCollection.insertManyAndGet()
are in Preview
status.
SodaDocument objects can be created in three ways:
The result of sodaDatabase.createDocument()
. This
is a proto SodaDocument object usable for SODA insert and replace methods.
The SodaDocument will have content and media type components set. Attributes
like createdOn
will not be defined. Optional attributes not specified when
calling createDocument()
will also not be defined.
The result of a read operation from the database, such as calling
sodaOperation.getOne()
, or from
sodaDocumentCursor.getNext()
after a
sodaOperation.getCursor()
call. These
return complete SodaDocument objects containing the document content and
attributes, such as time stamps.
The result of sodaCollection.insertOneAndGet()
,
sodaOperation.replaceOneAndGet()
, or
sodaCollection.insertManyAndGet()
methods.
These return SodaDocuments that contain all attributes except the document
content itself. They are useful for finding document attributes such as
system generated keys, and versions of new and updated documents.
The available document properties are shown below. Document content
of queried SodaDocument objects is only accessible via one of the
accessor methods getContent()
,
getContentAsBuffer()
or
getContentAsString()
.
Other properties of a SodaDocument object can be accessed directly. They are read-only. The properties for default collections are:
Property | Description |
---|---|
readonly String createdOn | The creation time of the document as a string in the UTC time zone using an ISO8601 format such as ‘2018-07-11T01:37:50.123456Z’ or ‘2018-07-11T01:37:50.123Z’. By default, SODA sets this automatically. |
readonly String key | A unique key value for this document. By default, SODA automatically generates the key. |
readonly String lastModified | Last modified time of the document as a string in the UTC time zone using an ISO8601 format such as ‘2018-07-11T01:37:50.123456Z’ or ‘2018-07-11T01:37:50.123Z’. By default, SODA sets this automatically. |
readonly String mediaType | An arbitrary string value designating the content media type. The recommendation when creating documents is to use a MIME type for the media type. By default, collections store only JSON document content and this property will be ‘application/json’. This property will be null if the media type is unknown, which will only be in the rare case when a collection was created to store mixed or non-JSON content on top of a pre-existing database table, and that table has NULLs in its mediaType column. |
readonly String version | Version of the document. By default, SODA automatically updates the version each time the document is changed. |
These properties were added in node-oracledb 3.0.
These methods return the document content stored in a SodaDocument.
Which one to call depends on the content and how you want to use it.
For example, if the document content is JSON, then any of the methods
may be called. But if the document content is binary, then only
getContentAsBuffer()
may be called.
Although documents cannot be null, content can be.
sodaDocument.getContent()
getContent()
A synchronous method that returns the document content as an object. An exception will occur if the document content is not JSON and cannot be converted to an object.
This method was added in node-oracledb 3.0.
sodaDocument.getContentAsBuffer()
getContentAsBuffer()
A synchronous method that returns the document content as a Buffer.
If the documents were originally created with
sodaDatabase.createDocument()
, then
documents are returned as they were created.
For documents fetched from the database where the collection storage
is BLOB (which is the default), and whose mediaType
is
‘application/json’, then the buffer returned is identical to that
which was stored. If the storage is not BLOB, it is UTF-8 encoded.
This method was added in node-oracledb 3.0.
sodaDocument.getContentAsString()
getContentAsString()
A synchronous method that returns JSON document content as a String.
An exception will occur if the document content cannot be converted to a string.
If the document encoding is not known, UTF8 will be used.
This method was added in node-oracledb 3.0.
A SodaDocumentCursor is used to walk through a set of SODA documents
returned from a find()
getCursor()
method.
sodaDocumentCursor.close()
Callback
close(function(Error error){});
Promise
promise = close();
This method closes a SodaDocumentCursor. It must be called when the cursor is no longer required. It releases resources in node-oracledb and Oracle Database.
This method was added in node-oracledb 3.0.
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. |
sodaDocumentCursor.getNext()
Callback:
getNext(function(Error error, SodaDocument document){});
Promise:
promise = getNext();
This method returns the next SodaDocument in the
cursor returned by a find()
terminal method read
operation.
If there are no more documents, the returned document
parameter will
be undefined.
This method was added in node-oracledb 3.0.
function(Error error, SodaDocument document)
The parameters of the callback function are:
Callback function parameter | Description |
---|---|
Error error | If getNext() succeeds, error is NULL. If an error occurs, then error contains the error message. |
SodaDocument document | The next document in the cursor. If there are no more documents, then document will be undefined. |
The node-oracledb add-on consists of JavaScript code that calls a binary module.
This binary loads Oracle Client libraries which communicate over Oracle Net to
an existing database. Node-oracledb can be installed with npm
but the Oracle
Client libraries need to be installed separately. See the node-oracledb
installation instructions. Oracle Net is not a separate product: it is how
the Oracle Client and Oracle Database communicate.
Node-oracledb dynamically loads the Oracle Client libraries using a search heuristic. If appropriate libraries cannot be found, node-oracledb will return an error like “Error: DPI-1047: Cannot locate a 64-bit Oracle Client library”.
Only the first set of libraries found are loaded. The libraries can be in an installation of Oracle Instant Client, in a full Oracle Client installation, or in 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. For certified configurations see Oracle Support’s Doc ID 207303.1 and see the node-installation instructions.
Node-oracledb looks for the Oracle Client libraries as follows:
On Windows:
In the libDir
directory specified in a
call to oracledb.initOracleClient()
. This
directory should contain the libraries from an unzipped Instant Client
‘Basic’ or ‘Basic Light’ package. If you pass the library directory from
a full client or database installation, such as Oracle Database “XE”
Express Edition, then you will need to have previously set your
environment to use that software installation otherwise files such as
message files will not be located. If the Oracle Client libraries cannot
be loaded from libDir
, then an error is thrown.
If libDir
was not specified, then Oracle Client libraries are looked for
in the directory where the oracledb*.node
binary is. For example in
node_modules\oracledb\build\Release
. This directory should contain the
libraries from an unzipped Instant Client ‘Basic’ or ‘Basic Light’
package. If the libraries are not found, no error is thrown and the
search continues, see next bullet point.
In the directories on the system library search path, e.g. the PATH
environment variable. If the Oracle Client libraries cannot be loaded,
then an error is thrown.
On macOS:
In the libDir
directory specified in a
call to oracledb.initOracleClient()
. This
directory should contain the libraries from an unzipped Instant Client
‘Basic’ or ‘Basic Light’ package. If the Oracle Client libraries cannot
be loaded from libDir
, then an error is thrown.
If libDir
was not specified, then Oracle Client libraries are looked for
in the directory where the oracledb*.node
binary is. For example in
node_modules/oracledb/build/Release
. This directory should contain the
libraries from an unzipped Instant Client ‘Basic’ or ‘Basic Light’
package. For example, use ln -s ~/Downloads/instantclient_19_8/libclntsh.dylib
node_modules/oracledb/build/Release/
. If the libraries are not found, no
error is thrown and the search continues, see next bullet point.
In the library search path such as set in DYLD_LIBRARY_PATH
(note this
variable does not propagate to sub-shells) or in /usr/local/lib
. If the
Oracle Client libraries cannot be loaded, then an error is thrown.
On Linux and related platforms:
In the libDir
directory specified in a
call to oracledb.initOracleClient()
. Note on
Linux this is only useful to force immediate loading of the libraries
because the libraries must also be in the system library search path,
i.e. configured with ldconfig
or set in LD_LIBRARY_PATH
. This
directory should contain the libraries from an unzipped Instant Client
‘Basic’ or ‘Basic Light’ package. If you pass the library directory from
a full client or database installation, such as Oracle Database “XE”
Express Edition then you will need to have previously set the
ORACLE_HOME
environment variable. If the Oracle Client libraries cannot
be loaded from libDir
, then an error is thrown.
If libDir
was not specified, then Oracle Client libraries are looked for
in the operating system library search path, such as configured with
ldconfig
or set in the environment variable LD_LIBRARY_PATH
. On some
UNIX platforms an OS specific equivalent, such as LIBPATH
or
SHLIB_PATH
is used instead of LD_LIBRARY_PATH
. If the libraries are
not found, no error is thrown and the search continues, see next bullet
point.
In $ORACLE_HOME/lib
. Note the environment variable ORACLE_HOME
should
only ever be set when you have a full database installation or full client
installation. It should not be set if you are using Oracle Instant
Client. The ORACLE_HOME
variable, and other necessary variables, should
be set before starting Node.js. See Oracle Environment
Variables. If the Oracle Client libraries cannot
be loaded, then an error is thrown.
If you call initOracleClient()
with a libDir
attribute, the Oracle Client
libraries are loaded immediately from that directory. If you call
initOracleClient()
but do not set the libDir
attribute, the Oracle Client
libraries are loaded immediately using the search heuristic above. If you do
not call initOracleClient()
, then the libraries are loaded using the search
heuristic when the first node-oracledb function that depends on the libraries is
called, for example when a connection pool is created. If there is a problem
loading the libraries, then an error is thrown.
Make sure the Node.js process has directory and file access permissions for 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
or from the directory where the
oracledb*.node
binary is. Note other libraries used by libclntsh*
are also
required.
To trace the loading of Oracle Client libraries, the environment variable
DPI_DEBUG_LEVEL
can be set to 64 before starting Node.js. For example, on
Linux, you might use:
$ export DPI_DEBUG_LEVEL=64
$ node myapp.js 2> log.txt
The oracledb.initOracleClient()
method and searching of the directory where
the oracledb*.node
binary is located were added in node-oracledb 5.0.
initOracleClient()
to set the Oracle Client directoryApplications can call the synchronous function
oracledb.initOracleClient()
to specify the directory
containing Oracle Instant Client libraries. The Oracle Client Libraries are
loaded when initOracleClient()
is called. For example, if the Oracle Instant
Client Libraries are in C:\oracle\instantclient_19_6
on Windows, then you can
use:
const oracledb = require('oracledb');
try {
oracledb.initOracleClient({libDir: 'C:\\oracle\\instantclient_19_6'});
} catch (err) {
console.error('Whoops!');
console.error(err);
process.exit(1);
}
If you use backslashes in the libDir
string, you will need to double them.
The initOracleClient()
function should only be called once.
If you set libDir
on Linux and related platforms, you must still have
configured the system library search path to include that directory before
starting Node.js.
On any operating system, if you set libDir
to the library directory of a full
database or full client installation, you will need to have previously set the
Oracle environment, for example by setting the ORACLE_HOME
environment
variable. Otherwise you will get errors like ORA-1804. You should set this,
and other Oracle environment variables, before starting Node.js, as shown in
Oracle Environment Variables.
Optional Oracle Net configuration files are read when node-oracledb is loaded. These files affect connections and applications. The common files are:
Name | Description |
---|---|
tnsnames.ora |
Contains net service names and Oracle Net options for databases that can be connected to, see Net Service Names for Connection Strings. This file is only needed for advanced configuration. Not needed if connection strings use the Easy Connect syntax. The Oracle Net documentation on tnsnames.ora has more information. |
sqlnet.ora |
A configuration file controlling the network transport behavior. For example it can set call timeouts for high availability, or be used to encrypt network traffic, or be used to configure logging and tracing. The Oracle Net documentation on sqlnet.ora has more information. |
The files should be in a directory accessible to Node.js, not on the database server host.
To make node-oracledb use the files you can set
configDir
in a call to
oracledb.initOracleClient()
. For example, if the file
/etc/my-oracle-config/tnsnames.ora
should be used, then your code could be:
const oracledb = require('oracledb');
oracledb.initOracleClient({configDir: '/etc/my-oracle-config'});
(If you use backslashes in the configDir
string, you will need to double them.)
This is equivalent to setting the environment variable TNS_ADMIN
to
/etc/my-oracle-config
.
If initOracleClient()
is not called, or it is called but
configDir
is not set, then default
directories are searched for the configuration files. They include:
$TNS_ADMIN
/opt/oracle/instantclient_19_6/network/admin
if Instant Client is in /opt/oracle/instantclient_19_6
./usr/lib/oracle/19.6/client64/lib/network/admin
if Oracle 19.6 Instant Client RPMs are used on Linux.$ORACLE_HOME/network/admin
if node-oracledb is using libraries from the database installation.A wallet configuration file cwallet.sso
for secure connection can be located
with, or separately from, the tnsnames.ora
and sqlnet.ora
files. It should
be securely stored. The sqlnet.ora
file’s WALLET_LOCATION
path should be
set to the directory containing cwallet.sso
. For Oracle Autonomous Database
use of wallets, see Connecting to Oracle Autonomous Database.
Note the Easy Connect Plus syntax can set many common
configuration options without needing tnsnames.ora
or sqlnet.ora
files.
The section Connections and High Availability has some discussion about Oracle Net configuration.
If the Oracle Client Libraries used by node-oracledb are version 12, or later,
then an optional oraaccess.xml
file can be used to configure some
behaviors of those libraries, such as statement caching and prefetching. This
can be useful if the application cannot be altered. The file is read when
node-oracledb starts. The file is read from the same directory as the Optional
Oracle Net Configuration files.
The following oraaccess.xml
file sets the Oracle client
‘prefetch’ value to 1000 rows. This value affects every SQL
query in the application:
<?xml version="1.0"?>
<oraaccess xmlns="http://xmlns.oracle.com/oci/oraaccess"
xmlns:oci="http://xmlns.oracle.com/oci/oraaccess"
schemaLocation="http://xmlns.oracle.com/oci/oraaccess
http://xmlns.oracle.com/oci/oraaccess.xsd">
<default_parameters>
<prefetch>
<rows>1000</rows>
</prefetch>
</default_parameters>
</oraaccess>
Prefetching is a tuning feature, see Tuning Fetch Performance.
The oraaccess.xml
file has other uses including:
Refer to the oraaccess.xml
documentation for more information.
Some common environment variables that influence node-oracledb are shown below.
The variables that may be needed depend on how Node.js is installed, how you
connect to the database, and what optional settings are desired. It is
recommended to set Oracle variables in the environment before invoking Node.js,
however they may also be set in application code as long as they are set before
node-oracledb is first used. System environment variables like
LD_LIBRARY_PATH
must be set before Node.js starts.
Name | Description |
---|---|
LD_LIBRARY_PATH |
Used on Linux and some UNIX platforms. Set this to the directory containing the Oracle Client libraries, for example /opt/oracle/instantclient_19_6 or $ORACLE_HOME/lib . The variable needs to be set in the environment before Node.js is invoked. The variable is not needed if the libraries are located by an alternative method, such as from running ldconfig . On some UNIX platforms an OS specific equivalent, such as LIBPATH or SHLIB_PATH is used instead of LD_LIBRARY_PATH . |
PATH |
The library search path for Windows should include the location where OCI.DLL is found. Not needed if you pass libDir when calling oracledb.initOracleClient() |
TNS_ADMIN |
The location of the optional Oracle Net configuration files and Oracle Client configuration files, including tnsnames.ora , sqlnet.ora , and oraaccess.xml , if they are not in a default location. The configDir value in a call to oracledb.initOracleClient() overrides TNS_ADMIN . |
ORA_SDTZ |
The default session time zone, see Fetching Dates and Timestamps. |
ORA_TZFILE |
The name of the Oracle time zone file to use. See the notes below. |
ORACLE_HOME |
The directory containing the Oracle Database software. This directory must be accessible by the Node.js process. This variable should not be set if node-oracledb uses Oracle Instant Client. |
NLS_LANG |
Determines the ‘national language support’ globalization options for node-oracledb. If not set, a default value will be chosen by Oracle. Note that node-oracledb will always uses the AL32UTF8 character set. See Globalization and National Language Support (NLS). |
NLS_DATE_FORMAT , NLS_TIMESTAMP_FORMAT |
See Fetching Numbers and Dates as String. The variables are ignored if NLS_LANG is not set. |
NLS_NUMERIC_CHARACTERS |
See Fetching Numbers and Dates as String. The variable is ignored if NLS_LANG is not |
The name of the Oracle time zone file to use can be set in ORA_TZFILE
.
If node-oracledb is using Oracle Client libraries from an Oracle Database or
full Oracle Client software installation, and you want to use a non-default time
zone file, then set ORA_TZFILE
to the file name with a directory prefix, for
example: export ORA_TZFILE=/opt/oracle/myconfig/timezone_31.dat
.
Oracle Instant Client includes a small and big time zone file, for example
timezone_32.dat
and timezlrg_32.dat
. The versions can be shown by running
the utility genezi -v
located in the Instant Client directory. The small file
contains only the most commonly used time zones. By default the larger
timezlrg_n.dat
file is used. If you want to use the smaller timezone_n.dat
file, then set the ORA_TZFILE
environment variable to the name of the file
without any directory prefix, for example export ORA_TZFILE=timezone_32.dat
.
With Oracle Instant Client 12.2 or later, you can also use an external time zone
file. Create a subdirectory oracore/zoneinfo
under the Instant Client
directory, and move the file into it. Then set ORA_TZFILE
to the file name,
without any directory prefix. The genezi -v
utility will show the time zone
file in use.
The Oracle Database documentation contains more information about time zone files, see Choosing a Time Zone File.
If you are using Linux, and node-oracledb is being run on the same
computer as the database, you can set required Oracle environment
variables, such as ORACLE_HOME
and LD_LIBRARY_PATH
in your shell
by executing:
source /usr/local/bin/oraenv
Or, if you are using Oracle Database XE 11.2, by executing:
source /u01/app/oracle/product/11.2.0/xe/bin/oracle_env.sh
Make sure the Node.js process has directory and file access permissions for the Oracle libraries and other files. Typically the home directory of the Oracle software owner will need permissions relaxed.
The oracledb.initOracleClient()
function allows
driverName
and
errorUrl
attributes to be set. These are
useful for applications whose end-users are not aware node-oracledb is being
used. An example of setting the attributes is:
const oracledb = require('oracledb');
oracledb.initOracleClient({
driverName: 'My Great App : 3.1.4'
errorUrl: 'https://example.com/MyInstallInstructions.html',
});
The driverName
value will be shown in Oracle Database views like
V$SESSION_CONNECT_INFO
. The convention for driverName
is to separate the
product name from the product version by a colon and single space characters.
If this attribute is not specified, then the value “node-oracledb : version”
is used, see Add-on Name.
The errorUrl
string will be shown in the exception raised 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 set, then the node-oracledb installation instructions URL
is used.
Connections between node-oracledb and Oracle Database are used for executing SQL, PL/SQL, and for SODA.
There are two types of connection:
Standalone connections: These are useful when the application maintains a single user session to a database.
Pooled connections: Connection pooling is important for performance when applications frequently connect and disconnect from the database. Oracle high availability features in the pool implementation mean that small pools can also be useful for applications that want a few connections available for infrequent use.
Many connection behaviors can be controlled by node-oracledb options. Other settings can be configured in Oracle Net files or in connection strings. These include limiting the amount of time that opening a connection can take, or enabling network encryption.
In applications which use connections infrequently, create a
connection with oracledb.getConnection()
.
Connections should be released with
connection.close()
when no longer needed:
const oracledb = require('oracledb');
const mypw = ... // set mypw to the hr schema password
async function run() {
try {
connection = await oracledb.getConnection({
user : "hr",
password : mypw,
connectString : "localhost/XEPDB1"
});
result = await connection.execute(`SELECT last_name FROM employees`);
console.log("Result is:", result);
} catch (err) {
console.error(err.message);
} finally {
if (connection) {
try {
await connection.close(); // Always close connections
} catch (err) {
console.error(err.message);
}
}
}
}
run();
Applications which frequently create and close connections should use a Connection Pool. Since pools provide Oracle high availability features, using one is also recommended if you have a long running application, particularly if connections are released to the pool while no database work is being done.
const oracledb = require('oracledb');
const mypw = ... // set mypw to the hr schema password
async function run() {
let pool;
try {
pool = await oracledb.createPool({
user : "hr",
password : mypw // mypw contains the hr schema password
connectString : "localhost/XEPDB1"
});
let connection;
try {
connection = await pool.getConnection();
result = await connection.execute(`SELECT last_name FROM employees`);
console.log("Result is:", result);
} catch (err) {
throw (err);
} finally {
if (connection) {
try {
await connection.close(); // Put the connection back in the pool
} catch (err) {
throw (err);
}
}
}
} catch (err) {
console.error(err.message);
} finally {
await pool.close();
}
}
run();
See Connection Pooling for more information.
The connectString
property for oracledb.getConnection()
and oracledb.createPool()
can be one of:
tnsnames.ora
file or external naming serviceIf a connect string is not specified, the empty string “” is used which indicates to connect to the local, default database.
The connectionString
property is an alias for connectString
.
Use only one of the properties.
An Easy Connect string is often the simplest to use. For example, to connect to
the Oracle Database service orclpdb1
that is running on the host
mydbmachine.example.com
with the default Oracle Database port 1521, use:
const oracledb = require('oracledb');
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "mydbmachine.example.com/orclpdb1"
}
);
If the database is using a non-default port, for example 1984, the port must be given:
const oracledb = require('oracledb');
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "mydbmachine.example.com:1984/orclpdb1"
}
);
The Easy Connect syntax supports Oracle Database service names. It cannot be used with the older System Identifiers (SID).
The Easy Connect syntax has been extended in recent versions of Oracle Database client since its introduction in Oracle 10g. Check the Easy Connect Naming method in Oracle Net Service Administrator’s Guide for the syntax in your version of the Oracle Client libraries.
If you are using Oracle Client 19c, the latest Easy Connect Plus syntax
allows the use of multiple hosts or ports, along with optional entries for the
wallet location, the distinguished name of the database server, and even lets
some network configuration options be set. The technical paper Oracle Database 19c
Easy Connect Plus Configurable Database Connection Syntax discusses the
syntax. The Easy Connect Plus syntax means that tnsnames.ora
or
sqlnet.ora
files are not needed for some further common
connection scenarios.
For example, if a firewall terminates idle connections every five minutes, you
may decide it is more efficient to keep connections alive instead of having the
overhead of recreation. Your connection string could be
"mydbmachine.example.com/orclpdb1?expire_time=2"
to send packets every two
minutes with the EXPIRE_TIME
feature. The general recommendation for
EXPIRE_TIME
is to use a value that is slightly less than half of the
termination period.
Another common use case for Easy Connect Plus is to limit the amount of time
required to open a connection. For example, to return an error after 15 seconds
if a connection cannot be established to the database, use
"mydbmachine.example.com/orclpdb1?connect_timeout=15"
.
Full Connect Descriptor strings can be embedded in applications:
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=mymachine.example.com)(PORT=1521))(CONNECT_DATA=(SERVER=DEDICATED)(SERVICE_NAME=orcl)))"
}
);
Connect Descriptor strings are commonly stored in optional tnsnames.ora
configuration files
and associated with a Net Service Name, for
example:
sales =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = mymachine.example.com)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = orcl)
)
)
Net Service Names may also be defined in a directory server.
Given a Net Service Name, node-oracledb can connect like:
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "sales"
}
);
Some older databases may use a ‘SID’ instead of a ‘Service Name’. A connection string for these databases could look like:
sales =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = mymachine.example.com)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SID = orcl)
)
)
See Optional Oracle Net Configuration for where tnsnames.ora
files can be located.
For general information on tnsnames.ora
files, see the Oracle Net
documentation on tnsnames.ora
.
The node-oracledb connection string syntax is different to Java JDBC and the common Oracle SQL Developer syntax. If these JDBC connection strings reference a service name like:
jdbc:oracle:thin:@hostname:port/service_name
for example:
jdbc:oracle:thin:@mydbmachine.example.com:1521/orclpdb1
then use Oracle’s Easy Connect syntax in node-oracledb:
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "mydbmachine.example.com:1521/orclpdb1"
}
);
Alternatively, if a JDBC connection string uses an old-style Oracle system identifier SID, and there is no service name available:
jdbc:oracle:thin:@hostname:port:sid
for example:
jdbc:oracle:thin:@mydbmachine.example.com:1521:orcl
then either embed the Connect Descriptor:
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=mymachine.example.com)(PORT=1521))(CONNECT_DATA=(SERVER=DEDICATED)(SID=ORCL)))"
}
);
or create a Net Service Name:
# tnsnames.ora
finance =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = mydbmachine.example.com)(PORT = 1521))
(CONNECT_DATA =
(SID = ORCL)
)
)
This can be referenced in node-oracledb:
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "finance"
}
);
If you open more than four connections, such as via increasing
poolMax
, you should increase the number of worker threads
available to node-oracledb. A thread pool that is too small can cause
connection requests to fail with the error NJS-040: connection request
timeout or NJS-076: connection request rejected.
The thread pool size should be equal to, or greater than, the maximum number of connections. If the application does database and non-database work concurrently, then additional threads could also be required for optimal throughput.
Increase the thread pool size by setting the environment variable
UV_THREADPOOL_SIZE before starting Node.js. For example, on Linux your
package.json
may have a script like:
"scripts": {
"start": "export UV_THREADPOOL_SIZE=10 && node index.js"
},
. . .
Or, on Windows:
"scripts": {
"start": "SET UV_THREADPOOL_SIZE=10 && node index.js"
},
. . .
With these, you can start your application with npm start
.
On non-Windows platforms, the value can also be set inside the application. It must be set prior to any asynchronous Node.js call that uses the thread pool:
// !! First file executed. Non-Windows only !!
process.env.UV_THREADPOOL_SIZE = 10
// ... rest of code
If you set UV_THREADPOOL_SIZE
too late, the setting will be ignored and the
default thread pool size of 4 will still be used. Note that
pool._logStats()
can only show the value of the variable,
not the actual size of the thread pool.
The ‘libuv’ library used by Node.js 12.5 and earlier limits the number of
threads to 128. In Node.js 12.6 onward the limit is 1024. You should restrict
the maximum number of connections opened in an application,
i.e. poolMax
, to a value lower than
UV_THREADPOOL_SIZE
. If you have multiple pools, make sure the sum of all
poolMax
values is no larger than UV_THREADPOOL_SIZE
.
Node.js worker threads executing database statements on a connection will wait until round-trips between node-oracledb and the database are complete. When an application handles a sustained number of user requests, and database operations take some time to execute or the network is slow, then all available threads may be held in use. This prevents other connections from beginning work and stops Node.js from handling more user load. Increasing the number of worker threads may improve throughput and prevent deadlocks.
Each connection can only execute one statement at a time. Code will not run faster when parallel calls are used with a single connection since statements will still be executed sequentially and only one call will be able to use the connection at a time. You may end up blocking many threads.
Structure your code to avoid parallel operations on a single connection. Do not
use Promise.all()
on a single connection. Instead consider, for example,
using a basic for
loop and async/await
to iterate through each action:
async function myfunc() {
const stmts = [
`INSERT INTO ADRESSES (ADDRESS_ID, CITY) VALUES (94065, 'Redwood Shores')`,
`INSERT INTO EMPLOYEES (ADDRESS_ID, EMPLOYEE_NAME) VALUES (94065, 'Jones')`
];
for (const s of stmts) {
await connection.execute(s);
}
}
If you use ESlint for code validation, and it warns about await in loops
for code that is using a single connection, then disable the no-await-in-loop
rule for these cases.
Instead of using async.parallel()
or async.each()
which call each of
their items in parallel, use async.series()
or async.eachSeries()
.
If you want to repeat a number of INSERT or UPDATE statements, then consider
using connection.executeMany()
.
Using functions like promise.all()
to fetch rows from nested cursor result
sets can result in inconsistent data.
When you use parallel calls on a single connection, queuing of each call is done
in the C layer via a mutex. However libuv
is not aware that a connection can
only do one thing at a time - it only knows when it has background threads
available and so it sends off the work to be done. If your application runs
operations in parallel on a connection, you could use more than one background
thread (perhaps all of them) and each could be waiting on the one before it to
finish its “execute”. Of course other users or transactions cannot use the
threads at that time either. When you use methods like async.series
or
async.eachSeries()
, the queuing is instead done in the main JavaScript thread.
When applications use a lot of connections for short periods, Oracle recommends using a connection pool for efficiency. Each connection in a pool should be used for a given unit of work, such as a transaction or a set of sequentially executed statements. Statements should be executed sequentially, not in parallel on each connection.
Each node-oracledb process can use one or more connection pools. Each pool can contain zero or more connections. In addition to providing an immediately available set of connections, pools provide dead connection detection and transparently handle Oracle Database High Availability events. This helps shield applications during planned maintenance and from unplanned failures. Internally Oracle Call Interface Session Pooling is used, which provides many of these features.
Since pools provide Oracle high availability features, using one is also recommended if you have a long running application, particularly if connections are released to the pool while no database work is being done.
Pools are created by calling oracledb.createPool()
.
Generally applications will create a pool once as part of
initialization. After an application finishes using a connection
pool, it should release all connections and terminate the connection
pool by calling the pool.close()
method.
Connections from the pool are obtained with
pool.getConnection()
. If all connections in a pool are
being used, then subsequent getConnection()
calls will be put in a
queue until a connection is available. Connections must be
released with connection.close()
when no longer needed so
they can be reused. Make sure to release connections in all codes paths,
include error handlers.
When a connection is released back to its pool, any ongoing transaction will be rolled back however it will retain session state, such as NLS settings from ALTER SESSION statements. See Connection Tagging and Session State for more information.
Connections can also be dropped completely from the pool.
A connection pool should be started during application initialization, for example before the web server is started:
const oracledb = require('oracledb');
const mypw = ... // set mypw to the hr schema password
// Start the pool and webserver
async function init() {
try {
await oracledb.createPool({
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "localhost/XEPDB1",
poolIncrement : 0,
poolMax : 4,
poolMin : 4
});
const server = http.createServer();
server.on('error', (err) => {
console.log('HTTP server problem: ' + err);
});
server.on('request', (request, response) => {
handleRequest(request, response);
});
await server.listen(3000);
console.log("Server is running");
} catch (err) {
console.error("init() error: " + err.message);
}
}
Each web request will invoke handleRequest()
. In it, a connection can be
obtained from the pool and used:
async function handleRequest(request, response) {
response.writeHead(200, {"Content-Type": "text/html"});
response.write("<!DOCTYPE html><html><head><title>My App</title></head><body>");
let connection;
try {
connection = await oracledb.getConnection();
const result = await connection.execute(`SELECT * FROM locations`);
displayResults(response, result); // do something with the results
} catch (err) {
response.write("<p>Error: " + text + "</p>");
} finally {
if (connection) {
try {
await connection.close(); // always release the connection back to the pool
} catch (err) {
console.error(err);
}
}
}
response.write("</body></html>");
response.end();
}
See webapp.js for a runnable example.
The characteristics of a connection pool are determined by its attributes
poolMin
, poolMax
,
poolIncrement
, and
poolTimeout
. Pool expansion happens when the
following are all true: (i) pool.getConnection()
is
called and (ii) all the currently established connections in the pool are
“checked out” by previous pool.getConnection()
calls and are in-use by the
application, and (iii) the number of those connections is less than the pool’s
poolMax
setting. Note that when external authentication or
heterogeneous pools are used, the pool growth behavior is
different.
Importantly, if you increase the size of the pool, you must increase the number of threads used by Node.js before Node.js starts its threadpool.
The Oracle Real-World Performance Group’s recommendation is to use fixed size
connection pools. The values of poolMin
and poolMax
should be the same (and
poolIncrement
equal to zero). This avoids connection storms which can
decrease throughput. See Guideline for Preventing Connection Storms: Use
Static Pools, which contains more details about sizing of pools. Having a
fixed size will guarantee that the database can handle the upper pool size. For
example, if a pool needs to grow but the database resources are limited, then
pool.getConnection()
may return errors such as ORA-28547. With a fixed pool
size, this class of error will occur when the pool is created, allowing you to
change the size before users access the application. With a dynamically growing
pool, the error may occur much later after the pool has been in use for some
time.
The Real-World Performance Group also recommends keeping pool sizes small, as
this may perform better than larger pools. Use
pool._logStats()
to monitor pool usage. The pool
attributes should be adjusted to handle the desired workload within the bounds
of available resources in Node.js and the database.
Make sure any firewall, resource manager or user profile
IDLE_TIME
does not expire idle connections, since this will require
connections be recreated, which will impact performance and scalability. See
Preventing Premature Connection Closing.
Closing a connection pool allows database resources to be freed. If
Node.js is killed without pool.close()
being called,
it may be some time before the unused database-side of connections are
automatically cleaned up in the database.
When pool.close()
is called, the pool will be closed only if all
connections have been released to the pool with connection.close()
.
Otherwise an error is returned and the pool will not be closed.
An optional drainTime
parameter can be used to force the pool closed
even if connections are in use. This lets the pool be ‘drained’ of
connections. The drainTime
indicates how many seconds the pool is
allowed to remain active before it and its connections are terminated.
For example, to give active connections 10 seconds to complete their
work before being terminated:
await pool.close(10);
When a pool has been closed with a specified drainTime
, then any new
pool.getConnection()
calls will fail. If connections are currently
in use by the application, they can continue to be used for the
specified number of seconds, after which the pool and all open
connections are forcibly closed. Prior to this time limit, if there
are no connections currently “checked out” from the pool with
getConnection()
, then the pool and its connections are immediately
closed.
In network configurations that drop (or in-line) out-of-band breaks,
forced pool termination may hang unless you have
DISABLE_OOB=ON
in a sqlnet.ora
file, see Optional Oracle
Net Configuration.
Non-zero drainTime
values are recommended so applications
have the opportunity to gracefully finish database operations, however
pools can be forcibly closed by specifying a zero drain time:
await pool.close(0);
Closing the pool would commonly be one of the last stages of a Node.js application. A typical closing routine look likes:
// Close the default connection pool with 10 seconds draining, and exit
async function closePoolAndExit() {
console.log("\nTerminating");
try {
await oracledb.getPool().close(10);
process.exit(0);
} catch(err) {
console.error(err.message);
process.exit(1);
}
}
It is helpful to invoke closePoolAndExit()
if Node.js is
sent a signal or interrupted:
// Close the pool cleanly if Node.js is interrupted
process
.once('SIGTERM', closePoolAndExit)
.once('SIGINT', closePoolAndExit);
When pools are created, they can be given a named alias. The alias can later be used to retrieve the related pool object for use. This facilitates sharing pools across modules and simplifies getting connections.
Pools are added to the cache by using a
poolAlias
property in the
poolAttrs
object:
async function init() {
try {
await oracledb.createPool({ // no need to store the returned pool
user: 'hr',
password: mypw, // mypw contains the hr schema password
connectString: 'localhost/XEPDB1',
poolAlias: 'hrpool'
});
// do stuff
. . .
// get the pool from the cache and use it
const pool = oracledb.getPool('hrpool');
. . .
}
There can be multiple pools in the cache if each pool is created with a unique alias.
If a pool is created without providing a pool alias, and a pool with an alias of ‘default’ is not in the cache already, this pool will be cached using the alias ‘default’. This pool is used by default in methods that utilize the connection pool cache. If subsequent pools are created without explicit aliases, they will be not stored in the pool cache.
Methods that can affect or use the connection pool cache include:
Assuming the connection pool cache is empty, the following will create a new pool and cache it using the pool alias ‘default’:
async function init() {
try {
await oracledb.createPool({
user: 'hr',
password: mypw, // mypw contains the hr schema password
connectString: 'localhost/XEPDB1'
});
. . .
}
If you are using callbacks, note that createPool()
is not synchronous.
Connections can be returned by using the shortcut to oracledb.getConnection() that returns a connection from a pool:
const connection = await oracledb.getConnection();
. . . // Use connection from the previously created 'default' pool
await connection.close();
The default pool can also be retrieved using oracledb.getPool()
without passing the poolAlias
parameter:
const pool = oracledb.getPool();
console.log(pool.poolAlias); // 'default'
const connection = await pool.getConnection();
If the application needs to use more than one pool at a time, unique pool aliases can be used when creating the pools:
await oracledb.createPool({
user: 'hr',
password: myhrpw, // myhrpw contains the hr schema password
connectString: 'localhost/XEPDB1',
poolAlias: 'hrpool'
});
await oracledb.createPool({
user: 'sh',
password: myshpw, // myshpw contains the sh schema password
connectString: 'localhost/XEPDB1',
poolAlias: 'shpool'
});
. . .
To use the methods or attributes of a pool in the cache, a pool can be retrieved from the cache by passing its pool alias to oracledb.getPool():
const pool = oracledb.getPool('hrpool'); // or 'shpool'
const connection = await pool.getConnection();
. . . // Use connection from the pool and then release it
The oracledb.getConnection() shortcut can also be used with a pool alias:
const connection = await oracledb.getConnection('hrpool');
. . . // Use connection from the pool and then release it
From node-oracledb 3.1.0 you can pass the alias as an attribute of the options:
const connection = await oracledb.getConnection({ poolAlias: 'hrpool' });
. . . // Use connection from the pool and then release it
The presence of the poolAlias
attribute indicates the previously
created connection pool should be used instead of creating a
standalone connection. This syntax is useful when you want to pass
other attributes to a pooled getConnection()
call, such as for
proxy connections or with connection
tagging:
const connection = await oracledb.getConnection({ poolAlias: 'hrpool', tag: 'loc=cn;p=1 });
. . . // Use connection from the pool and then release it
To use the default pool in this way you must explicitly pass the alias
default
:
const connection = await oracledb.getConnection({ poolAlias: 'default', tag: 'loc=cn;p=1 });
. . . // Use connection from the pool and then release it
The connection pool queue allows applications to gracefully handle connection
load spikes without having to set poolMax
too large for general operation.
Keeping poolMax
small allows efficient use of resources.
If the application has called getConnection()
enough times so that all
connections in the pool are in use, and further
pool.getConnection()
calls (or
oracledb.getConnection()
calls that use a pool) are made,
then each new request will be queued until an in-use connection is released back
to the pool with connection.close()
. If poolMax
has not
been reached, then connection requests can be satisfied and are not queued.
The amount of time that a queued request will wait for a free connection can be configured with queueTimeout. When connections are timed out of the queue, they will return the error NJS-040: connection request timeout to the application.
If more than oracledb.queueMax
pending connection requests
are in the queue, then pool.getConnection()
calls will immediately return an
error NJS-076: connection request rejected. Pool queue length queueMax reached
and will not be queued. Use this to protect against connection request storms.
It helps applications return errors early when many connections are requested
concurrently. This avoids connection requests blocking (for up to
poolTimeout
) while waiting an available pooled
connection. It lets you see when the pool is too small.
You may also experience NJS-040 or NJS-076 errors if your application is not correctly closing connections, or UV_THREADPOOL_SIZE is too small.
Internally the queue is implemented in node-oracledb’s JavaScript top
level. A queued connection request is dequeued and passed down to
node-oracledb’s underlying C API connection pool when an active
connection is released, and the number of
connections in use drops below the value of
poolMax
.
Connection pool usage should be monitored to choose the appropriate connection pool settings for your workload.
The Pool attributes connectionsInUse
and connectionsOpen
provide basic
information about an active pool.
Further statistics can be enabled by setting the
createPool()
poolAttrs
parameter _enableStats
to
true. Statistics can be output to the console by calling the
pool._logStats()
method. The underscore prefixes indicate that
these are private attributes and methods. This interface may be
altered or enhanced in the future.
To enable recording of queue statistics:
const pool = await oracledb.createPool (
{
_enableStats : true, // default is false
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "localhost/XEPDB1"
});
. . .
The application can later, on some developer-chosen event, display the current statistics to the console by calling:
pool._logStats();
The output contains pool queue statistics, pool settings, and related environment variables.
The statistics displayed by _logStats()
in this release are:
Statistic | Description |
---|---|
total up time | The number of milliseconds this pool has been running. |
total connection requests | Number of getConnection() requests made by the application to this pool. |
total requests enqueued | Number of getConnection() requests that were added to this pool’s queue (waiting for the application to return an in-use connection to the pool) because every connection in this pool was already being used. |
total requests dequeued | Number of getConnection() requests that were dequeued when a connection in this pool became available for use. |
total requests failed | Number of getConnection() requests that invoked the underlying C API callback with an error state. Does not include queue size limit or queue timeout errors. |
total requests exceeding queueMax | Number of getConnection() requests rejected because the number of connections in the queue exceeded queueMax . |
total request timeouts | Number of queued getConnection() requests that were timed out after they had spent queueTimeout or longer in the pool queue. |
max queue length | Maximum number of getConnection() requests that were ever waiting in the queue at one time. |
sum of time in queue | The sum of the time (milliseconds) that dequeued requests spent in the pool queue. |
min time in queue | The minimum time (milliseconds) that any dequeued request spent in the pool queue. |
max time in queue | The maximum time (milliseconds) that any dequeued request spent in the pool queue. |
avg time in queue | The average time (milliseconds) that dequeued requests spent in the pool queue. |
pool connections in use | The number of connections from this pool that getConnection() returned successfully to the application and have not yet been released back to the pool. |
pool connections open | The number of connections in this pool that have been established to the database. |
Note that for efficiency, the minimum, maximum, average, and sum of times in the queue are calculated when requests are removed from the queue. They do not take into account times for connection requests still waiting in the queue.
The sum of ‘total requests failed’, ‘total requests exceeding queueMax’, and
‘total request timeouts’ is the number of pool.getConnection()
calls that
failed.
The _logStats()
method also shows attribute values of the pool:
Attribute |
---|
poolAlias |
queueMax |
queueTimeout |
poolMin |
poolMax |
poolIncrement |
poolTimeout |
poolPingInterval |
sessionCallback |
stmtCacheSize |
The _logStats()
method also shows the pool status:
Attribute |
---|
status |
One related environment variable is is shown by _logStats()
:
Environment Variable | Description |
---|---|
process.env.UV_THREADPOOL_SIZE |
The number of worker threads for this process. Note this shows the value of the variable, however if this variable was set after the thread pool starts, the thread pool will actually be the default size of 4. |
Connection pool pinging is a way for node-oracledb to identify unusable pooled connections and replace them with usable ones before returning them to the application. Node-oracledb connections may become unusable due to network dropouts, database instance failures, exceeding user profile resource limits, or by explicit session closure from a DBA. By default, idle connections in the pool are unaware of these events so the pool could return unusable connections to the application and errors would only occur when they are later used. Pinging helps provide tolerance against this situation.
The frequency of pinging can be controlled with the
oracledb.poolPingInterval
property or
during pool creation to meet
your quality of service requirements.
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 |
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 |
A ping has the cost of a round-trip to the database so
always pinging after each getConnection()
is not recommended for
most applications.
When getConnection()
is called to return a pooled connection, and
the connection has been idle in the pool (not “checked out” to the
application by getConnection()
) for the specified poolPingInterval
time, then an internal “ping” will be performed first. If the ping
detects the connection is invalid then node-oracledb internally drops
the unusable connection and obtains another from the pool. This
second connection may also need a ping. This ping-and-release process
may be repeated until:
getConnection()
call returns this to the application. Note that since a ping may not have been performed, the connection is not guaranteed to be usablePools in active use may never have connections idle longer than
poolPingInterval
, so pinging often only occurs for infrequently
accessed connection pools.
Because a ping may not occur every time a connection is returned from
getConnection()
, and also it is possible for
network outages to occur after getConnection()
is called,
applications should continue to use appropriate statement execution
error checking.
When node-oracledb is using the Oracle client library version 12.2 or
later, then a lightweight connection check always occurs in the client
library. While this check prevents some unusable connections from
being returned by getConnection()
, it does not identify errors such
as session termination from the database resource manager or
user resource profile IDLE_TIME
, or from an ALTER SYSTEM
KILL SESSION
command. The explicit ping initiated by
poolPingInterval
will detect these problems.
For ultimate scalability, use Oracle client 12.2 (or later) libraries, disable
explicit pool pinging by setting poolPingInterval
to a negative value, and
make sure the firewall, database resource manager, or user profile is not
expiring idle connections. See Preventing Premature Connection
Closing.
In all cases, when a bad connection is released back to the pool with
connection.close(), the connection is
automatically destroyed. This allows a valid connection to the
database to be opened by some subsequent getConnection()
call.
Explicit pings can be performed at any time with
connection.ping()
.
Applications can set “session” state in each connection. For all
practical purposes, connections are synonymous with sessions.
Examples of session state are NLS settings from ALTER SESSION
statements. Pooled connections will retain their session state after
they have been released back to the pool with connection.close()
.
However, because pools can grow, or connections in the pool can be
recreated, there is no guarantee a subsequent pool.getConnection()
call will return a database connection that has any particular state.
The oracledb.createPool()
option attribute
sessionCallback
can be used
to set session state efficiently so that connections have a known
session state. The sessionCallback
can be a Node.js function that
will be called whenever pool.getConnection()
will return a newly
created database connection that has not been used before. It is also
called when connection tagging is being used and the requested tag is
not identical to the tag in the connection returned by the pool. It
is called before pool.getConnection()
returns in these two cases.
It will not be called in other cases. Using a callback saves the cost
of setting session state if a previous user of a connection has
already set it. The caller of pool.getConnection()
can always
assume the correct state is set. The sessionCallback
can also be a
PL/SQL procedure, described in PL/SQL Session Tagging
Callback.
There are three common scenarios for sessionCallback
:
When all connections in the pool should have the same state: use a Node.js callback without tagging.
When connections in the pool require different state for different users: use a Node.js callback with tagging.
When using DRCP: use a PL/SQL callback and tagging.
This example sets two NLS settings in each pooled connection. They
are only set the very first time connections are established to the
database. The requestedTag
parameter is ignored because it is only
valid when tagging is being used:
function initSession(connection, requestedTag, cb) {
connection.execute(
`alter session set nls_date_format = 'YYYY-MM-DD' nls_language = AMERICAN`,
cb);
}
try {
const pool = await oracledb.createPool({
user: 'hr',
password: mypw, // mypw contains the hr schema password
connectString: 'localhost/XEPDB1',
sessionCallback: initSession
});
. . .
}
If you need to execute multiple SQL statements in the callback, use an
anonymous PL/SQL block to save round-trips of repeated
execute()
calls:
connection.execute(
`begin
execute immediate
'alter session set nls_date_format = ''YYYY-MM-DD'' nls_language = AMERICAN';
-- other SQL statements could be put here
end;`,
cb);
See sessionfixup.js
for a runnable example.
Connection tagging and sessionCallback
are new features in
node-oracledb 3.1.
Pooled connections can be tagged to record their session state by
setting the property connection.tag
to a string. A
pool.getConnection({tag: 'mytag'})
call can request a connection
that has the specified tag. If no available connections with that tag
exist in the pool, an untagged connection or a connection with a new
session will be returned. If the optional getConnection()
attribute
matchAnyTag
is true, then a connection that has a different tag
may be returned.
The sessionCallback
function
is invoked before pool.getConnection()
returns if the requested tag
is not identical to the actual tag of the pooled connection. The
callback can compare the requested tag with the current actual tag in
connection.tag
. Any desired state change can be made to the
connection and connection.tag
can be updated to record the change.
The best practice recommendation is to set the tag in the callback
function but, if required, a tag can be set anytime prior to closing
the connection. To clear a connection’s tag set connection.tag
to
an empty string.
You would use tagging where you want pool.getConnection()
to return
a connection which has one of several different states. If all
connections should have the same state then you can simply set
sessionCallback
, as shown earlier, and not use
tagging. Also, it may not be worthwhile using huge numbers of
different tags or using tagging where connections are being
dropped or recreated frequently since the chance
of pool.getConnection()
returning an already initialized connection
with the requested tag could be low, so most pool.getConnection()
calls would return a connection needing its session reset, and tag
management will just add overhead.
When node-oracledb is using Oracle Client libraries 12.2 or later,
then node-oracledb uses ‘multi-property tags’ and the tag string must
be of the form of one or more “name=value” pairs separated by a
semi-colon, for example "loc=uk;lang=cy"
. The Oracle session
pool used by node-oracledb has various heuristics to determine
which connection is returned to the application. Refer to the
multi-property tags documentation. The callback function can
parse the requested multi-property tag and compare it with the
connection’s actual properties in connection.tag
to
determine what exact state to set and what value to update
connection.tag
to.
This example Node.js callback function ensures the connection contains valid settings for an application-specific “location=USA” property and ignores any other properties in the tag that represent session state set by other parts of the application (not shown) that are using the same pool:
const sessionTag = "location=USA";
function initSession(connection, requestedTag, cb) {
const seen = connection.tag ? connection.tag.split(";").includes(requestedTag) : false;
if (seen) {
cb()
} else {
connection.execute(
`ALTER SESSION SET NLS_DATE_FORMAT = 'MM/DD/YY' NLS_LANGUAGE = AMERICAN`,
(err) => {
// Update the tag the record the connection's new state
const k = requestedTag.substr(0, requestedTag.indexOf('=')+1);
if (connection.tag.indexOf(k) >= 0) {
// Update value of an existing, matching property in the tag
const re = new RegExp(k + "[^;]*");
connection.tag = connection.tag.replace(re, requestedTag);
} else {
// the requested property was not previously set in the tag
connection.tag = requestedTag + ';' + connection.tag;
}
cb();
});
}
}
try {
await oracledb.createPool({
user: 'hr',
password: mypw, // mypw contains the hr schema password
connectString: 'localhost/XEPDB1',
sessionCallback: initSession
});
// Request a connection with a given tag from the pool cache, but accept any tag being returned.
const connection = await oracledb.getConnection({poolAlias: 'default', tag: sessionTag, matchAnyTag: true});
. . . // Use the connection
// The connection will be returned to the pool with the tag value of connection.tag
await connection.close();
. . .
For runnable examples, see sessiontagging1.js
and sessiontagging2.js
.
When node-oracledb is using Oracle Client libraries 12.2 or later,
sessionCallback
can be a string containing the name of a PL/SQL
procedure that is called when the requested tag does not match the
actual tag in the connection. 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.
After a PL/SQL callback completes and pool.getConnection()
returns,
connection.tag
will have the same property values as
the requested tag. The property order may be different. For example
you may request “USER_TZ=UTC;LANGUAGE=FRENCH” but connection.tag
may
be “LANGUAGE=FRENCH;USER_TZ=UTC”. When matchAnyTag
is true, then
various heuristics are used to determine which connection in the pool
to use. See the multi-property tags documentation. Additional
properties may be present in connection.tag
.
There is no direct way for Node.js to know if the PL/SQL procedure was
called or what session state it changed. After pool.getConnection()
returns, care must be taken to set connection.tag
to an appropriate
value.
A sample PL/SQL callback procedure looks like:
CREATE OR REPLACE PACKAGE myPackage AS
TYPE property_t IS TABLE OF VARCHAR2(64) INDEX BY VARCHAR2(64);
PROCEDURE buildTab(
tag IN VARCHAR2,
propertyTab OUT property_t
);
PROCEDURE myPlsqlCallback (
requestedTag IN VARCHAR2,
actualTag IN VARCHAR2
);
END;
/
CREATE OR REPLACE PACKAGE BODY myPackage AS
-- Parse the "property=value" pairs in the tag
PROCEDURE buildTab(tag IN VARCHAR2, propertyTab OUT property_t) IS
property VARCHAR2(64);
propertyName VARCHAR2(64);
propertyValue VARCHAR2(64);
propertyEndPos NUMBER := 1;
propertyStartPos NUMBER := 1;
propertyNameEndPos NUMBER := 1;
begin
WHILE (LENGTH(tag) > propertyEndPos)
LOOP
propertyEndPos := INSTR(tag, ';', propertyStartPos);
IF (propertyEndPos = 0) THEN
propertyEndPos := LENGTH(tag) + 1;
END IF;
propertyNameEndPos := INSTR(tag, '=', propertyStartPos);
propertyName := SUBSTR(tag, propertyStartPos,
propertyNameEndPos - propertyStartPos);
propertyValue := SUBSTR(tag, propertyNameEndPos + 1,
propertyEndPos - propertyNameEndPos - 1);
propertyTab(propertyName) := propertyValue;
propertyStartPos := propertyEndPos + 1;
END LOOP;
END;
PROCEDURE myPlsqlCallback (
requestedTag IN VARCHAR2,
actualTag IN VARCHAR2
) IS
reqPropTab property_t;
actPropTab property_t;
propertyName VARCHAR2(64);
BEGIN
buildTab(requestedTag, reqPropTab);
buildTab(actualTag, actPropTab);
-- Iterate over requested properties to set state when it's not
-- currently set, or not set to the desired value
propertyName := reqPropTab.FIRST;
WHILE (propertyName IS NOT NULL)
LOOP
IF ((NOT actPropTab.exists(propertyName)) OR
(actPropTab(propertyName) != reqPropTab(propertyName))) THEN
IF (propertyName = 'SDTZ') THEN
EXECUTE IMMEDIATE
'ALTER SESSION SET TIME_ZONE=''' || reqPropTab(propertyName) || '''';
ELSE
RAISE_APPLICATION_ERROR(-20001,'Unexpected session setting requested');
END IF;
END IF;
propertyName := reqPropTab.NEXT(propertyName);
END LOOP;
-- Could iterate over other actual properties to set any to a default state
END;
END myPackage;
/
This could be used in your application like:
const sessionTag = "SDTZ=UTC";
try {
const pool = await oracledb.createPool({
user: 'hr',
password: mypw, // mypw contains the hr schema password
connectString: 'localhost/XEPDB1',
sessionCallback: "myPackage.myPlsqlCallback"
});
. . .
const connection = await pool.getConnection({tag: sessionTag});
. . . // The value of connection.tag will be sessionTag
// Use connection.
await connection.close();
}
By default, connection pools are ‘homogeneous’ meaning that all
connections use the same database credentials. However, if the pool
option homogeneous
is false at
pool creation, then a ‘heterogeneous’ pool will be created. This
allows different credentials to be used each time a connection is
acquired from the pool with
pool.getConnection()
.
When a heterogeneous pool is created by setting
homogeneous
to false and no
credentials supplied during pool creation, then a user name and
password may be passed to pool.getConnection()
:
const pool = await oracledb.createPool(
{
connectString : "localhost/XEPDB1", // no user name or password
homogeneous : false,
. . . // other pool options such as poolMax
});
const connection = await pool.getConnection(
{
user : 'hr',
password : mypw, // mypw contains the hr schema password
});
. . . // use connection
await connection.close();
The connectString
is required during pool creation since the pool is
created for one database instance.
Different user names may be used each time pool.getConnection()
is
called.
When applications want to use connection pools but are not able to use
connection.clientId
to distinguish application
users from database schema owners, a ‘heterogeneous’ connection pool
might be an option.
Note 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
.
For heterogeneous pools, the number of connections initially created
is zero even if a larger value is specified for
poolMin
. The pool increment is always 1,
regardless of the value of
poolIncrement
. Once the number
of open connections exceeds poolMin
and connections are idle for
more than the poolTimeout
seconds, then the
number of open connections does not fall below poolMin
.
Pool proxy authentication requires a heterogeneous pool.
The idea of a proxy is to create a schema in one database user name. Privilege is granted on that schema to other database users so they can access the schema and manipulate its data. This aids three-tier applications where one user owns the schema while multiple end-users access the data.
To grant access, typically a DBA would execute:
ALTER USER sessionuser GRANT CONNECT THROUGH proxyuser;
For example, to allow a user called MYPROXYUSER
to access the schema
of HR
:
SQL> CONNECT system
SQL> ALTER USER hr GRANT CONNECT THROUGH myproxyuser;
SQL> CONNECT myproxyuser[hr]/myproxyuserpassword
SQL> SELECT SYS_CONTEXT('USERENV', 'SESSION_USER') AS SESSION_USER,
2 SYS_CONTEXT('USERENV', 'PROXY_USER') AS PROXY_USER
3 FROM DUAL;
SESSION_USER PROXY_USER
-------------------- --------------------
HR MYPROXYUSER
See the Client Access Through a Proxy section in the Oracle Call Interface manual for more details about proxy authentication.
To use the proxy user with a node-oracledb heterogeneous connection pool you could do:
const myproxyuserpw = ... // the password of the 'myproxyuser' proxy user
const pool = await oracledb.createPool({ connectString: "localhost/orclpdb1", homogeneous: false });
const connection = await pool.getConnection({ user: 'myproxyuser[hr]', password: myproxyuserpw});
. . . // connection has access to the HR schema objects
await connection.close();
Other proxy cases are supported such as:
const myproxyuserpw = ... // the password of the 'myproxyuser' proxy user
const pool = await oracledb.createPool(
{
user : 'myproxyuser',
password : myproxyuserpw,
connectString : "localhost/XEPDB1",
homogeneous : false,
. . . // other pool options such as poolMax can be used
});
const connection = await pool.getConnection({ user : 'hr' }); // the session user
. . . // connection has access to the HR schema objects
await connection.close();
External Authentication allows applications to use an external password store (such as an Oracle Wallet), the Secure Socket Layer (SSL), or the operating system to validate user access. One of the benefits is that database credentials do not need to be hard coded in the application.
To use external authentication, set the
oracledb.externalAuth
property to true. This property can
also be set in the connAttrs
or poolAttrs
parameters of the
oracledb.getConnection()
or
oracledb.createPool()
calls, respectively.
When externalAuth
is set, any subsequent connections obtained using
the oracledb.getConnection()
or
pool.getConnection()
calls will use external
authentication. Setting this property does not affect the operation
of existing connections or pools.
For a standalone connection:
const config = { connectString: "localhost/orclpdb1", externalAuth: true };
const connection = await oracledb.getConnection(config);
. . . // connection has access to the schema objects of the externally identified user
If a user HR
has been given the CONNECT THROUGH
grant from the
externally identified user MYPROXYUSER
:
ALTER USER hr GRANT CONNECT THROUGH myproxyuser;
then to specify that the session user of the connection should be
HR
, use:
const config = { connectString: "localhost/orclpdb1", user: "[hr]", externalAuth: true };
const connection = await oracledb.getConnection(config);
. . . // connection has access to the HR schema objects
For a Pool, you can authenticate as an externally identified user like:
const config = { connectString: "localhost/orclpdb1", externalAuth: true };
const pool = await oracledb.createPool(config);
const connection = await pool.getConnection();
. . . // connection has access to the schema objects of the externally identified user
await connection.close();
If a user HR
has been given the CONNECT THROUGH
grant from the
externally identified user, then to specify that the session user of
the connection should be HR
, use:
const config = { connectString: "localhost/orclpdb1", externalAuth: true };
const pool = await oracledb.createPool(config);
const connection = await pool.getConnection({ user: "[hr]" });
. . . // connection has access to the HR schema objects
await connection.close();
Note this last case needs Oracle Client libraries version 18 or later.
Using externalAuth
in the connAttrs
parameter of a
pool.getConnection()
call is not possible. The connections from a Pool
object are always obtained in the manner in which the pool was
initially created.
For pools created with external authentication, the number of
connections initially created is zero even if a larger value is
specified for poolMin
. The pool increment is
always 1, regardless of the value of
poolIncrement
. Once the number
of open connections exceeds poolMin
and connections are idle for
more than the poolTimeout
seconds, then the
number of open connections does not fall below poolMin
.
Database Resident Connection Pooling (DRCP) enables database resource sharing for applications that run in multiple client processes or run on multiple middle-tier application servers. DRCP reduces the overall number of connections that a database must handle.
DRCP is generally used only when the database host does not have enough memory
to keep all connections open concurrently. For example, if your application
runs as 10 Node.js processes each with a connection pool having poolMax
of
50, then the database host must be able to have 10 * 50 = 500 database server
processes open at the same time. If the database host does not have enough
memory for these 500 server processes, then DRCP may be a solution because a
smaller pool of server processes will be shared between all the Node.js
connections.
DRCP is useful for applications which share the same database credentials, have similar session settings (for example date format settings and PL/SQL package state), and where the application gets a database connection, works on it for a relatively short duration, and then releases it.
To use DRCP in node-oracledb:
SQL> EXECUTE DBMS_CONNECTION_POOL.START_POOL();
connectionClass
should be set by the node-oracledb application. If it is not set, the pooled server session memory will not be reused optimally, and the statistic views will record large values for NUM_MISSES
.pool.createPool()
or oracledb.getConnection()
property connectString
(or its alias connectionString
) must specify to use a pooled server, either by the Easy Connect syntax like myhost/sales:POOLED
, or by using a tnsnames.ora
alias for a connection that contains (SERVER=POOLED)
.For efficiency, it is recommended that DRCP connections should be used with node-oracledb’s local connection pool.
The DRCP ‘Purity’ is SELF for DRCP connections. This allows reuse of both the pooled server process and session memory, giving maximum benefit from DRCP. See the Oracle documentation on benefiting from scalability.
The Oracle DRCP documentation has more details, including when to use, and when not to use DRCP.
There are a number of Oracle Database V$
views that can be used to
monitor DRCP. These are discussed in the Oracle documentation and in
the Oracle technical paper PHP Scalability and High Availability.
This paper also gives more detail on configuring DRCP.
Database privileges such as SYSDBA
can be obtained when using
standalone connections. Use one of the Privileged Connection
Constants with the connection
privilege
property, for example:
let connection;
try {
connection = await oracledb.getConnection(
{
user : 'sys',
password : 'secret',
connectString : 'localhost/orclpdb1',
privilege : oracledb.SYSDBA
});
console.log('I have power');
. . . // use connection
} catch (err) {
console.error(err);
} finally {
if (connection) {
try {
await connection.close();
} catch (err) {
console.error(err);
}
}
}
Note that if node-oracledb is using the Oracle client libraries
located in the Oracle Database installation, i.e. is on the same
machine as the database and is not using Oracle Instant Client, then
operating system privileges may be used for authentication. In this
case the password value is ignored. For example on Linux, membership
of the operating system dba
group allows SYSDBA
connections.
Administrative privileges can allow access to a database instance even when the database is not open. Control of these privileges is totally outside of the database itself. Care must be taken with authentication to ensure security. See the Database Administrator’s Guide for information.
Data transferred between Oracle Database and the Oracle client libraries used by node-oracledb can be encrypted so that unauthorized parties are not able to view plain text data as it passes over the network. The easiest configuration is Oracle’s native network encryption. The standard SSL protocol can also be used if you have a PKI, but setup is necessarily more involved.
With native network encryption, the client and database server negotiate a key using Diffie-Hellman key exchange. There is protection against man-in-the-middle attacks.
Native network encryption can be configured by editing Oracle Net’s
optional sqlnet.ora
configuration files, on either the
database server and/or on each node-oracledb ‘client’. Parameters
control whether data integrity checking and encryption is required or
just allowed, and which algorithms the client and server should
consider for use.
As an example, to ensure all connections to the database are checked
for integrity and are also encrypted, create or edit the Oracle
Database $ORACLE_HOME/network/admin/sqlnet.ora
file. Set the
checksum negotiation to always validate a checksum and set the
checksum type to your desired value. The network encryption settings
can similarly be set. For example, to use the SHA512 checksum and
AES256 encryption use:
SQLNET.CRYPTO_CHECKSUM_SERVER = required
SQLNET.CRYPTO_CHECKSUM_TYPES_SERVER = (SHA512)
SQLNET.ENCRYPTION_SERVER = required
SQLNET.ENCRYPTION_TYPES_SERVER = (AES256)
If you definitely know that the database server enforces integrity and
encryption, then you do not need to configure Node.js separately.
However you can also, or alternatively, do so depending on your
business needs. Create a file sqlnet.ora
(see Optional Oracle Net
Configuration):
SQLNET.CRYPTO_CHECKSUM_CLIENT = required
SQLNET.CRYPTO_CHECKSUM_TYPES_CLIENT = (SHA512)
SQLNET.ENCRYPTION_CLIENT = required
SQLNET.ENCRYPTION_TYPES_CLIENT = (AES256)
The client and server sides can negotiate the protocols used if the settings indicate more than one value is accepted.
Note these are example settings only. You must review your security requirements and read the documentation for your Oracle version. In particular review the available algorithms for security and performance.
The NETWORK_SERVICE_BANNER
column of the database view
V$SESSION_CONNECT_INFO
can be used to verify the encryption
status of a connection.
For more information about Oracle Data Network Encryption and Integrity, and for information about configuring SSL network encryption, refer to the Oracle Database Security Guide. This manual also contains information about other important security features that Oracle Database provides, such Transparent Data Encryption of data-at-rest in the database.
Database passwords can be changed with
connection.changePassword()
. For example:
const currentpw = ... // the current password for the hr schema
const newpw = ... // the new hr schema password
const connection = await oracledb.getConnection(
{
user : "hr",
password : currentpw,
connectString : "localhost/orclpdb1"
});
await connection.changePassword('hr', currentpw, newpw);
Only DBAs, or users with the ALTER USER privilege, can change the password of another user. In this case, the old password value is ignored and can be an empty string:
const newpw = ... // the new password
const connection = await oracledb.getConnection(
{
user : "system", // a privileged user
password : mypw, // mypw contains the system schema password
connectString : "localhost/orclpdb1"
});
await connection.changePassword('hr', '', newpw);
When creating a standalone, non-pooled connection the user’s password can be changed at time of connection. This is most useful when the user’s password has expired, because it allows a user to connect without requiring a DBA to reset their password.
Both the current and new passwords must be given when connecting. For example:
const oldpw = ... // the hr schema's old password
const newpw = ... // the new password
const connection = await oracledb.getConnection(
{
user : "hr",
password : oldpw,
newPassword : newpw,
connectString : "localhost/orclpdb1"
});
To make highly available applications, use the latest versions of Oracle Client and Database. Also use the latest node-oracledb driver. These have improved APIs and improved implementations to make connections efficient and available. In addition, features like Connection Pool Pinging, Fast Application Notification (FAN), Application Continuity, and Oracle Net Services settings can all help high availability, often without the application being aware of any issue.
For application high availability, use a connection pool. Pools provide immediately available connections. Also the internal pool implementation supports a number of Oracle Database high availability features for planned and unplanned database instance downtime. Use a fixed size pool to avoid connection storms.
Configuring TCP timeouts can help avoid application hangs if there is a network failure. FAN is also useful.
Oracle Net options may be useful for high availability and performance tuning.
Connection establishment timeouts can be set. The database’s
listener.ora
file can have RATE_LIMIT
and QUEUESIZE
parameters that can help handle connection storms. In the bigger picture,
Oracle Net can be used to configure database service settings, such as for
failover using Oracle RAC or a standby database.
Database Resident Connection Pooling (DRCP) may be useful to reduce load on a database host. It can also help reduce connection time when a number of Node.js processes are used to scale up an application.
Finally, applications should always check for execution errors, and perform appropriate application-specific recovery.
When connections are idle, external timeouts may disconnect them from the database. This can impact scalability, cause connection storms, and lead to application errors when invalid connections are attempted to be used.
There are three components to a node-oracledb connection:
The memory structure in node-oracledb that is returned by a
getConnection()
call. It may be stored in a connection pool.
The underlying network connection between the Oracle Client libraries and the database.
A server process, or thread, on the database host to handle database processing.
Node-oracledb connections may become unusable due to network dropouts, database
instance failures, exceeding user profile resource limits, or by explicit
session closure of the server process from a DBA. By default, idle connections
in connection pools are unaware of these changes, so a pool.getConnection()
call could successfully return a connection to the application that will not be
usable. An error would only occur when calling connection.execute()
, or
similar.
Disable any firewall that is killing idle connections. Also disable the
database resource manager and any user resource profile
IDLE_TIME
setting so they do not terminate sessions. These issues can
be hidden by node-oracledb’s automatic connection re-establishment features so
it is recommended to use AWR to check the connection rate, and then fix
underlying causes.
With Oracle Client 19c, EXPIRE_TIME
can be used in
tnsnames.ora
connect descriptors to prevent firewalls from
terminating idle connections and to adjust keepalive timeouts. The general
recommendation for EXPIRE_TIME
is to use a value that is slightly less than
half of the termination period. In older versions of Oracle Client, a
tnsnames.ora connect descriptor option ENABLE=BROKEN
can be used instead
of EXPIRE_TIME
. These settings can also aid detection of a terminated remote
database server. With Oracle Client 19c, the setting can be passed in Easy
Connect strings, for example your connection string could be
"mydbmachine.example.com/orclpdb1?expire_time=2"
to send packets every two
minutes.
If the network or the database server processes used by node-oracledb connections cannot be prevented from becoming unusable, tune Connection Pool Pinging. Another case where this internal pinging is helpful is during development, where a laptop may go offline for an extended time.
FAN support is useful for planned and unplanned outages. It provides immediate notification to node-oracledb following outages related to the database, computers, and networks. Without FAN, node-oracledb can hang until a TCP timeout occurs and a network error is returned, which might be several minutes.
Users of Oracle Database FAN must connect to a FAN-enabled database
service. The application should have oracledb.events
is set
to true. This value can also be changed via Oracle Client
Configuration.
FAN allows node-oracledb to provide high availability features without
the application being aware of an outage. Unused, idle connections in
a connection pool will be automatically cleaned up. A future
pool.getConnection()
call will establish a fresh connection to a
surviving database instance without the application being aware of any
service disruption.
To handle errors that affect active connections, you can add application logic to re-connect (this will connect to a surviving database instance) and replay application logic without having to return an error to the application user. Alternatively, use Application Continuity.
FAN benefits users of Oracle Database’s clustering technology (Oracle RAC) because connections to surviving database instances can be immediately made. Users of Oracle’s Data Guard with a broker will get FAN events generated when the standby database goes online. Standalone databases will send FAN events when the database restarts.
For a more information on FAN see the technical paper on Fast Application Notification.
Oracle Database RAC users with Oracle Database (RLB)
advisory events configured should use node-oracledb Connection
Pooling and make sure
oracledb.events
is true. The events mode can
also be changed via Oracle Client Configuration.
RLB allows optimal use of database resources by balancing database requests across RAC instances.
For a more information on RLB, see the technical paper on Fast Application Notification.
Node-oracledb OLTP applications can take advantage of continuous availability with the Oracle Database features Application Continuity and Transparent Application Continuity. These help make unplanned database service downtime transparent to applications. See the technical papers Continuous Availability Application Continuity for the Oracle Database and Continuous Availability Best Practices for Applications Using Autonomous Database - Dedicated.
When connected to an AC or TAC enabled service, node-oracledb automatically supports AC or TAC.
To limit the amount of time taken to establish new connections to Oracle
Database, use Oracle Net options like SQLNET.OUTBOUND_CONNECT_TIMEOUT
in
a sqlnet.ora
file or CONNECT_TIMEOUT
in a connection
string. When using a connection pool, these values affect the
time taken to establish each connection stored in the pool. The
queueTimeout
and queueMax
settings
control higher-level pool behavior.
With Oracle Client 19c, timeouts can be passed in Easy Connect
strings, for example to timeout after 15 seconds:
"mydbmachine.example.com/orclpdb1?connect_timeout=15"
To limit the amount of time taken to execute statements on connections, use
connection.callTimeout
or Oracle Net settings like
SQLNET.RECV_TIMEOUT
and SQLNET.SEND_TIMEOUT
in a sqlnet.ora
file. The necessary out-of-band break setting is automatically configured when
using Oracle Client 19 and Oracle Database 19, or later. With older Oracle
versions on systems that drop (or in-line) out-of-band breaks, you may need to
add DISABLE_OOB=ON
to a sqlnet.ora
file.
The connection.callTimeout
attribute is available when
node-oracledb is using Oracle client libraries version 18, or later. It is a
millisecond timeout for executing database calls on a connection. The
connection.callTimeout
period is on each individual round-trip
between node-oracledb and Oracle Database. Each node-oracledb method or
operation may require zero or more round-trips to Oracle Database. 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.
If the time from the start of any one round-trip to the completion
of that same round-trip exceeds callTimeout
milliseconds, then the
operation is halted and an error is returned.
In the case where a node-oracledb operation requires more than one
round-trip and each round-trip takes less than callTimeout
milliseconds, then no timeout will occur, even if the sum of all
round-trip calls exceeds callTimeout
.
If no round-trip is required, the operation will never be interrupted.
After a timeout occurs, node-oracledb attempts to clean up the
internal connection state. The cleanup is allowed to take another
callTimeout
milliseconds.
If the cleanup was successful, a DPI-1067 error will be returned and the application can continue to use the connection.
For small values of callTimeout
, the connection cleanup may not
complete successfully within the additional callTimeout
period. In
this case an ORA-3114 is returned and the connection will no longer
be usable. It should be released.
To enable connection to Oracle Autonomous Database in Oracle Cloud, a wallet needs be downloaded from the cloud GUI, and node-oracledb needs to be configured to use it. A database username and password is still required. The wallet only enables SSL/TLS.
From the Oracle Cloud console for the database download the wallet zip file. It contains the wallet and network configuration files. Note: keep wallet files in a secure location and share them only with authorized users.
Unzip the wallet zip file.
For node-oracledb, only these files from the zip are needed:
tnsnames.ora
- Maps net service names used for application connection strings to your database servicessqlnet.ora
- Configures Oracle Network settingscwallet.sso
- Enables SSL/TLS connections. Note the cloud wallet does not contain a database username or password.The other files and the wallet password are not needed.
Place these files as shown in Optional Oracle Net Configuration.
The sqlnet.ora
file contains a WALLET_LOCATION
path to the directory where
cwallet.sso
will be read from. By default this path is "?/network/admin"
.
This path maps to the network/admin
subdirectory of Oracle Instant Client , or
to the $ORACLE_HOME/network/admin
subdirectory (when node-oracledb is linked
with the client libraries from a full client or database installation). If
cwallet.sso
is in a different location, then you will need to edit the path in
sqlnet.ora
and set it to the directory containing cwallet.sso
.
The tnsnames.ora
file contains net service names for various levels of
database service. For example, if you create a database called CJDB1 with the
Always Free services from the Oracle Cloud Free Tier, then you might
decide to use the connection string in tnsnames.ora
called cjdb1_high
.
Update your application to use your schema username, its database password, and a net service name, for example:
connection = await oracledb.getConnection({
user: "scott",
password: mypw, // mypw contains the scott schema password
connectString: "cjdb1_high"
});
Once you have set Oracle environment variables required by your application,
such as ORA_SDTZ
or TNS_ADMIN
, you can start your application.
If you need to create a new database schema so you do not login as the privileged ADMIN user, refer to the relevant Oracle Cloud documentation, for example see Create Database Users in the Oracle Autonomous Transaction Processing Dedicated Deployments manual.
If you are behind a firewall, you can tunnel TLS/SSL connections via a proxy using HTTPS_PROXY in the connect descriptor. Successful connection depends on specific proxy configurations. Oracle does not recommend doing this when performance is critical.
Edit sqlnet.ora
and add a line:
SQLNET.USE_HTTPS_PROXY=on
Edit tnsnames.ora
and add an HTTPS_PROXY
proxy name and HTTPS_PROXY_PORT
port to the connect descriptor address list of any service name you plan to use,
for example:
cjdb1_high = (description= (address=(https_proxy=myproxy.example.com)(https_proxy_port=80)(protocol=tcps)(port=1522)(host= . . .
Sharding can be used to horizontally partition data across independent databases. A database table can be split so each shard contains a table with the same columns but a different subset of rows. These tables are known as sharded tables.
Sharding is configured in Oracle Database, see the Oracle Sharding manual. Sharding requires Oracle Database and client libraries 12.2, or later.
When opening a connection in node-oracledb, the
shardingKey
and
superShardingKey
properties can be
used to route the connection directly to a given
shard. A sharding key is always required. A super sharding key is additionally
required when using composite sharding, which is when data has been partitioned
by a list or range (the super sharding key), and then further partitioned by a
sharding key.
When creating a connection pool, the property
poolMaxPerShard
can be set. This is used to balance
connections in the pool equally across shards.
When connected to a shard, queries only returns data from that shard. For queries that need to access data from multiple shards, connections can be established to the coordinator shard catalog database. In this case, no shard key or super shard key is used.
The sharding and super sharding key properties are arrays of values. Array key values may be of type String (mapping to VARCHAR2 sharding keys), Number (NUMBER), Date (DATE), or Buffer (RAW). Multiple types may be used in each array. Sharding keys of TIMESTAMP type are not supported by node-oracledb.
For example, if sharding had been configured on a single column like:
CREATE SHARDED TABLE customers (
cust_id NUMBER,
cust_name VARCHAR2(30),
class VARCHAR2(10) NOT NULL,
signup_date DATE,
cust_code RAW(20),
CONSTRAINT cust_name_pk PRIMARY KEY(cust_name))
PARTITION BY CONSISTENT HASH (cust_name)
PARTITIONS AUTO TABLESPACE SET ts1;
then a shard can be directly connected to by passing a single sharding key:
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "localhost/orclpdb1",
shardingKey : ["SCOTT"]
});
Similar code works for NUMBER keys.
The shardingKey
and superShardingKey
properties are arrays because multiple
values can be used. If database shards had been partitioned with multiple keys
such as with:
CREATE SHARDED TABLE customers (
cust_id NUMBER NOT NULL,
cust_name VARCHAR2(30) NOT NULL,
class VARCHAR2(10) NOT NULL,
signup_date DATE,
cust_code RAW(20),
CONSTRAINT cust_pk PRIMARY KEY(cust_id, cust_name));
PARTITION BY CONSISTENT HASH (cust_id, cust_name)
PARTITIONS AUTO TABLESPACE SET ts1;
then direct connection to a shard can be established by specifying multiple keys, for example:
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "localhost/orclpdb1",
shardingKey : [70, "SCOTT"]
});
When the sharding key is a DATE column like:
CREATE SHARDED TABLE customers (
cust_id NUMBER,
cust_name VARCHAR2(30),
class VARCHAR2(10) NOT NULL,
signup_date DATE,
cust_code RAW(20),
CONSTRAINT signup_date_pk PRIMARY KEY(signup_date))
PARTITION BY CONSISTENT HASH (signup_date)
PARTITIONS AUTO TABLESPACE SET ts1;
then direct connection to a shard needs a Date key that is in the session time zone. For example if the session time zone is set to UTC (see Fetching Dates and Timestamps) then Dates must also be in UTC:
key = new Date ("2019-11-30Z"); // when session time zone is UTC
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "localhost/orclpdb1",
shardingKey : [key]
});
When the sharding key is a RAW column like:
CREATE SHARDED TABLE customers (
cust_id NUMBER,
cust_name VARCHAR2(30),
class VARCHAR2(10) NOT NULL,
signup_date DATE,
cust_code RAW(20),
CONSTRAINT cust_code_pk PRIMARY KEY(cust_code))
PARTITION BY CONSISTENT HASH (cust_code)
PARTITIONS AUTO TABLESPACE SET ts1;
then direct connection to a shard could be like:
const data = [0x00, 0x01, 0x02];
const key = Buffer.from(data);
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "localhost/orclpdb1",
shardingKey : [key]
});
If composite sharding was in use, for example:
CREATE SHARDED TABLE customers (
cust_id NUMBER NOT NULL,
cust_name VARCHAR2(30) NOT NULL,
class VARCHAR2(10) NOT NULL,
signup_date DATE,
cust_code RAW(20),
PARTITIONSET BY LIST (class)
PARTITION BY CONSISTENT HASH (cust_name)
PARTITIONS AUTO (PARTITIONSET gold VALUES ('gold') TABLESPACE SET ts1,
PARTITIONSET silver VALUES ('silver') TABLESPACE SET ts2);
then direct connection to a shard can be established by specifying a super sharding key and sharding key, for example:
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw, // mypw contains the hr schema password
connectString : "localhost/orclpdb1",
superShardingKey: ["gold"]
shardingKey : ["SCOTT"],
});
A single SQL or PL/SQL statement may be executed using the
Connection execute()
method. The callback style shown
below, or promises, or
Async/Await may be used.
Results may be returned in a single array, or fetched in batches with
a ResultSet. Queries may optionally be streamed
using the connection.queryStream()
method.
Node-oracledb’s execute()
and
queryStream()
methods use Statement
Caching to make re-execution of statements efficient.
This removes the need for a separate ‘prepare’ method to parse
statements.
Tune query performance by adjusting fetchArraySize
and prefetchRows
, see Tuning Fetch
Performance.
Connections can handle one database operation at a time. Other
database operations will block. Structure your code to avoid starting
parallel operations on a connection. For example avoid using
async.parallel
or Promise.all()
which call each of their items in parallel,
see Parallelism on a Connection.
After all database calls on the connection complete, the application
should use the connection.close()
call to
release the connection.
By default, queries are handled as ‘direct fetches’, meaning all
results are returned in the callback result.rows
property:
const result = await connection.execute(
`SELECT department_id, department_name
FROM departments
WHERE department_id = :did`,
[180],
{ maxRows: 10 } // a maximum of 10 rows will be returned
);
console.log(result.rows); // print all returned rows
Any rows beyond the maxRows
limit are not returned. If
maxRows
is 0 (the default), then all rows will be returned - up to the limit
by Node.js memory.
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.
Internally, rows are fetched from Oracle Database in batches to improve
performance. The internal batch size is based on the lesser of
fetchArraySize
and maxRows
. Row prefetching can
also be adjusted for tuning, see Tuning Fetch Performance. Each
internally fetched batch is concatenated into the array eventually returned to
the application.
For queries expected to return a small number of rows, reduce
fetchArraySize
to reduce internal memory overhead
by node-oracledb.
For direct fetches, JavaScript memory can become a limitation in two cases:
the absolute amount of data returned is simply too large for JavaScript to hold in a single array.
the JavaScript heap can be exceeded, or become fragmented, due to
concatenation of the successive buffers of records fetched from the database.
To minimize this, use fetchArraySize
and prefetchRows
values determined by
tuning.
In both cases, use a ResultSet or Query Stream instead of a direct fetch.
When the number of query rows is relatively big, or cannot be
predicted, it is recommended to use a ResultSet
with callbacks, as described in this section, or via query streaming,
as described later. This prevents query results
being unexpectedly truncated by the maxRows
limit,
or exceeding Node.js memory constraints. Otherwise, for queries that
return a known small number of rows, non-ResultSet queries may have
less overhead.
A ResultSet is created when the execute()
option property
resultSet
is true. ResultSet rows can be
fetched using getRow()
or getRows()
on the
execute()
callback function’s result.resultSet
property.
For ResultSets, the maxRows
limit is ignored. All
rows can be fetched.
When all rows have been fetched, or the application does not want to
continue getting more rows, then the ResultSet should be freed using
close()
. The ResultSet should also be explicitly closed
in the cases where no rows will be fetched from it.
REF CURSORS returned from PL/SQL blocks via
oracledb.CURSOR
OUT binds are also available as
ResultSets. See REF CURSOR Bind Parameters.
The format of each row will be an array or object, depending on the value of outFormat.
See resultset1.js, resultset2.js and refcursor.js for full examples.
To fetch one row at a time use getRow() :
const result = await connection.execute(
`SELECT employee_id, last_name
FROM employees
WHERE ROWNUM < 5
ORDER BY employee_id`,
[], // no bind variables
{
resultSet: true // return a ResultSet (default is false)
}
);
const rs = result.resultSet;
let row;
let i = 1;
while ((row = await rs.getRow())) {
console.log("getRow(): row " + i++);
console.log(row);
}
// always close the ResultSet
await rs.close();
To fetch multiple rows at a time, use getRows()
:
const numRows = 10;
const result = await connection.execute(
`SELECT employee_id, last_name
FROM employees
WHERE ROWNUM < 25
ORDER BY employee_id`,
[], // no bind variables
{
resultSet: true // return a ResultSet (default is false)
}
);
// Fetch rows from the ResultSet.
const rs = result.resultSet;
let rows;
do {
rows = await rs.getRows(numRows); // get numRows rows at a time
if (rows.length > 0) {
console.log("getRows(): Got " + rows.length + " rows");
console.log(rows);
}
} while (rows.length === numRows);
// always close the ResultSet
await rs.close();
Streaming of query results allows data to be piped to other streams, for example when dealing with HTTP responses.
Use connection.queryStream()
to create a stream from a top
level query and listen for events. You can also call
connection.execute()
and use toQueryStream()
to return a stream from the returned ResultSet, from an OUT
bind REF CURSOR ResultSet, or from Implicit Results
ResultSets.
With streaming, each row is returned as a data
event. Query metadata is
available via a metadata
event. The end
event indicates the end of the
query results. After the end
event has been received, the Stream
destroy() function should be called to clean up resources properly. Any
further end-of-fetch logic, in particular the connection release, should be in
the close
event.
Query results should be fetched to completion to avoid resource leaks, or the
Stream destroy()
function can be used to terminate a stream early. When
fetching, the connection must remain open until the stream is completely read
and the close
event received. Any returned Lob objects should
also be processed first.
The query stream implementation is a wrapper over the ResultSet
Class. In particular, successive calls to getRow()
are made internally. Each row will generate a data
event. For tuning, adjust
the values of the connection.querystream()
options
fetchArraySize
and
prefetchRows
, see Tuning Fetch
Performance.
An example of streaming query results is:
const stream = await connection.queryStream(`SELECT employees_name FROM employees`);
stream.on('error', function (error) {
// handle any error...
});
stream.on('data', function (data) {
// handle data row...
});
stream.on('end', function () {
// all data has been fetched...
stream.destroy(); // the stream should be closed when it has been finished
});
stream.on('close', function () {
// can now close connection... (Note: do not close connections on 'end')
});
stream.on('metadata', function (metadata) {
// access metadata of query
});
// listen to any other standard stream events...
See selectstream.js for a runnable example using
connection.queryStream()
.
The REF CURSOR Bind Parameters section shows using
toQueryStream()
to return a stream for a REF CURSOR.
Query rows may be returned as an array of column values, or as JavaScript objects, depending on the values of outFormat.
The default format for each row is an array of column values. For example:
const result = await connection.execute(
`SELECT department_id, department_name
FROM departments
WHERE manager_id < :id`,
[110] // bind value for :id
);
console.log(result.rows);
If run with Oracle’s sample HR schema, the output is:
[ [ 60, 'IT' ], [ 90, 'Executive' ], [ 100, 'Finance' ] ]
Using this format is recommended for efficiency.
Alternatively, rows may be fetched as JavaScript objects. To do so,
specify the outFormat
option to be oracledb.OUT_FORMAT_OBJECT
:
oracledb.outFormat = oracledb.OUT_FORMAT_OBJECT;
The value can also be set as an execute()
option:
const result = await connection.execute(
`SELECT department_id, department_name
FROM departments
WHERE manager_id < :id`,
[110], // bind value for :id
{ outFormat: oracledb.OUT_FORMAT_OBJECT }
);
console.log(result.rows);
The output is:
[ { DEPARTMENT_ID: 60, DEPARTMENT_NAME: 'IT' },
{ DEPARTMENT_ID: 90, DEPARTMENT_NAME: 'Executive' },
{ DEPARTMENT_ID: 100, DEPARTMENT_NAME: 'Finance' } ]
In the preceding example, each row is a JavaScript object that specifies column names and their respective values. Note the property names follow Oracle’s standard name-casing rules. They will commonly be uppercase, since most applications create tables using unquoted, case-insensitive names.
Prior to node-oracledb 4.0, the constants oracledb.ARRAY
and oracledb.OBJECT
where used. These are now deprecated.
Support for queries containing cursor expressions that return nested cursors was added in node-oracledb 5.0.
Each nested cursor in query results is returned as a sub-array of rows in
result.rows
. For example with:
const sql = `SELECT department_name,
CURSOR(SELECT salary, commission_pct
FROM employees e
WHERE e.department_id = d.department_id
ORDER BY salary) as nc
FROM departments d
ORDER BY department_name`;
const result = await connection.execute(sql);
console.dir(result.rows, {depth: null});
Output will be:
[
[ 'Accounting', [ [ 8300, null ], [ 12008, null ] ] ],
[ 'Administration', [ [ 4400, null ] ] ],
[ 'Benefits', [] ],
[ 'Construction', [] ],
[ 'Contracting', [] ],
[ 'Control And Credit', [] ],
[ 'Corporate Tax', [] ],
[
'Executive',
[ [ 17000, null ], [ 17000, null ], [ 24000, null ] ]
],
[
'Finance',
[
[ 6900, null ],
[ 7700, null ],
[ 7800, null ],
[ 8200, null ],
[ 9000, null ],
[ 12008, null ]
]
],
. . .
If oracledb.outFormat
is oracledb.OUT_FORMAT_OBJECT
,
then each row in the sub-array is an object, for example with:
result = await connection.execute(sql, [], {outFormat: oracledb.OUT_FORMAT_OBJECT});
Output will be:
[
{
DEPARTMENT_NAME: 'Accounting',
NC: [
{ SALARY: 8300, COMMISSION_PCT: null },
{ SALARY: 12008, COMMISSION_PCT: null }
]
},
{
DEPARTMENT_NAME: 'Administration',
NC: [ { SALARY: 4400, COMMISSION_PCT: null } ]
},
. . .
The values of oracledb.maxRows
, and
oracledb.fetchArraySize
used when executing the
top-level query also apply to each nested cursor that is fetched. The
oracledb.fetchAsBuffer
and
oracledb.fetchAsString
values are also used.
The total number of cursors open is constrained by the OPEN_CURSORS
initialization parameter of the database. With the query above, where
each row contains a single nested cursor, and when
fetchArraySize
is 100 (the default), then 101 cursors
will be open at a time. One cursor is required for the top level query and one
cursor is required for each of the 100 rows internally fetched at a time.
If the connection.execute()
option resultSet
is set to
true, or when using connection.queryStream()
, then each
nested cursor in a fetched row is returned as a ResultSet
object. You can recursively call resultSet.getRow()
,
resultSet.getRows()
, or
resultSet.toQueryStream()
on the ResultSet to fetch each
nested cursor’s data. You should not concurrently fetch data from nested
cursors in different data rows because this may give inconsistent results.
For example:
async function traverseResults(resultSet) {
const fetchedRows = [];
while (true) {
const row = await resultSet.getRow();
if (!row)
break;
for (let i = 0; i < row.length; i++) {
if (row[i] instanceof oracledb.ResultSet) {
const rs = row[i];
row[i] = await traverseResults(rs); // replace a cursor with its expansion
await rs.close();
}
}
fetchedRows.push(row);
}
return fetchedRows;
}
const sql = `SELECT department_name,
CURSOR(SELECT salary, commission_pct
FROM employees e
WHERE e.department_id = d.department_id
ORDER BY salary) as nc
FROM departments d
ORDER BY department_name`;
const result = await connection.execute(sql, [], { resultSet: true });
const rows = await traverseResults(result.resultSet);
await result.resultSet.close();
console.dir(rows, {depth: null});
Output is the same as the previous non-resultSet example.
Each ResultSet should be closed when it is no longer needed.
The column names of a query are returned in the execute()
callback’s
result.metaData
attribute:
const result = await connection.execute(
`SELECT department_id, department_name
FROM departments
WHERE manager_id < :id`,
[110] // bind value for :id
);
console.dir(result.metaData, { depth: null }); // show the metadata
When using a ResultSet, metadata is also available
in result.resultSet.metaData
. For queries using
queryStream()
, metadata is available via the
metadata
event.
The metadata is an array of objects, one per column. By default each
object has a name
attribute:
[ { name: 'DEPARTMENT_ID' }, { name: 'DEPARTMENT_NAME' } ]
The names are in uppercase. This is the default casing behavior for Oracle client programs when a database table is created with unquoted, case-insensitive column names.
More metadata is included when the
oracledb.extendedMetaData
or
connection.execute()
option
extendedMetaData
is true. For
example:
const result = await connection.execute(
`SELECT department_id, department_name
FROM departments
WHERE manager_id < :id`,
[110], // bind value for :id
{ extendedMetaData: true }
);
console.dir(result.metaData, { depth: null }); // show the extended metadata
The output is:
[ { name: 'DEPARTMENT_ID',
fetchType: 2002,
dbType: 2,
precision: 4,
scale: 0,
nullable: false },
{ name: 'DEPARTMENT_NAME',
fetchType: 2001,
dbType: 1,
byteSize: 30,
nullable: false } ]
Description of the properties is given in the
result.metaData
description.
Also see connection.getStatementInfo()
.
Oracle number, date, character, ROWID, UROWID, LONG and LONG RAW column types are selected as Numbers, Dates, Strings, or Buffers. BLOBs and CLOBs are selected into Lobs by default.
The default mapping for some types can be changed using
fetchAsBuffer
, or
fetchAsString
. The
fetchInfo
property can also be used to change
the default mapping, or override a global mapping, for individual
columns.
Data types in SELECT
statements that are unsupported give an error
NJS-010: unsupported data type in select list. These include
INTERVAL, BFILE and XMLType types.
Details are in the following sections.
Columns of database type CHAR, VARCHAR2, NCHAR and NVARCHAR are returned from queries as JavaScript strings.
By default all numeric columns are mapped to JavaScript numbers. Node.js uses double floating point numbers as its native number type.
When numbers are fetched from the database, conversion to JavaScript’s less precise binary number format can result in “unexpected” representations. For example:
const result = await connection.execute(`SELECT 38.73 FROM dual`);
console.log(result.rows[0]); // gives 38.730000000000004
Similar issues can occur with binary floating-point arithmetic purely in Node.js, for example:
console.log(0.2 + 0.7); // gives 0.8999999999999999
Node.js can also only represent numbers up to 2 ^ 53 which is 9007199254740992. Numbers larger than this will be truncated.
The primary recommendation for number handling is to use Oracle SQL or PL/SQL for mathematical operations, particularly for currency calculations.
To reliably work with numbers in Node.js, use fetchAsString
or
fetchInfo
(see below) to fetch numbers in
string format, and then use one of the available third-party
JavaScript number libraries that handles large values and more
precision.
By default, date and timestamp columns are mapped to JavaScript Date objects. Internally, DATE, TIMESTAMP, TIMESTAMP WITH LOCAL TIME ZONE, and TIMESTAMP WITH TIME ZONE columns are fetched as TIMESTAMP WITH LOCAL TIME ZONE using the session time zone. Oracle INTERVAL types are not supported.
Note that JavaScript Date has millisecond precision therefore timestamps will lose any sub-millisecond fractional part when fetched.
To make applications more portable, it is recommended to always set the session
time zone to a pre-determined value, such as UTC. The session time zone should
generally match the client system time zone, for example the TZ
environment
variable or the Windows time zone region.
You can find the current session time zone with:
SELECT sessiontimezone FROM DUAL;
You can set the environment variable ORA_SDTZ
before starting Node.js,
for example:
$ export ORA_SDTZ='UTC'
$ node myapp.js
If this variable is set in the application, it must be set before the first connection is established:
process.env.ORA_SDTZ = 'UTC';
const oracledb = require('oracledb');
const connection = await oracledb.getConnection(. . . );
The session time zone can also be changed at runtime for each connection by executing:
await connection.execute(`ALTER SESSION SET TIME_ZONE='UTC'`);
With pooled connections, you could make use of a
sessionCallback
function to
minimize the number of times the ALTER SESSION needs to be executed.
To set the time zone without requiring the overhead of a
round-trip to execute the ALTER
statement, you could
use a PL/SQL trigger:
CREATE OR REPLACE TRIGGER my_logon_trigger
AFTER LOGON
ON hr.SCHEMA
BEGIN
EXECUTE IMMEDIATE 'ALTER SESSION SET TIME_ZONE=''UTC''';
END;
A query that returns the node-oracledb client-side date and timestamp is:
oracledb.fetchAsString = [oracledb.DATE];
result = await connection.execute(`SELECT current_date, current_timestamp FROM DUAL`);
console.log(result);
For more information on time zones, see Oracle Support’s Timestamps & time zones - Frequently Asked Questions, Doc ID 340512.1. Also see Working with Dates Using the Node.js Driver.
The global fetchAsString
property can be used to force
all number or date columns (and CLOB columns) queried by an
application to be fetched as strings instead of in native format. Allowing data
to be fetched as strings helps avoid situations where using JavaScript types can
lead to numeric precision loss, or where date conversion is unwanted. This
method can be used for CLOBs up to 1 GB in length.
For example, to force all dates and numbers used by queries in an application to be fetched as strings:
const oracledb = require('oracledb');
oracledb.fetchAsString = [ oracledb.DATE, oracledb.NUMBER ];
For dates and numbers, the maximum length of a string created can be 200 bytes.
Individual queries can use the execute()
option
fetchInfo
to map individual number or date
columns to strings without affecting other columns or other queries.
Any global fetchAsString
setting can be overridden to allow specific
columns to have data returned in native format:
const oracledb = require('oracledb');
const mypw = ... // set mypw to the hr schema password
oracledb.fetchAsString = [ oracledb.NUMBER ]; // any number queried will be returned as a string
const connection = await oracledb.getConnection(
{
user : "hr",
password : mypw,
connectString : "localhost/XEPDB1"
}
);
const result = await connection.execute(
`SELECT last_name, hire_date, salary, commission_pct FROM employees WHERE employee_id = :id`,
[178],
{
fetchInfo :
{
"HIRE_DATE": { type : oracledb.STRING }, // return the date as a string
"COMMISSION_PCT": { type : oracledb.DEFAULT } // override oracledb.fetchAsString and fetch as native type
}
}
);
console.log(result.rows);
The output is:
[ [ 'Grant', '24-MAY-07', '7000', 0.15 ] ]
The date and salary columns are returned as strings, but the
commission is a number. The date is mapped using the current session
date format, which was DD-MON-YY
in this example. The default date
format can be set, for example, with the environment variable
NLS_DATE_FORMAT
. Note this variable will only be read if NLS_LANG
is also set.
Without the mapping capabilities provided by fetchAsString
and
fetchInfo
the hire date would have been a JavaScript date in the
local time zone, and both numeric columns would have been represented
as numbers:
[ [ 'Grant', Thu May 24 2007 00:00:00 GMT+1000 (AEST), 7000, 0.15 ] ]
To map columns returned from REF CURSORS, use fetchAsString
. The
fetchInfo
settings do not apply.
When using fetchAsString
or fetchInfo
for numbers, you may need to
explicitly use NLS_NUMERIC_CHARACTERS
to override your NLS settings
and force the decimal separator to be a period. This can be done for
each connection by executing the statement:
await connection.execute(`ALTER SESSION SET NLS_NUMERIC_CHARACTERS = '.,'`);
Alternatively you can set the equivalent environment variable prior to starting Node.js:
$ export NLS_NUMERIC_CHARACTERS='.,'
Note this environment variable is not used unless the NLS_LANG
environment variable is also set.
By default BLOB, CLOB and NCLOB columns are fetched into Lob
instances. For LOBs less than 1 GB in length it can be more efficient and
convenient to fetch them directly into Buffers or Strings by using the global
fetchAsBuffer
or
fetchAsString
settings, or the per-column
fetchInfo
setting. See the section Working with CLOB,
NCLOB and BLOB Data.
LONG columns in queries will be fetched as Strings. LONG RAW columns will be fetched as Buffers.
Unlike for LOBs, there is no support for streaming LONG types. Oracle
Database allows values 2 GB in length, but Node.js and V8 memory
limitations typically only allow memory chunks in the order of tens of
megabytes. This means complete data may not be able to fetched from
the database. The SQL function TO_LOB
can be used to migrate
data to LOB columns which can be streamed to node-oracledb, however
TO_LOB
cannot be used directly in a SELECT
.
Queries will return ROWID and UROWID columns as Strings.
XMLType
columns queried will returns as Strings. They can also be
handled as CLOBs, see Working with XMLType.
Queries will return RAW columns as Node.js Buffers.
See Oracle Database Objects and Collections.
Query data is commonly broken into one or more sets:
To give an upper bound on the number of rows that a query has to process, which can help improve database scalability.
To perform ‘Web pagination’ that allows moving from one set of rows to a next, or previous, set on demand.
For fetching of all data in consecutive small sets for batch processing. This happens because the number of records is too large for Node.js to handle at the same time.
The latter can be handled by ResultSets or
queryStream()
with one execution of the SQL query as
discussed in those links.
‘Web pagination’ and limiting the maximum number of rows are discussed in this section. For each ‘page’ of results, a SQL query is executed to get the appropriate set of rows from a table. Since the query will be executed more than once, make sure to use bind variables for row numbers and row limits.
Oracle Database 12c SQL introduced an OFFSET
/ FETCH
clause which
is similar to the LIMIT
keyword of MySQL. See Row Limiting:
Examples in the Oracle documentation. A node-oracledb example is:
const myoffset = 0; // do not skip any rows (start at row 1)
const mymaxnumrows = 20; // get 20 rows
const result = await connection.execute(
`SELECT last_name
FROM employees
ORDER BY last_name
OFFSET :offset ROWS FETCH NEXT :maxnumrows ROWS ONLY`,
{ offset: myoffset, maxnumrows: mymaxnumrows },
{ prefetchRows: mymaxnumrows + 1, fetchArraySize: mymaxnumrows }
);
A runnable example is in rowlimit.js.
You can use a basic execute()
or a
ResultSet, or queryStream()
with
your query. For basic execute()
fetches, make sure that
oracledb.maxRows
is greater than the value bound to :maxnumrows
,
or set to 0 (meaning unlimited).
In applications where the SQL query is not known in advance, this
method sometimes involves appending the OFFSET
clause to the ‘real’
user query. Be very careful to avoid SQL injection security issues.
As an anti-example, another way to limit the number of rows returned
involves setting maxRows
. However it is more
efficient to let Oracle Database do the row selection in the SQL query
and only return the exact number of rows required to node-oracledb.
For Oracle Database 11g and earlier there are several alternative ways to limit the number of rows returned. The old, canonical paging query is:
SELECT *
FROM (SELECT a.*, ROWNUM AS rnum
FROM (YOUR_QUERY_GOES_HERE -- including the order by) a
WHERE ROWNUM <= MAX_ROW)
WHERE rnum >= MIN_ROW
Here, MIN_ROW
is the row number of first row and MAX_ROW
is the
row number of the last row to return. For example:
SELECT *
FROM (SELECT a.*, ROWNUM AS rnum
FROM (SELECT last_name FROM employees ORDER BY last_name) a
WHERE ROWNUM <= 20)
WHERE rnum >= 1
This always has an ‘extra’ column, here called RNUM.
An alternative and preferred query syntax for Oracle Database 11g uses
the analytic ROW_NUMBER()
function. For example to get the 1st to
20th names the query is:
SELECT last_name FROM
(SELECT last_name,
ROW_NUMBER() OVER (ORDER BY last_name) AS myr
FROM employees)
WHERE myr BETWEEN 1 and 20
Refer to On Top-n and Pagination Queries in Oracle Magazine for details. Also review the videos SQL for pagination queries - memory and performance and SQL for pagination queries - advanced options.
From Oracle Database 12c you can create tables with auto-incremented values. This is useful to generate unique primary keys for your data when ROWID or UROWID are not preferred.
In SQL*Plus execute:
CREATE TABLE mytable
(myid NUMBER(11) GENERATED BY DEFAULT ON NULL AS IDENTITY (START WITH 1),
mydata VARCHAR2(20)
)
Refer to the CREATE TABLE identity column documentation.
If you already have a sequence myseq
you can use values from it to
auto-increment a column value like this:
CREATE TABLE mytable
(myid NUMBER DEFAULT myseq.NEXTVAL,
mydata VARCHAR2(20)
)
This also requires Oracle Database 12c or later.
Prior to Oracle Database 12c, auto-increment columns in Oracle Database can be created using a sequence generator and a trigger.
Sequence generators are defined in the database and return Oracle numbers. Sequence numbers are generated independently of tables. Therefore, the same sequence generator can be used for more than one table or anywhere that you want to use a unique number. You can get a new value from a sequence generator using the NEXTVAL operator in a SQL statement. This gives the next available number and increments the generator. The similar CURRVAL operator returns the current value of a sequence without incrementing the generator.
A trigger is a PL/SQL procedure that is automatically invoked at a predetermined point. In this example a trigger is invoked whenever an insert is made to a table.
In SQL*Plus run:
CREATE SEQUENCE myseq;
CREATE TABLE mytable (myid NUMBER PRIMARY KEY, mydata VARCHAR2(20));
CREATE TRIGGER mytrigger BEFORE INSERT ON mytable FOR EACH ROW
BEGIN
:new.myid := myseq.NEXTVAL;
END;
/
Prior to Oracle Database 11g replace the trigger assignment with a SELECT like:
SELECT myseq.NEXTVAL INTO :new.myid FROM dual;
To get the automatically inserted identifier in node-oracledb, use a DML RETURNING clause:
. . .
const result = await connection.execute(
`INSERT INTO mytable (mydata) VALUES ('Hello') RETURN myid INTO :id`,
{id : {type: oracledb.NUMBER, dir: oracledb.BIND_OUT } }
);
console.log(result.outBinds.id); // print the ID of the inserted row
A cursor is a “handle for the session-specific private SQL area that holds a parsed SQL statement and other processing information”. If your application returns the error ORA-1000: maximum open cursors exceeded here are possible solutions:
Avoid having too many incompletely processed statements open at one time:
Make sure your application is handling connections and statements in the order you expect.
Close ResultSets before releasing the connection.
If cursors are opened with DBMS_SQL.OPEN_CURSOR()
in a PL/SQL
block, close them before the block returns - except for REF
CURSORs being passed back to node-oracledb.
Choose the appropriate Statement Cache size. Node-oracledb has a statement cache per connection. When node-oracledb internally releases a statement it will be put into the statement cache of that connection, and its cursor will remain open. This makes statement re-execution very efficient.
The cache size is settable with the
oracle.stmtCacheSize
attribute. The size
you choose will depend on your knowledge of the locality of the
statements, and of the resources available to the application. Are
statements re-executed? Will they still be in the cache when they
get executed? How many statements do you want to be cached? In
rare cases when statements are not re-executed, or are likely not to
be in the cache, you might even want to disable the cache to
eliminate its management overheads.
Incorrectly sizing the statement cache will reduce application efficiency.
To help set the cache size, you can turn on auto-tuning with Oracle
12.1, or later, using an oraaccess.xml
file.
For more information, see the Statement Caching documentation.
Use bind variables otherwise each variant of the statement will have its own statement cache entry and cursor. With appropriate binding only one entry and cursor will be needed.
Set the database’s open_cursors parameter appropriately. This parameter specifies the maximum number of cursors that each “session” (i.e each node-oracledb connection) can use. When a connection exceeds the value, the ORA-1000 error is thrown.
Along with a cursor per entry in the connection’s statement cache, any new statements that a connection is currently executing, or ResultSets that have not been released (in neither situation are these yet cached), will also consume a cursor. Make sure that open_cursors is large enough to accommodate the maximum open cursors any connection may have. The upper bound required is the sum of stmtCacheSize and the maximum number of executing statements in a connection.
Remember this is all per connection. Also cache management happens when statements are internally released. The majority of your connections may use less than open_cursors cursors, but if one connection is at the limit and it then tries to execute a new statement, that connection will get ORA-1000.
PL/SQL stored procedures, functions and anonymous blocks can be called
from node-oracledb using execute()
.
Note the error property of the callback is not set when PL/SQL “success with info” warnings such as compilation warnings occur.
The PL/SQL procedure:
CREATE OR REPLACE PROCEDURE myproc (id IN NUMBER, name OUT VARCHAR2) AS
BEGIN
SELECT last_name INTO name FROM employees WHERE employee_id = id;
END;
can be called:
const result = await connection.execute(
`BEGIN
myproc(:id, :name);
END;`,
{ // bind variables
id: 159,
name: { dir: oracledb.BIND_OUT, type: oracledb.STRING, maxSize: 40 },
}
);
console.log(result.outBinds);
The output is:
{ name: 'Smith' }
Binding is required for IN OUT and OUT parameters. It is strongly recommended for IN parameters. See Bind Parameters for Prepared Statements.
The PL/SQL function:
CREATE OR REPLACE FUNCTION myfunc RETURN VARCHAR2 AS
BEGIN
RETURN 'Hello';
END;
can be called by using an OUT bind variable for the function return value:
const result = await connection.execute(
`BEGIN
:ret := myfunc();
END;`,
{
ret: { dir: oracledb.BIND_OUT, type: oracledb.STRING, maxSize: 40 }
}
);
console.log(result.outBinds);
The output is:
{ ret: 'Hello' }
See Bind Parameters for Prepared Statements for information on binding.
Anonymous PL/SQL blocks can be called from node-oracledb like:
const result = await connection.execute(
`BEGIN
SELECT last_name INTO :name FROM employees WHERE employee_id = :id;
END;`,
{ // bind variables
id: 134,
name: { dir: oracledb.BIND_OUT, type: oracledb.STRING, maxSize: 40 },
}
);
console.log(result.outBinds);
The output is:
{ name: 'Rogers' }
See Bind Parameters for Prepared Statements for information on binding.
The DBMS_OUTPUT package is the standard way to “print” output
from PL/SQL. The way DBMS_OUTPUT works is like a buffer. Your
Node.js application code must first turn on DBMS_OUTPUT buffering for
the current connection by calling the PL/SQL procedure
DBMS_OUTPUT.ENABLE(NULL)
. Then any PL/SQL executed by the
connection can put text into the buffer using
DBMS_OUTPUT.PUT_LINE()
. Finally DBMS_OUTPUT.GET_LINE()
is used to
fetch from that buffer. Note, any PL/SQL code that uses DBMS_OUTPUT
runs to completion before any output is available to the user. Also,
other database connections cannot access your buffer.
A basic way to fetch DBMS_OUTPUT with node-oracledb is to bind an
output string when calling the PL/SQL DBMS_OUTPUT.GET_LINE()
procedure, print the string, and then repeat until there is no more
data. The following snippet is based on the example
dbmsoutputgetline.js:
let result;
do {
result = await connection.execute(
`BEGIN
DBMS_OUTPUT.GET_LINE(:ln, :st);
END;`,
{ ln: { dir: oracledb.BIND_OUT, type: oracledb.STRING, maxSize: 32767 },
st: { dir: oracledb.BIND_OUT, type: oracledb.NUMBER }
}
);
if (result.outBinds.st === 0)
console.log(result.outBinds.ln);
} while (result.outBinds.st === 0);
Another way is to wrap the DBMS_OUTPUT.GET_LINE()
call into a
pipelined function and fetch the output using a SQL query. See
dbmsoutputpipe.js for the full example.
The pipelined function could be created like:
CREATE OR REPLACE TYPE dorow AS TABLE OF VARCHAR2(32767);
/
CREATE OR REPLACE FUNCTION mydofetch RETURN dorow PIPELINED IS
line VARCHAR2(32767);
status INTEGER;
BEGIN LOOP
DBMS_OUTPUT.GET_LINE(line, status);
EXIT WHEN status = 1;
PIPE ROW (line);
END LOOP;
END;
/
To get DBMS_OUTPUT, simply query this function using the same connection that created the output:
const result = await connection.execute(
`SELECT * FROM TABLE(mydofetch())`,
[],
{ resultSet: true }
);
const rs = result.resultSet;
let row;
while ((row = await rs.getRow())) {
console.log(row);
}
The query rows in this example are handled using a ResultSet.
Remember to first enable output using DBMS_OUTPUT.ENABLE(NULL)
.
The Edition-Based Redefinition (EBR) feature of Oracle Database allows multiple versions of views, synonyms, PL/SQL objects and SQL Translation profiles to be used concurrently. Each items version is associated with an ‘edition’ which can be nominated at runtime by applications. This lets database logic be updated and tested while production users are still accessing the original version. Once every user has begun using the objects in the new edition, the old objects can be dropped.
To choose the edition, node-oracledb applications can set
oracledb.edition
globally, or specify a value when
creating a pool
or a standalone
connection
.
The example below shows how a PL/SQL function DISCOUNT
can be
created with two different implementations. The initial procedure is
created as normal in the SQL*Plus command line:
CONNECT nodedemo/welcome
-- The default edition's DISCOUNT procedure
CREATE OR REPLACE FUNCTION discount(price IN NUMBER) RETURN NUMBER
AS
newprice NUMBER;
BEGIN
newprice := price - 4;
IF (newprice < 1) THEN
newprice := 1;
END IF;
RETURN newprice;
END;
/
This initial implementation is in the default ‘edition’ ora$base
,
which is pre-created in new and upgraded databases.
The user nodedemo
can be given permission to create new ‘editions’:
CONNECT system
GRANT CREATE ANY EDITION TO nodedemo;
ALTER USER nodedemo ENABLE EDITIONS FORCE;
The next SQL*Plus script creates a new edition e2
, and changes the
current session to use it. A new version of DISCOUNT
is created
under that edition:
CONNECT nodedemo/welcome
CREATE EDITION e2;
ALTER SESSION SET EDITION = e2;
-- E2 edition's discount
CREATE OR REPLACE FUNCTION discount(price IN NUMBER) RETURN NUMBER
AS
newprice NUMBER;
BEGIN
newprice := 0.75 * price;
RETURN newprice;
END;
/
There are now two implementations of the PL/SQL procedure DISCOUNT
with the same prototype. Applications can choose at runtime which
implementation to use. Here is a script that calls DISCOUNT
:
const mypw = ... // set mypw to the nodedemo schema password
const connection = await oracledb.getConnection(
{
user: 'nodedemo',
password: mypw,
connectString: 'localhost/orclpdb1'
}
);
const result = await connection.execute(
`SELECT name, price, DISCOUNT(price) AS discountprice
FROM parts
ORDER BY id`,
[],
{ outFormat: oracledb.OUT_FORMAT_OBJECT }
);
console.log(result.rows);
Since the code does not explicitly set oracledb.edition
(or
equivalent), then the first implementation of DISCOUNT
in the
default edition is used. The output might be like:
[ { NAME: 'lamp', PRICE: 40, DISCOUNTPRICE: 36 },
{ NAME: 'wire', PRICE: 10, DISCOUNTPRICE: 6 },
{ NAME: 'switch', PRICE: 4, DISCOUNTPRICE: 1 } ]
If the connection uses edition e2
, then the second implementation of
DISCOUNT
will be used:
const connection = await oracledb.getConnection(
{
user: 'nodedemo',
password: mypw, // mypw contains the nodedemo schema password
connectString: 'localhost/orclpdb1',
edition: 'e2'
}
);
. . . // same query code as before
The output might be like:
[ { NAME: 'lamp', PRICE: 40, DISCOUNTPRICE: 30 },
{ NAME: 'wire', PRICE: 10, DISCOUNTPRICE: 7.5 },
{ NAME: 'switch', PRICE: 4, DISCOUNTPRICE: 3 } ]
See the Database Development Guide chapter Using Edition-Based Redefinition for more information about EBR.
Oracle Implicit Results allow queries in PL/SQL to be returned to Node.js without requiring REF CURSORS or bind variables. Implicit Results requires node-oracledb 4.0, Oracle Database 12.1 or later, and Oracle Client 12.1 or later.
PL/SQL code uses DBMS_SQL.RETURN_RESULT()
to return query results.
These are accessible in the execute()
callback
implicitResults
attribute.
For example:
const plsql = `
DECLARE
c1 SYS_REFCURSOR;
c2 SYS_REFCURSOR;
BEGIN
OPEN c1 FOR SELECT city, postal_code
FROM locations
WHERE location_id < 1200;
DBMS_SQL.RETURN_RESULT(c1);
OPEN C2 FOR SELECT job_id, employee_id, last_name
FROM employees
WHERE employee_id < 103;
DBMS_SQL.RETURN_RESULT(c2);
END;`;
result = await connection.execute(plsql);
console.log(result.implicitResults);
will display:
[
[
[ 'Roma', '00989' ],
[ 'Venice', '10934' ],
],
[
[ 'AD_PRES', 100, 'King' ],
[ 'AD_VP', 101, 'Kochhar' ],
[ 'AD_VP', 102, 'De Haan' ],
]
]
For larger query results, fetching ResultSets is recommended:
result = await connection.execute(plsql, [], { resultSet: true });
for (const i = 0; i < result.implicitResults.length; i++) {
console.log(" Implicit Result Set", i + 1);
const rs = result.implicitResults[i]; // get the next ResultSet
let row;
while ((row = await rs.getRow())) {
console.log(" ", row);
}
console.log();
await rs.close();
}
This displays:
Implicit Result Set 1
[ 'Roma', '00989' ]
[ 'Venice', '10934' ]
Implicit Result Set 2
[ 'AD_PRES', 100, 'King' ]
[ 'AD_VP', 101, 'Kochhar' ]
[ 'AD_VP', 102, 'De Haan' ]
A runnable example is in impres.js.
Oracle Database uses LOB data types to store long objects. The CLOB type is used for character data and the BLOB type is used for binary data. NCLOB can hold character data in the database’s alternative national character set. In node-oracledb, LOBs can be represented by instances of the Lob class or as Strings and Buffers.
There are runnable LOB examples in the GitHub examples directory.
Node.js String or Buffer types can be passed into PL/SQL blocks or inserted into the database by binding to LOB columns or PL/SQL parameters.
Given the table:
CREATE TABLE mylobs (id NUMBER, c CLOB, b BLOB);
an INSERT
example is:
const fs = require('fs');
const str = fs.readFileSync('example.txt', 'utf8');
. . .
const result = await connection.execute(
`INSERT INTO mylobs (id, myclobcol) VALUES (:idbv, :cbv)`,
{ idbv: 1, cbv: str } // type and direction are optional for IN binds
);
console.log('CLOB inserted from example.txt');
. . .
Updating LOBs is similar to insertion:
const result = await connection.execute(
`UPDATE mylobs SET myclobcol = :cbv WHERE id = :idbv`,
{ idbv: 1, cbv: str }
);
Buffers can similarly be bound for inserting into, or updating, BLOB columns.
When binding Strings to NCLOB columns, explicitly specify the bind
type
as
oracledb.DB_TYPE_NVARCHAR
:
const result = await connection.execute(
`UPDATE mylobs SET mynclobcol = :ncbv WHERE id = :idbv`,
{ idbv: 1, ncbv: { type: oracledb.DB_TYPE_NVARCHAR, val: str } }
);
When using PL/SQL, a procedure:
PROCEDURE lobs_in (p_id IN NUMBER, c_in IN CLOB, b_in IN BLOB) . . .
can be called like:
const bigStr = 'My string to insert';
const bigBuf = Buffer.from([. . .]);
const result = await connection.execute(
`BEGIN lobs_in(:id, :c, :b); END;`,
{ id: 20,
c: bigStr, // type and direction are optional for CLOB and BLOB IN binds
b: bigBuf }
}
);
See LOB Bind Parameters for size considerations regarding LOB binds.
If the data is larger than can be handled as a String or Buffer in Node.js or node-oracledb, it will need to be streamed to a Lob, as discussed in Streaming Lobs.
LOBs queried from the database that are shorter than 1 GB can be returned as
Strings or Buffers by using oracledb.fetchAsString
or
oracledb.fetchAsBuffer
(or
fetchInfo
). If the data is larger than can be handled
as a String or Buffer in Node.js or node-oracledb, it will need to be streamed
from a Lob, as discussed later in Streaming
Lobs.
For example, to make every CLOB and NCLOB queried by the application be returned as a string:
oracledb.fetchAsString = [ oracledb.CLOB ];
const result = await connection.execute(`SELECT c FROM mylobs WHERE id = 1`);
if (result.rows.length === 0)
console.error("No results");
else {
const clob = result.rows[0][0];
console.log(clob);
}
CLOB columns in individual queries can be fetched as strings using
fetchInfo
:
const result = await connection.execute(
`SELECT c FROM mylobs WHERE id = 1`,
[], // no binds
{ fetchInfo: {"C": {type: oracledb.STRING}} }
);
if (result.rows.length === 0) {
console.error("No results");
}
else {
const clob = result.rows[0][0];
console.log(clob);
}
BLOB query examples are very similar. To force every BLOB in the application to be returned as a buffer:
oracledb.fetchAsBuffer = [ oracledb.BLOB ];
const result = await connection.execute(`SELECT b FROM mylobs WHERE id = 2`);
if (result.rows.length === 0)
console.error("No results");
else {
const blob = result.rows[0][0];
console.log(blob.toString()); // assuming printable characters
}
BLOB columns in individual queries can be fetched as buffers using
fetchInfo
:
const result = await connection.execute(
`SELECT b FROM mylobs WHERE id = 2`,
[ ], // no binds
{ fetchInfo: {"B": {type: oracledb.BUFFER}} }
);
if (result.rows.length === 0) {
console.error("No results");
} else {
const blob = result.rows[0][0];
console.log(blob.toString()); // assuming printable characters
}
To get PL/SQL LOB OUT parameters as String or Buffer, set the bind type
as:
oracledb.STRING
for CLOBoracledb.DB_TYPE_NVARCHAR
for NCLOBoracledb.BUFFER
for BLOBconst result = await connection.execute(
`BEGIN lobs_out(:id, :c, :b); END;`,
{ id: 20,
c: {type: oracledb.STRING, dir: oracledb.BIND_OUT, maxSize: 50000},
b: {type: oracledb.BUFFER, dir: oracledb.BIND_OUT, maxSize: 50000}
}
);
const str = result.outBinds.c; // a String
const buf = result.outBinds.b; // a Buffer
. . . // do something with str and buf
The fetched String and Buffer can be used directly in Node.js.
If data to be bound is larger than can be handled as a String or Buffer in Node.js or node-oracledb, it will need to be explicitly streamed to a Lob, as discussed in Streaming Lobs. See LOB Bind Parameters for size considerations regarding LOB binds.
The Lob Class in node-oracledb implements the Node.js Stream interface to provide streaming access to CLOB, NCLOB and BLOB database columns and to PL/SQL bind parameters.
Node-oracledb Lobs can represent persistent LOBs (those permanently
stored in the database) or temporary LOBs (such as those created with
connection.createLob()
, or returned from
some SQL or PL/SQL).
If multiple LOBs are streamed concurrently, worker threads will effectively be serialized on the connection.
It is the application’s responsibility to make sure the connection
remains open while a Stream operation such as pipe()
is in progress.
Being a Stream object, a Lob being read from the database has two
modes of operation: “flowing mode” and “paused mode”. In flowing
mode, data is piped to another stream, or events are posted as data is
read. In paused mode the application must explicitly call read()
to
get data.
The read(size)
unit is in bytes for BLOBs, and characters for CLOBs and
NCLOBs.
When reading a LOB from the database, resources are automatically released at
completion of the readable stream or if there is a LOB error. The
lob.destroy()
method can also be used to close persistent LOBs
that have not been streamed to completion.
A Readable Lob object starts out in paused mode. If a data
event
handler is added, or the Lob is piped to a Writeable stream, then the
Lob switches to flowing mode.
For unpiped Readable Lobs operating in flowing mode where the Lob is
read through event handlers, the Lob object can be switched to paused
mode by calling pause()
. Once the Lob is in paused mode, it stops
emitting data
events.
Similarly, a Readable Lob operating in the paused mode can be switched
to flowing mode by calling resume()
. It will then start emitting
data
events again.
Lobs are written to with pipe()
. Alternatively the write()
method
can be called successively, with the last piece being written by the
end()
method. The end()
method must be called because it frees
resources. If the Lob is being piped into, then the write()
and
end()
methods are automatically called.
Writeable Lobs also have events, see the Node.js Stream documentation.
At the conclusion of streaming into a Writeable Lob, the finish
event will
occur. It is recommended to put logic such as committing and releasing
connections in this event (or after it occurs). See lobinsert2.js.
If Strings or Buffers are too large to be directly inserted into the
database (see Simple Insertion of LOBs), use a
RETURNING INTO
clause to retrieve a Lob for a table
item. Data can then be streamed into the Lob and committed directly
to the table:
const result = await connection.execute(
`INSERT INTO mylobs (id, c) VALUES (:id, EMPTY_CLOB()) RETURNING c INTO :lobbv`,
{ id: 4,
lobbv: {type: oracledb.CLOB, dir: oracledb.BIND_OUT} },
{ autoCommit: false } // a transaction needs to span the INSERT and pipe()
);
if (result.rowsAffected != 1 || result.outBinds.lobbv.length != 1) {
throw new Error('Error getting a LOB locator');
}
const doInsert = new Promise((resolve, reject) => {
const lob = result.outBinds.lobbv[0];
lob.on('finish', async () => {
await connection.commit(); // all data is loaded so we can commit it
});
lob.on('error', async (err) => {
await connection.close();
reject(err);
});
const inStream = fs.createReadStream('example.txt'); // open the file to read from
inStream.on('error', (err) => {
reject(err);
});
inStream.pipe(lob); // copies the text to the LOB
});
await doInsert;
This example streams from a file into the table. When the data has
been completely streamed, the Lob is automatically closed and the
close
event triggered. At this point the data can be committed.
See lobinsert2.js for the full example.
By default, when a SELECT
clause contains a LOB column, or a PL/SQL
OUT parameter returns a LOB, instances of Lob are
created. (This can be changed, see Simple LOB Queries and PL/SQL OUT
Binds.)
For each Lob instance, the lob.type
property will be
oracledb.BLOB
or
oracledb.CLOB
, depending on the column
or PL/SQL parameter type.
Returned Lobs can be used as Readable Streams. Data can be streamed from each Lob, for example to a file. At the conclusion of the stream, persistent LOBs are automatically closed.
Lobs returned from the database that are not streamed can be passed
back to the database as IN binds for PL/SQL blocks, for INSERT
, or
for UPDATE
statements. The Lobs should then be closed with
lob.destroy()
. If they are passed as IN OUT binds, they
will be automatically closed and the execution
outBinds
property will contain the updated Lob.
Each CLOB, NCLOB or BLOB in a SELECT
returns a Lob by default.
For example, the table:
CREATE TABLE mylobs (id NUMBER, c CLOB, b BLOB);
can be called to get a Lob clob
like:
const result = await connection.execute(`SELECT c FROM mylobs WHERE id = 1`);
if (result.rows.length === 1) {
const clob = result.rows[0][0]; // Instance of a node-oracledb Lob
// console.log(clob.type); // -> 2017 aka oracledb.CLOB
. . . // do something with the Lob
}
A PL/SQL procedure such as this:
PROCEDURE lobs_out (id IN NUMBER, clob_out OUT CLOB, blob_out OUT BLOB) . . .
can be called to get the Lobs clob
and blob
:
const result = await connection.execute(
`BEGIN lobs_out(:id, :c, :b); END;`,
{ id: 1,
c: {type: oracledb.CLOB, dir: oracledb.BIND_OUT},
b: {type: oracledb.BLOB, dir: oracledb.BIND_OUT}
}
);
const clob = result.outBinds.c;
const blob = result.outBinds.b;
. . . // do something with the Lobs
To bind a Lob object to an NCLOB parameter, set type
to oracledb.DB_TYPE_NCLOB
.
Once a Lob is obtained from a query or PL/SQL OUT bind, it can be streamed out:
if (lob === null) {
// . . . do special handling such as create an empty file or throw an error
}
if (lob.type === oracledb.CLOB) {
lob.setEncoding('utf8'); // set the encoding so we get a 'string' not a 'buffer'
}
lob.on('error', function(err) { cb(err); });
lob.on('end', function() { cb(null); }); // all done. The Lob is automatically closed.
const outStream = fs.createWriteStream('myoutput.txt');
outStream.on('error', function(err) { cb(err); });
// switch into flowing mode and push the LOB to myoutput.txt
lob.pipe(outStream);
Note the Lob is automatically closed at the end of the stream.
An alternative to the lob.pipe()
call is to have a data
event on
the Lob Stream which processes each chunk of LOB data separately.
Either a String or Buffer can be built up or, if the LOB is big, each
chunk can be written to another Stream or to a file:
if (lob === null) {
// . . . do special handling such as create an empty file or throw an error
}
let str = "";
lob.setEncoding('utf8'); // set the encoding so we get a 'string' not a 'buffer'
lob.on('error', function(err) { cb(err); });
lob.on('end', function() { cb(null); }); // all done. The Lob is automatically closed.
lob.on('data', function(chunk) {
str += chunk; // or use Buffer.concat() for BLOBS
});
lob.on('end', function() {
fs.writeFile(..., str, ...);
});
Node-oracledb’s lob.pieceSize
can be used to control the
number of bytes retrieved for each readable data
event. This sets the number
of bytes (for BLOBs) or characters (for CLOBs and NCLOBs). The default is
lob.chunkSize
. The recommendation is for it to be a
multiple of chunkSize
.
See lobbinds.js for a full example.
createLob()
for PL/SQL IN BindsNode-oracledb applications can create Oracle ‘temporary LOBs’ by
calling connection.createLob()
. These are
instances of the Lob class. They can be populated with
data and passed to PL/SQL blocks. This is useful if the data is
larger than feasible for direct binding (see Simple Insertion of
LOBs). These Lobs can also be used for SQL
statement IN binds, however the RETURNING INTO
method shown above
will be more efficient.
Lobs from createLob()
will use space in the temporary tablespace
until lob.destroy()
is called. Database Administrators
can track this usage by querying V$TEMPORARY_LOBS
.
The following insertion example is based on lobplsqltemp.js. It creates an empty LOB, populates it, and then passes it to a PL/SQL procedure.
A temporary LOB can be created with
connection.createLob()
:
const templob = await connection.createLob(oracledb.CLOB);
Once created, data can be inserted into it. For example to read a text file:
templob.on('error', function(err) { somecallback(err); });
// The data was loaded into the temporary LOB, so use it
templob.on('finish', function() { somecallback(null, templob); });
// copies the text from 'example.txt' to the temporary LOB
const inStream = fs.createReadStream('example.txt');
inStream.on('error', function(err) { . . . });
inStream.pipe(templob);
Now the LOB has been populated, it can be bound in somecallback()
to
a PL/SQL IN parameter:
// For PROCEDURE lobs_in (p_id IN NUMBER, c_in IN CLOB, b_in IN BLOB)
const result = await connection.execute(
`BEGIN lobs_in(:id, :c, null); END;`,
{ id: 3,
c: templob // type and direction are optional for IN binds
}
);
When the temporary LOB is no longer needed, it must be closed with
lob.destroy()
:
await templob.destroy();
Closing a Lob frees up resources. In particular, the temporary tablespace storage used by a temporary LOB is released. Once a Lob is closed, it can no longer be bound or used for streaming.
Lobs created with createLob()
should be
explicitly closed with lob.destroy()
.
Persistent or temporary Lobs returned from the database should be
closed with lob.destroy()
unless they have been automatically closed.
Automatic closing of returned Lobs occurs when:
Oracle Database 12.1.0.2 introduced native support for JSON data. You can use JSON with relational database features, including transactions, indexing, declarative querying, and views. You can project JSON data relationally, making it available for relational processes and tools. Also see node-oracledb’s SODA API, which allows access to JSON documents through a set of NoSQL-style APIs.
Prior to Oracle Database 21, JSON in relational tables is stored as BLOB, CLOB or VARCHAR2 data, allowing easy access with node-oracledb. Oracle Database 21 introduced a dedicated JSON data type with a new binary storage format that improves performance and functionality. To use the new dedicated JSON type, the Oracle Database and Oracle Client libraries must be version 21, or later. Also node-oracledb must be 5.1, or later.
For more information about using JSON in Oracle Database see the Database JSON Developer’s Guide.
In Oracle Database 21, to create a table with a column called PO_DOCUMENT
for
JSON data:
CREATE TABLE j_purchaseorder (po_document JSON);
For older Oracle Database versions the syntax is:
CREATE TABLE j_purchaseorder (po_document BLOB CHECK (po_document IS JSON));
The check constraint with the clause IS JSON
ensures only JSON data is
stored in that column.
The older syntax can still be used in Oracle Database 21, however the recommendation is to move to the new JSON type. With the old syntax, the storage can be BLOB, CLOB or VARCHAR2. Of these, BLOB is preferred to avoid character set conversion overheads.
Using Oracle Database 21 and Oracle Client 21 with node-oracledb 5.1 (or later),
you can insert JavaScript objects directly by binding as
oracledb.DB_TYPE_JSON
:
const data = { "userId": 1, "userName": "Chris", "location": "Australia" };
await connection.execute(
`INSERT INTO j_purchaseorder (po_document) VALUES (:bv)`,
{ bv: {val: data, type: oracledb.DB_TYPE_JSON} }
);
With the older BLOB storage, or to insert JSON strings:
const data = { "userId": 1, "userName": "Chris", "location": "Australia" };
const s = JSON.stringify(data); // change JavaScript value to a JSON string
const b = Buffer.from(s, 'utf8');
const result = await connection.execute(
`INSERT INTO j_purchaseorder (po_document) VALUES (:bv)`,
[b] // bind the JSON string
);
To query with Oracle Database 21 and Oracle Client 21, or later:
const r = await conn.execute(`SELECT po_document FROM j_purchaseorder`);
console.dir(r.rows, { depth: null });
The output is:
[
{
PO_DOCUMENT: '{"userId":1,"userName":"Chris","location":"Australia"}'
}
]
If node-oracledb uses Oracle Client Libraries 19 (or lower), querying an Oracle
Database 21 (or later) JSON column returns a Lob Class BLOB. You
can stream the Lob or use lob.getData()
:
const result = await connection.execute(`SELECT po_document FROM j_purchaseorder`);,
const lob = result.rows[0][0]; // just show first row
const d = await lob.getData();
const j = JSON.parse(d);
console.dir(j, { depth: null });
The output is:
{ userId: 1, userName: 'Chris', location: 'Australia' }
Note oracledb.fetchAsBuffer
will not automatically convert the Oracle Database
21c JSON type to a Buffer. Using it will give ORA-40569: Unimplemented JSON
feature. Use await lob.getData()
as shown.
When binding a JavaScript object as oracledb.DB_TYPE_JSON
for
oracledb.BIND_IN
or oracledb.BIND_INOUT
in Oracle Database 21 (or later),
JavaScript values are converted to JSON attributes as shown in the following
table. The ‘SQL Equivalent’ syntax can be used in SQL INSERT and UPDATE
statements if specific attribute types are needed but there is no direct mapping
from JavaScript.
JavaScript Type or Value | JSON Attribute Type or Value | SQL Equivalent Example |
---|---|---|
null | null | NULL |
undefined | null | n/a |
true | true | n/a |
false | false | n/a |
Number | NUMBER | json_scalar(1) |
String | VARCHAR2 | json_scalar('String') |
Date | TIMESTAMP | json_scalar(to_timestamp('2020-03-10', 'YYYY-MM-DD')) |
Buffer | RAW | json_scalar(utl_raw.cast_to_raw('A raw value')) |
Array | Array | json_array(1, 2, 3 returning json) |
Object | Object | json_object(key 'Fred' value json_scalar(5), key 'George' value json_scalar('A string') returning json) |
n/a | CLOB | json_scalar(to_clob('A short CLOB')) |
n/a | BLOB | json_scalar(to_blob(utl_raw.cast_to_raw('A short BLOB'))) |
n/a | DATE | json_scalar(to_date('2020-03-10', 'YYYY-MM-DD')) |
n/a | INTERVAL YEAR TO MONTH | json_scalar(to_yminterval('+5-9')) |
n/a | INTERVAL DAY TO SECOND | json_scalar(to_dsinterval('P25DT8H25M')) |
n/a | BINARY_DOUBLE | json_scalar(to_binary_double(25)) |
n/a | BINARY_FLOAT | json_scalar(to_binary_float(15.5)) |
An example of creating a CLOB attribute with key mydocument
in a JSON column
using SQL is:
const sql = `INSERT INTO mytab (myjsoncol)
VALUES (JSON_OBJECT(key 'mydocument' value JSON_SCALAR(TO_CLOB(:b)) RETURNING JSON))`;
await connection.execute(sql, ['A short CLOB']);
When mytab
is queried in node-oracledb, the CLOB data will be returned as a
JavaScript String, as shown by the following table. Output might be like:
{ mydocument: 'A short CLOB' }
When getting Oracle Database 21 JSON values from the database, the following attribute mapping occurs:
Database JSON Attribute Type or Value | JavaScript Type or Value |
---|---|
null | null |
false | false |
true | true |
NUMBER | Number |
VARCHAR2 | String |
RAW | Buffer |
CLOB | String |
BLOB | Buffer |
DATE | Date |
TIMESTAMP | Date |
INTERVAL YEAR TO MONTH | Not supported. Will give an error. |
INTERVAL DAY TO SECOND | Not supported. Will give an error. |
BINARY_DOUBLE | Number |
BINARY_FLOAT | Number |
Arrays | Array |
Objects | A plain JavaScript Object |
Oracle Database provides SQL access to JSON data using SQL/JSON path
expressions. A path expression selects zero or more JSON values that match, or
satisfy, it. Path expressions can use wildcards and array ranges. A simple
path expression is $.friends
which is the value of the JSON field friends
.
For example, the previously created j_purchaseorder
table with JSON column
po_document
can be queried like:
SELECT po.po_document.location FROM j_purchaseorder po
With the JSON '{"userId":1,"userName":"Chris","location":"Australia"}'
stored
in the table, a queried value would be Australia
.
The JSON_EXISTS
function tests for the existence of a particular value within
some JSON data. To look for JSON entries that have a location
field:
const result = await connection.execute(
`SELECT po_document FROM j_purchaseorder WHERE JSON_EXISTS (po_document, '$.location')`
);
const d = result.rows[0][0]; // show only first record in this example
console.dir(d, { depth: null }); // assumes Oracle Database and Client 21c
This query displays:
{ userId: 1, userName: 'Chris', location: 'Australia' }
The SQL/JSON functions JSON_VALUE
and JSON_QUERY
can also be used.
Note that the default error-handling behavior for these functions is NULL ON ERROR, which means that no value is returned if an error occurs. To ensure that an error is raised, use ERROR ON ERROR.
For more information, see SQL/JSON Path Expressions in the Oracle JSON Developer’s Guide.
In Oracle Database 12.2, or later, the JSON_OBJECT
function is a great
way to convert relational table data to JSON:
const result = await connection.execute(
`SELECT JSON_OBJECT ('deptId' IS d.department_id, 'name' IS d.department_name) department
FROM departments d
WHERE department_id < :did
ORDER BY d.department_id`,
[50]
);
for (const row of result.rows)
console.log(row[0]);
This produces:
{"deptId":10,"name":"Administration"}
{"deptId":20,"name":"Marketing"}
{"deptId":30,"name":"Purchasing"}
{"deptId":40,"name":"Human Resources"}
Writing applications that can handle all the potential JSON storage types and potential client-server version combinations requires code that checks the Oracle versions and the returned column metadata. This allows the code to do appropropriate streaming or type conversion. It will be simpler to restrict the environment and data types supported by the application. Where possible, migrate to the new JSON type to take advantage of its ease of use and performance benefits.
Here is an example of code that works with multiple versions, with the assumption that older DBs use BLOB storage.
Create a table:
if (connection.oracleServerVersion >= 2100000000) {
await connection.execute(`CREATE TABLE mytab (mycol JSON)`);
} else if (connection.oracleServerVersion >= 1201000200) {
await connection.execute(`CREATE TABLE mytab (mycol BLOB CHECK (mycol IS JSON)) LOB (mycol) STORE AS (CACHE)`);
} else {
throw new Error('This application only works with Oracle Database 12.1.0.2 or greater');
}
Insert data:
const inssql = `INSERT INTO mytab (mycol) VALUES (:bv)`;
const data = { "userId": 2, "userName": "Anna", "location": "New Zealand" };
if (oracledb.oracleClientVersion >= 2100000000 && connection.oracleServerVersion >= 2100000000 ) {
await connection.execute(inssql, { bv: { val: data, type: oracledb.DB_TYPE_JSON } });
} else {
const s = JSON.stringify(data);
const b = Buffer.from(s, 'utf8');
await connection.execute(inssql, { bv: { val: b } });
}
Query data:
const qrysql = `SELECT mycol
FROM mytab
WHERE JSON_EXISTS (mycol, '$.location')
OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY`;
result = await connection.execute(qrysql, [], { outFormat: oracledb.OUT_FORMAT_ARRAY });
if (result.metaData[0].fetchType == oracledb.DB_TYPE_JSON) {
j = result.rows[0][0];
} else {
const d = await result.rows[0][0].getData();
j = await JSON.parse(d);
}
console.dir(j, { depth: null });
XMLType
columns queried will returns as Strings by default, limited
to the size of a VARCHAR2.
However, if desired, the SQL query could be changed to return a CLOB, for example:
const sql = `SELECT XMLTYPE.GETCLOBVAL(res) FROM resource_view`;
The CLOB can be fetched in node-oracledb as a String or Lob.
To insert into an XMLType
column, directly insert a string
containing the XML, or use a temporary LOB, depending on the data
length.
const myxml =
`<Warehouse>
<WarehouseId>1</WarehouseId>
<WarehouseName>Melbourne, Australia</WarehouseName>
<Building>Owned</Building>
<Area>2020</Area>
<Docks>1</Docks>
<DockType>Rear load</DockType>
<WaterAccess>false</WaterAccess>
<RailAccess>N</RailAccess>
<Parking>Garage</Parking>
<VClearance>20</VClearance>
</Warehouse>`;
const result = await connection.execute(
`INSERT INTO xwarehouses (warehouse_id, warehouse_spec) VALUES (:id, XMLType(:bv))`,
{ id: 1, bv: myxml }
);
LOB handling as discussed in the section Working with CLOB, NCLOB and BLOB Data.
SQL and PL/SQL statements may contain bind parameters, indicated by colon-prefixed identifiers or numerals. These indicate where separately specified values are substituted in a statement when it is executed, or where values are to be returned after execution.
IN binds are values passed into the database. OUT binds are used to retrieve data. IN OUT binds are passed in, and may return a different value after the statement executes.
Using bind parameters is recommended in preference to constructing SQL or PL/SQL statements by string concatenation or template literals. This is for performance and security.
Inserted data that is bound is passed to the database separately from the statement text. It can never be executed directly. This means there is no need to escape bound data inserted into the database.
If a statement is executed more than once with different values for the bind parameters, then Oracle can re-use context from the initial execution, generally improving performance. However, if similar statements contain hard coded values instead of bind parameters, Oracle sees the statement text is different and will be less efficient.
Bind parameters can be used to substitute data but not the text of the statement.
Bind variables cannot be used in DDL statements, for example
CREATE TABLE
or ALTER
commands.
Sets of values can bound for use in connection.executeMany()
,
see Batch Statement Execution and Bulk Loading.
For IN binds, a data value is passed into the database and substituted into the statement during execution of SQL or PL/SQL.
To bind data values, the bindParams
argument of
execute()
should contain bind variable objects with
dir
, val
,
type
properties. Each bind variable object name must
match the statement’s bind parameter name:
const oracledb = require('oracledb');
const result = await connection.execute(
`INSERT INTO countries VALUES (:country_id, :country_name)`,
{
country_id: { dir: oracledb.BIND_IN, val: 90, type: oracledb.NUMBER },
country_name: { dir: oracledb.BIND_IN, val: "Tonga", type: oracledb.STRING }
}
);
console.log("Rows inserted " + result.rowsAffected);
For IN binds:
The direction dir
is oracledb.BIND_IN
, which is the default when
dir
is not specified.
The val
attribute may be a constant or a JavaScript variable.
If type
is omitted, it is derived from the bind data value. If it is set,
it can be one of the values in the type
table.
Typically type
is one of oracledb.STRING
, oracledb.NUMBER
,
oracledb.DATE
or oracledb.BUFFER
matching the standard Node.js type of the
data being passed into the database. Use a bind type of oracledb.BLOB
or
oracledb.CLOB
to pass in Lob instances. For binding Oracle
Database objects, it can also be the name of an Oracle Database object or
collection, or a DbObject Class type.
Since dir
and type
have defaults, these attributes are sometimes
omitted for IN binds. Binds can be like:
const result = await connection.execute(
`INSERT INTO countries VALUES (:country_id, :country_name)`,
{country_id: 90, country_name: "Tonga"}
);
console.log("Rows inserted " + result.rowsAffected);
When a bind parameter name is used more than once in the SQL statement, it should only occur once in the bind object:
const result = await connection.execute(
`SELECT first_name, last_name FROM employees WHERE first_name = :nmbv OR last_name = :nmbv`,
{nmbv: 'Christopher'}
);
Instead of using named bind parameters, the data can alternatively be
in an array. In this example, values are bound to the SQL bind
parameters :country_id
and :country_name
:
const result = await connection.execute(
`INSERT INTO countries VALUES (:country_id, :country_name)`,
[90, "Tonga"]
);
The position of the array values corresponds to the position of the
SQL bind parameters as they occur in the statement, regardless of
their names. This is still true even if the bind parameters are named
like :0
, :1
, etc. The following snippet will fail because the
country name needs to be the second entry of the array so it becomes
the second value in the INSERT
statement
const result = await connection.execute(
`INSERT INTO countries (country_id, country_name) VALUES (:1, :0)`,
["Tonga", 90] // fail
);
In the context of SQL statements, the input array position ‘n’ indicates the bind parameter at the n’th position in the statement. However, in the context of PL/SQL statements the position ‘n’ in the bind call indicates a binding for the n’th unique parameter name in the statement when scanned left to right.
If a bind parameter name is repeated in the SQL string then bind by name syntax should be used.
When binding a JavaScript Date value in an INSERT
statement, by default the
bind type
is equivalent to TIMESTAMP WITH LOCAL TIME ZONE. In the database,
TIMESTAMP WITH LOCAL TIME ZONE dates are normalized to the database time zone,
or to the time zone specified for TIMESTAMP WITH TIME ZONE columns. If later
queried, they are returned in the session time zone. See Fetching Date and
Timestamps for more information.
OUT binds are used to retrieve data from the database. IN OUT binds are passed into the database, and may return a different value after the statement executes. IN OUT binds can be used for PL/SQL calls, but not for SQL.
For each OUT and IN OUT bind parameter in bindParams
, a
bind variable object containing dir
,
val
, type
, and
maxSize
properties is used:
The dir
attribute should be oracledb.BIND_OUT
or
oracledb.BIND_INOUT
, depending on whether data is only to be
returned from the database or additionally passed into the database.
The val
parameter in needed when binding IN OUT to pass a value
into the database. It is not used for OUT binds.
The type
attribute can be one of the constants as discussed in the type
table. This determines the mapping between the
database type and the JavaScript type.
The attribute should be set for OUT binds. If type
is not specified, then
oracledb.STRING
is assumed.
For IN OUT binds, type
can inferred from the input data value type. However
is recommended to explicitly set type
, because the correct value cannot be
determined if the input data is null. The output data type will always be the
same as the input data type.
A maxSize
attribute should be set for String and Buffer OUT or IN OUT binds.
This is the maximum number of bytes the bind parameter will return. If the
output value does not fit in maxSize
bytes, then an error such ORA-06502:
PL/SQL: numeric or value error: character string buffer too small or
NJS-016: buffer is too small for OUT binds occurs.
A default value of 200 bytes is used when maxSize
is not provided for OUT
binds that are returned in Strings or Buffers.
A string representing a UROWID may be up to 5267 bytes long in node-oracledb.
For PL/SQL Associative Array binds a
maxArraySize
property is also required.
Note that before a PL/SQL block returns, all OUT binds should be explicitly set to a value. This includes bind variables that will be ignored. Set simple variables to NULL. Set REF CURSORS to an empty result set. See this GitHub Issue.
The results
parameter of the execute()
callback contains an outBinds
property with the
returned OUT and IN OUT bind values.
Given the creation of the PL/SQL procedure TESTPROC
:
CREATE OR REPLACE PROCEDURE testproc (
p_in IN VARCHAR2, p_inout IN OUT VARCHAR2, p_out OUT NUMBER)
AS
BEGIN
p_inout := p_in || p_inout;
p_out := 101;
END;
/
show errors
The procedure TESTPROC
can be called with:
const bindVars = {
i: 'Chris', // default direction is BIND_IN. Data type is inferred from the data
io: { val: 'Jones', dir: oracledb.BIND_INOUT },
o: { dir: oracledb.BIND_OUT, type: oracledb.NUMBER },
};
const result = await connection.execute(
`BEGIN testproc(:i, :io, :o); END;`,
bindVars
);
console.log(result.outBinds);
Since bindParams
is passed as an object, the outBinds
property is
also an object. The Node.js output is:
{ io: 'ChrisJones', o: 101 }
PL/SQL allows named parameters in procedure and function calls. This
can be used in execute()
like:
`BEGIN testproc(p_in => :i, p_inout => :io, p_out => :o); END;`,
An alternative to node-oracledb’s ‘bind by name’ syntax is ‘bind by array’ syntax:
const bindVars = [
'Chris',
{ val: 'Jones', dir: oracledb.BIND_INOUT },
{ type: oracledb.NUMBER, dir: oracledb.BIND_OUT }
];
When bindParams
is passed as an array, then
outBinds
is returned as an array, with the same order as the OUT
binds in the statement:
[ 'ChrisJones', 101 ]
Mixing positional and named syntax is not supported. The following will throw an error:
const bindVars = [
'Chris', // valid
{ val: 'Jones', dir: oracledb.BIND_INOUT }, // valid
{ o: { type: oracledb.NUMBER, dir: oracledb.BIND_OUT } } // invalid
];
“DML RETURNING” (also known as “RETURNING INTO”) statements such as INSERT INTO
tab VALUES (:1) RETURNING ROWID INTO :2
are a way information can be returned
about row changes from DML statements. For example you can use DML
RETURNING to get the ROWIDs of newly inserted rows. Another common use case is
to return auto incremented column values .
For statements that affect single rows, you may prefer to use
lastRowid
.
Bind parameters for DML RETURNING statements can use oracledb.BLOB
,
oracledb.CLOB
, oracledb.STRING
, oracledb.NUMBER
or oracledb.DATE
for the
BIND_OUT type
. To bind named Oracle objects use the
class name or DbObject prototype class for the bind type, as
shown for object binds in Fetching Oracle Database Objects and
Collections.
Oracle Database DATE, TIMESTAMP, TIMESTAMP WITH LOCAL TIME ZONE and
TIMESTAMP WITH TIME ZONE types can be bound as oracledb.DATE
for DML
RETURNING. These types can also be bound as oracledb.STRING
, if
desired. ROWID and UROWID data to be returned can be bound as
oracledb.STRING
. Note that a string representing a UROWID may be up
to 5267 bytes long.
For string and buffer types, an error occurs if
maxSize
is not large enough to hold a returned
value.
Note each DML RETURNING bind OUT parameter is returned as an array
containing zero or more elements. Application code that is designed
to expect only one value could be made more robust if it confirms the
returned array length is not greater than one. This will help
identify invalid data or an incorrect WHERE
clause that causes more
results to be returned.
Duplicate binds (using the same bind name more than once in the statement) are
not allowed in a DML statement with a RETURNING
clause, and no duplication is
allowed between bind parameters in the DML section and the RETURNING
section
of the statement.
An example of DML RETURNING binds is:
const result = await connection.execute(
`UPDATE mytab SET name = :name
WHERE id = :id
RETURNING id, ROWID INTO :ids, :rids`,
{
id: 1001,
name: "Krishna",
ids: { type: oracledb.NUMBER, dir: oracledb.BIND_OUT },
rids: { type: oracledb.STRING, dir: oracledb.BIND_OUT }
}
);
console.log(result.outBinds);
If the WHERE
clause matches one record, the output would be like:
{ ids: [ 1001 ], rids: [ 'AAAbvZAAMAAABtNAAA' ] }
When a couple of rows match, the output could be:
{ ids: [ 1001, 1002 ],
rids: [ 'AAAbvZAAMAAABtNAAA', 'AAAbvZAAMAAABtNAAB' ] }
If the WHERE
clause matches no rows, the output would be:
{ ids: [], rids: [] }
Oracle REF CURSORS can be bound in node-oracledb by using the type
oracledb.CURSOR
in PL/SQL calls. For an OUT bind, the resulting
bind variable becomes a ResultSet, allowing rows to
be fetched using getRow()
or getRows()
.
The ResultSet can also be converted to a Readable Stream by using
toQueryStream()
. Oracle Implicit
Results are an alternative way to return query
results from PL/SQL.
If using getRow()
or getRows()
the ResultSet must be freed using
close()
when all rows have been fetched, or when the
application does not want to continue getting more rows. If the REF
CURSOR is set to NULL or is not set in the PL/SQL procedure, then the
returned ResultSet is invalid and methods like getRows()
will return
an error when invoked.
Given a PL/SQL procedure defined as:
CREATE OR REPLACE PROCEDURE get_emp_rs (
p_sal IN NUMBER,
p_recordset OUT SYS_REFCURSOR) AS
BEGIN
OPEN p_recordset FOR
SELECT first_name, salary, hire_date
FROM employees
WHERE salary > p_sal;
END;
/
This PL/SQL procedure can be called in node-oracledb using:
const result = await connection.execute(
`"BEGIN get_emp_rs(:sal, :cursor); END;`,
{
sal: 6000,
cursor: { type: oracledb.CURSOR, dir: oracledb.BIND_OUT }
}
);
const resultSet = result.outBinds.cursor;
let row;
while ((row = await resultSet.getRow())) {
console.log(row);
}
// always close the ResultSet
await resultSet.close();
See refcursor.js for a complete example.
To convert the REF CURSOR ResultSet to a stream, use
toQueryStream()
:
const result = await connection.execute(
`"BEGIN get_emp_rs(:sal, :cursor); END;`,
{
sal: 6000,
cursor: { type: oracledb.CURSOR, dir: oracledb.BIND_OUT }
}
);
const cursor = result.outBinds.cursor;
const queryStream = cursor.toQueryStream();
const consumeStream = new Promise((resolve, reject) => {
queryStream.on('data', function(row) {
console.log(row);
});
queryStream.on('error', reject);
queryStream.on('close', resolve);
});
await consumeStream;
The connection must remain open until the stream is completely read.
Query results must be fetched to completion to avoid resource leaks.
The ResultSet close()
call for streaming query results will be
executed internally when all data has been fetched.
If you want to pass a queried ResultSet into PL/SQL using direction
oracledb.BIND_IN
, then set prefetchRows
to 0 for the query returning the ResultSet. This stops the first rows
being silently fetched by node-oracledb and not being available in the
later receiving PL/SQL code. For example:
const result = await connection.execute(
`SELECT * FROM locations`,
[],
{
resultSet: true,
prefetchRows: 0 // stop node-oracledb internally fetching rows from the ResultSet
}
);
// Pass the ResultSet as a REF CURSOR into PL/SQL
await conn.execute(
`BEGIN myproc(:rc); END;`,
{
rc: { val: result.resultSet, type: oracledb.CURSOR, dir: oracledb.BIND_IN }
}
);
Because the default bind direction is BIND_IN
, and the type can be inferred
from result.resultSet
, the PL/SQL procedure call can be simplified to:
await conn.execute(`BEGIN myproc(:rc); END;`, [result.resultSet]);
Database CLOBs can be bound with type
set to
oracledb.CLOB
. Database BLOBs can be bound as
oracledb.BLOB
. These binds accept, or return,
node-oracledb Lob instances, which implement the Node.js
Stream interface.
Lobs may represent Oracle Database persistent LOBs (those stored in
tables) or temporary LOBs (such as those created with
createLob()
or returned by some SQL and
PL/SQL operations).
LOBs can be bound with direction oracledb.BIND_IN
,
oracledb.BIND_OUT
or oracledb.BIND_INOUT
, depending on context.
Note that any PL/SQL OUT LOB parameter should be initialized in the PL/SQL block - even just to NULL - before the PL/SQL code completes. Make sure to do this in all PL/SQL code paths including in error handlers. This prevents node-oracledb throwing the error DPI-007: invalid OCI handle or descriptor.
In many cases it will be easier to work with JavaScript Strings and Buffers
instead of Lobs. These types can be bound directly for SQL IN
binds to insert into, or update, LOB columns. They can also be bound to PL/SQL
LOB parameters. Set the bind type
to
oracledb.STRING
for CLOBs,
oracledb.DB_TYPE_NVARCHAR
for NCLOBs, and
oracledb.BUFFER
for BLOBs. The default size
used for these binds in the OUT direction is 200, so set maxSize
appropriately.
See Working with CLOB, NCLOB and BLOB Data for examples and more information on binding and working with LOBs.
When CLOBs are bound as oracledb.STRING
, BCLOBs bound as
oracledb.DB_TYPE_NVARCHAR
, or BLOBs are bound as oracledb.BUFFER
, then their
size is limited to 1GB. Commonly the practical limitation is the memory
available to Node.js and the V8 engine. For data larger than several megabytes,
it is recommended to bind as oracledb.CLOB
or oracledb.BLOB
and use Lob
streaming. If you try to create large Strings or Buffers in
Node.js you will see errors like JavaScript heap out of memory, or other space
related messages.
Internally, temporary LOBs are used when binding Strings and Buffers larger than 32 KB for PL/SQL calls. Freeing of the temporary LOB is handled automatically. For SQL calls no temporary LOBs are used.
WHERE IN
ClauseBinding a single JavaScript value into a SQL WHERE IN
clause is
easy:
sql = `SELECT last_name FROM employees WHERE first_name IN (:bv)`;
binds = ['Christopher'];
await connection.execute(sql, binds, function(...));
But a common use case for a query WHERE IN
clause is for multiple
values, for example when a web user selects multiple check-box options
and the query should match all chosen values.
Trying to associate multiple data values with a single bind parameter
will not work. To use a fixed, small number of values in an WHERE
IN
bind clause, the SQL query should have individual bind parameters,
for example:
const sql = `SELECT last_name FROM employees WHERE first_name IN (:bv1, :bv2, :bv3, :bv4)`;
const binds = ['Alyssa', 'Christopher', 'Hazel', 'Samuel'];
const result = await connection.execute(sql, binds);
If you sometimes execute the query with a smaller number of items, a null can be bound for the ‘missing’ values:
const binds = ['Alyssa', 'Christopher', 'Hazel', null];
When the exact same statement text is re-executed many times regardless of the number of user supplied values, you get performance and scaling benefits from not having multiple, unique SQL statements being run.
Another solution when the number of data items is only known at runtime is to build up an exact SQL string like:
const binds = ['Christopher', 'Hazel', 'Samuel'];
let sql = `SELECT first_name, last_name FROM employees WHERE first_name IN (`;
for (const i = 0; i < binds.length; i++)
sql += (i > 0) ? ", :" + i : ":" + i;
sql += ")";
This will construct a SQL statement:
SELECT first_name, last_name FROM employees WHERE first_name IN (:0, :1, :2)
You could use a tagged literal template to do this conveniently. Binds are still used for security. But, depending how often this query is executed, and how changeable the number of bind values is, you can end up with lots of ‘unique’ query strings being executed. You might not get the statement caching benefits that re-executing a fixed SQL statement would have.
Another solution for a larger number of values is to construct a SQL statement like:
SELECT ... WHERE col IN ( <something that returns a list of rows> )
The easiest way to do the <something that returns a list of rows>
will depend on how the data is initially represented and the number of
items. You might look at using CONNECT BY
or nested tables. Or,
for really large numbers of items, you might prefer to use a global
temporary table. Some solutions are given in On Cursors, SQL, and
Analytics and in this StackOverflow answer.
It is not possible to bind table names in queries. Instead use a hard-coded Allow List of names to build the final SQL statement, for example:
const validTables = ['LOCATIONS', 'DEPARTMENTS'];
const tableName = getTableNameFromEndUser();
if (!validTables.includes(tableName)) {
throw new Error('Invalid table name');
}
const query = `SELECT * FROM ` + tableName;
The same technique can be used to construct the list of selected column names. Make sure to use a Allow List of names to avoid SQL Injection security risks.
Each final SQL statement will obviously be distinct, and will use a slot in the statement cache.
It is possible to bind column names used in an ORDER BY:
const sql = `SELECT first_name, last_name
FROM employees
ORDER BY
CASE :ob
WHEN 'FIRST_NAME' THEN first_name
ELSE last_name
END`;
const columnName = getColumnNameFromEndUser(); // your function
const binds = [columnName];
const result = await connection.execute(sql, binds);
In this example, when columnName
is ‘FIRST_NAME’ then the result set
will be ordered by first name, otherwise the order will be by last
name.
You should analyze the statement usage patterns and optimizer query plan before deciding whether to using binds like this, or to use multiple hard-coded SQL statements, each with a different ORDER BY.
You can query and insert most Oracle Database objects and collections, with some limitations.
Performance-sensitive applications should consider using scalar types instead of
objects. If you do use objects, avoid calling
connection.getDbObjectClass()
unnecessarily, and avoid
objects with large numbers of attributes.
As an example, the Oracle Spatial type SDO_GEOMETRY can easily be used in node-oracledb. Describing SDO_GEOMETRY in SQL*Plus shows:
Name Null? Type
----------------------------------------- -------- ----------------------------
SDO_GTYPE NUMBER
SDO_SRID NUMBER
SDO_POINT MDSYS.SDO_POINT_TYPE
SDO_ELEM_INFO MDSYS.SDO_ELEM_INFO_ARRAY
SDO_ORDINATES MDSYS.SDO_ORDINATE_ARRAY
In Node.js, a call to
connection.getDbObjectClass()
returns a
DbObject prototype object representing the database
type:
const GeomType = await connection.getDbObjectClass("MDSYS.SDO_GEOMETRY");
console.log(GeomType.prototype);
This gives:
DbObject {
schema: 'MDSYS',
name: 'SDO_GEOMETRY',
fqn: 'MDSYS.SDO_GEOMETRY',
attributes:
{ SDO_GTYPE: { type: 2010, typeName: 'NUMBER' },
SDO_SRID: { type: 2010, typeName: 'NUMBER' },
SDO_POINT:
{ type: 2023,
typeName: 'MDSYS.SDO_POINT_TYPE',
typeClass: [Object] },
SDO_ELEM_INFO:
{ type: 2023,
typeName: 'MDSYS.SDO_ELEM_INFO_ARRAY',
typeClass: [Object] },
SDO_ORDINATES:
{ type: 2023,
typeName: 'MDSYS.SDO_ORDINATE_ARRAY',
typeClass: [Object] } },
isCollection: false }
The type
value of 2023 corresponds to the oracledb.DB_TYPE_OBJECT
constant. The value 2010 corresponds to oracledb.DB_TYPE_NUMBER
.
Now the object prototype has been found, an object can be created by passing a JavaScript object to the constructor. The case of the attributes is important:
const geom = new GeomType(
{
SDO_GTYPE: 2003,
SDO_SRID: null,
SDO_POINT: null,
SDO_ELEM_INFO: [ 1, 1003, 3 ],
SDO_ORDINATES: [ 1, 1, 5, 7 ]
}
);
Attributes not assigned values will default to null. Extra attributes set that are not present in the database object will be ignored.
An alternative to instantiating the whole object at once is to set individual attributes:
const geom = new GeomType();
geom.S_GTYPE = 2003;
. . .
Once created, the DbObject in geom
can then be bound for insertion.
For example, if TESTGEOMETRY was created as:
CREATE TABLE testgeometry (id NUMBER, geometry MDSYS.SDO_GEOMETRY)
Then the INSERT statement would be:
await connection.execute(
`INSERT INTO testgeometry (id, geometry) VALUES (:id, :g)`,
{id: 1, g: geom}
);
Node-oracledb automatically detects the type for geom
.
Insertion can be simplified by setting the bind parameter type
to
the name of the Oracle Database object and passing a JavaScript object
as the bind value:
await connection.execute(
`INSERT INTO testgeometry (id, geometry) VALUES (:id, :g)`,
{
id: 1,
g: {
type: "MDSYS.SDO_GEOMETRY",
val: {
SDO_GTYPE: 2003,
SDO_SRID: null,
SDO_POINT: null,
SDO_ELEM_INFO: [ 1, 1003, 3 ],
SDO_ORDINATES: [ 1, 1, 5, 7 ]
}
}
}
);
For objects that are nested, such as SDO_GEOMETRY is, you only need to give the name of the top level object.
See selectgeometry.js for a runnable example.
When handling multiple objects of the same type, then use fully
qualified names like “MDSYS.SDO_GEOMETRY” instead of “SDO_GEOMETRY”.
Alternatively retain, and use, the prototype object returned by
connection.getDbObjectClass()
. Node-oracledb
will cache type information using the type’s fully qualified name as
the key to avoid the expense of a round-trip, when
possible. Each connection has its own cache.
When the definition of a type changes in the database, such as might
occur in a development environment, you should fully close connections
to clear the object caches used by node-oracledb and the Oracle client
libraries. For example, when using a pool you could use await
connection.close({drop: true})
, or restart the
pool. Then getDbObjectClass()
can be called again to get the
updated type information.
When objects are fetched, they are represented as a DbObject.
Note that LOBs will be represented as Lob objects regardless of any
fetchAsString
, fetchAsBuffer
, or fetchInfo
setting.
If oracledb.dbObjectAsPojo
is set to true, then queried
objects and OUT bind objects are returned as “plain old JavaScript objects”
instead of being database-backed. The setting can help performance if an
object’s attributes are accessed multiple times. However if only a few object
attributes are accessed, or attributes are accessed once, then it may be more
efficient to keep dbObjectAsPojo
false. Setting dbObjectAsPojo
to true
also allows applications to close connections before any attributes are accessed
unless LOBs are involved.
Accessing a DbObject is the same whichever value of dbObjectAsPojo
you use.
For example:
result = await connection.execute(`SELECT geometry FROM testgeometry WHERE id = 1`);
o = result.rows[0][0];
console.log(o);
This gives:
[MDSYS.SDO_GEOMETRY] { SDO_GTYPE: 2003,
SDO_SRID: null,
SDO_POINT: null,
SDO_ELEM_INFO: [ 4, 1003, 3 ],
SDO_ORDINATES: [ 4, 8, 5, 9 ] }
The SDO_ELEM_INFO attribute is itself a DbObject. The following code
console.log(o.SDO_ELEM_INFO);
gives:
[MDSYS.SDO_ELEM_INFO_ARRAY] [ 1, 1003, 3 ]
If a DbObject is for an Oracle Database collection, the
dbObject.isCollection
attribute will
be true.
console.log(o.isCollection); // false
console.log(o.SDO_ELEM_INFO.isCollection); // true
For DbObjects representing Oracle collections, methods such as
dbObject.getKeys()
and
dbObject.getValues()
can be used:
console.log(o.SDO_ELEM_INFO.getKeys()); // [ 0, 1, 2 ]
console.log(o.SDO_ELEM_INFO.getValues()); // [ 1, 1003, 3 ]
The options fetchAsBuffer
and
fetchAsString
do not affect values in
objects queried from the database.
LOBs will be fetched as Lob objects. The
lob.getData()
method is a convenient way to retrieve
the data. Note it is an asynchronous method and requires a round-trip
to the database.
PL/SQL has three collection types: associative arrays, VARRAY (variable-size arrays), and nested tables. See Collection Types in the Database PL/SQL Language Reference.
Arrays can be bound to PL/SQL IN, IN OUT, and OUT parameters of PL/SQL INDEX BY associative array types with integer keys. This Oracle type was formerly called PL/SQL tables or index-by tables.
While you could bind associative arrays via named types as shown in previous examples, it is more efficient to use the method shown below which uses the type of each element, not the name of the associative array type. Note that if you use named types for BIND_IN, then the resulting arrays in PL/SQL will start from index 0. The method shown below results in indexes starting from 1. (Using named type binding for nested tables and VARRAYs results in indexes starting from 1).
Given this table and PL/SQL package:
DROP TABLE mytab;
CREATE TABLE mytab (id NUMBER, numcol NUMBER);
CREATE OR REPLACE PACKAGE mypkg IS
TYPE numtype IS TABLE OF NUMBER INDEX BY BINARY_INTEGER;
PROCEDURE myinproc(p_id IN NUMBER, vals IN numtype);
PROCEDURE myoutproc(p_id IN NUMBER, vals OUT numtype);
END;
/
CREATE OR REPLACE PACKAGE BODY mypkg IS
PROCEDURE myinproc(p_id IN NUMBER, vals IN numtype) IS
BEGIN
FORALL i IN INDICES OF vals
INSERT INTO mytab (id, numcol) VALUES (p_id,