Connector/Node.js Promise API
Connector/Node.js Promise API
There are two different connection implementations: one, the default, uses Promise, and the other uses Callback, allowing for compatibility with the MySQL and mysql2 API's.
The documentation provided on this page is the promise API (default). If you want information on the Callback API, see the CALLBACK API.
Quick Start
Install the MariaDB Connector using npm
$ npm install mariadbYou can then use the Connector in your application code with the Promise API. For instance,
const mariadb = require('mariadb');
async function asyncFunction() {
const conn = await mariadb.createConnection({
host: 'mydb.com',
user: 'myUser',
password: 'myPwd'
});
try {
const res = await conn.query('select 1');
console.log(res); // [{ "1": 1 }]
return res;
} finally {
conn.end();
}
}
asyncFunction();Installation
To use the Connector, you first need to install it on your system. The installation process for Promise and Callback API is managed with the same package through npm.
To use the Connector, you need to import the package into your application code.
Migrating from 2.x or mysql/mysql2 to 3.x
Default behaviour for decoding BIGINT / DECIMAL datatype for 2.x version and mysql/mysql2 drivers return a JavaScript Number object. BIGINT/DECIMAL values might not be in threturns range, resulting in approximate results.
Since 3.x version, driver has reliable default, returning:
DECIMAL => javascript String
BIGINT => javascript BigInt object
For compatibility with previous version or mysql/mysql driver, 4 options have been added to return BIGINT/DECIMAL as number, as previous defaults.
insertIdAsNumber
Whether the query should return last insert id from INSERT/UPDATE command as BigInt or Number. default return BigInt
boolean
false
decimalAsNumber
Whether the query should return decimal as Number. If enabled, this might return approximate values.
boolean
false
bigIntAsNumber
Whether the query should return BigInt data type as Number. If enabled, this might return approximate values.
boolean
false
checkNumberRange
when used in conjunction of decimalAsNumber, insertIdAsNumber or bigIntAsNumber, if conversion to number is not exact, connector will throw an error (since 3.0.1)
function
Previous options supportBigNumbers and bigNumberStrings still exist for compatibility but are now deprecated.
Other considerations
mysql has an experimental syntax permitting the use of ?? characters as placeholder to escape id. This isn't implemented in the MariaDB driver, permitting the same query syntax for Connection.query and Connection.execute.
example:
has to use explicit escapeId:
Cluster configuration removeNodeErrorCount default to Infinity when mysql/mysql2 default to value 5. This avoids removing nodes without explicitly saying so.
Recommendation
Enable 'trace' option in development
It is recommended to activate the trace option in development. Since the driver is asynchronous, enabling this option permits saving initial stack when calling any driver methods. This allows having interesting debugging information: example:
The caller method and line are now in the error stack, permitting easy error debugging.
The problem is this error stack is created using Error.captureStackTrace that is super slow (hoping node.js solved it at some point). To give an idea, this slows down by 10% a query like 'select * from mysql.user LIMIT 1', so not recommended in production.
Timezone consideration
If Client and Server share the same timezone, default behavior (timezone='local') is the solution.
The problem resides when client and server don't share the same timezone.
The timezone option can have the following value:
'local' (default): connector doesn't do any conversion. If the database has a different timezone, there will be offset issues.
'auto': connector retrieves server timezone, and if client timezone differs from server, connector will set session timezone to client timezone
IANA timezone / offset, example 'America/New_York' or '+06:00'. Connector will set session timezone to indicated timezone. It is expected that this timezone corresponds to client tz.
Using 'auto' or setting specific timezone solves timezone correction. Please be careful for fixed timezone: Etc./GMT+12 = GMT-12:00 = -12:00 = offset -12. Etc./GMT have opposite sign!!
(Before 3.1, the connector was converting date to server timezone, but these were not correcting all timezone issues)
IANA timezone / offset
When using IANA timezone, the connector will set the connection timezone to the timezone. This can throw an error on connection if timezone is unknown by the server (see mariadb timezone documentation, timezone tables might be not initialized) If you are sure the server is using that timezone, this step can be skipped with the option skipSetTimezone.
If the timezone corresponds to JavaScript default timezone, then no conversion will be done.
Timezone setting recommendation
The best is to have the same timezone on client and database, then keep the 'local' default value.
If different, then either client or server has to convert the date. In general, it is best to use client conversion to avoid putting any unneeded stress on the database. Timezone has to be set to the IANA timezone corresponding to server timezone and disabled skipSetTimezone option since you are sure that the server has the corresponding timezone.
Example: The client uses 'America/New_York' by default, and server 'America/Los_Angeles'. Execute 'SELECT @@system_time_zone' on the server. That will give the server default timezone. The server can return a POSIX timezone like 'PDT' (Pacific Daylight Time). IANA timezone correspondence must be found (see IANA timezone List) and configure client-side. This will ensure DST (automatic daylight saving time change will be handled).
Security consideration
Connection details such as URL, username, and password are better hidden into environment variables. Using code like:
Then for example, run node.js setting those environment variables:
Another solution is using dotenv package. Dotenv loads environment variables from .env files into the process.env variable in Node.js:
Then configure dotenv to load all .env files:
with an .env file containing:
.env files must NOT be pushed into the repository, using .gitignore.
Alternatively, Node.js 20.0 introduced the experimental feature of using the node --env-file=.env syntax to load environment variables without the need for external dependencies. We can then simply write:
Assuming the presence of the same .env file as previously described.
Default options consideration
For new projects, enabling option supportBigInt is recommended (It will be in a future 3.x version).
This option permits to avoid exact value for big integer (value > 2^53) (see javascript ES2020 BigInt)
Promise API
Base:
createConnection(options) → Promise: Creates a new connection.createPool(options) → Pool: Creates a new Pool.createPoolCluster(options) → PoolCluster: Creates a new pool cluster.importFile(options) → Promise: Import Sql fileversion → String: Return library version.defaultOptions(options) → Json: List options with default values
Connection:
connection.query(sql [, values]) → Promise: Executes a query.connection.queryStream(sql [, values]) → Emitter: Executes a query, returning an emitter object to stream rows.connection.prepare(sql) → Promise: Prepares a query.connection.execute(sql [, values]) → Promise: Prepare and Executes a query.connection.batch(sql, values) → Promise: Fast batch processing.connection.beginTransaction() → Promise: Begins a transaction.connection.commit() → Promise: Commits the current transaction, if any.connection.release() → Promise: Release connection to pool if connection comes from pool.connection.rollback() → Promise: Rolls back the current transaction, if any.connection.changeUser(options) → Promise: Changes the current connection user.connection.ping() → Promise: Sends a 1 byte packet to the database to validate the connection.connection.reset() → Promise: Reset current connection state.connection.isValid() → boolean: Checks that the connection is active without checking socket state.connection.end() → Promise: Gracefully close the connection.connection.destroy(): Forces the connection to close.connection.escape(value) → String: Escape parameterconnection.escapeId(value) → String: Escape identifierconnection.pause(): Pauses the socket output.connection.resume(): Resumes the socket output.connection.serverVersion(): Retrieves the current server version.connection.importFile(options) → Promise: Import Sql fileevents: Subscribes to connection error events.
Pool:
pool.getConnection() → Promise: Creates a new connection.pool.query(sql [, values]) → Promise: Executes a query.pool.batch(sql, values) → Promise: Executes a batchpool.end() → Promise: Gracefully closes the connection.pool.escape(value) → String: Escape parameterpool.escapeId(value) → String: Escape identifierpool.importFile(options) → Promise: Import Sql filepool.activeConnections() → Number: Gets current active connection number.pool.totalConnections() → Number: Gets current total connection number.pool.idleConnections() → Number: Gets current idle connection number.pool.taskQueueSize() → Number: Gets current stacked request.pool events: Subscribes to pool events.
PoolCluster
poolCluster.add(id, config): Add a pool to cluster.poolCluster.remove(pattern): Remove and end pool according to pattern.poolCluster.end() → Promise: End cluster.poolCluster.getConnection(pattern, selector) → Promise: Return a connection from cluster.poolCluster.of(pattern, selector) → FilteredPoolCluster: Return a subset of cluster.poolCluster events: Subscribes to pool cluster events.
Base API
createConnection(options) → Promise
createConnection(options) → Promise
options: JSON/String connection option documentationReturns a promise that:
resolves with a Connection object,
Raises an Error.
Creates a new Connection object.
Example:
Connection options
Essential options list:
user
User to access database.
string
password
User password.
string
host
IP address or DNS of the database server. Not used when using option socketPath.
string
"localhost"
port
Database server port number. Not used when using the option socketPath
integer
3306
database
Default database to use when establishing the connection.
string
socketPath
Permits connections to the database through the Unix domain socket or named pipe.
string
compress
Compresses the exchange with the database through gzip. This permits better performance when the database is not in the same location.
boolean
false
connectTimeout
Sets the connection timeout in milliseconds.
integer
1000
socketTimeout
Sets the socket timeout in milliseconds after connection succeeds. A value of 0 disables the timeout.
integer
0
queryTimeout
Set maximum query time in ms (an error will be thrown if limit is reached). 0 or undefined meaning no timeout. This can be superseded for a query using the timeout option
int
0
rowsAsArray
Returns result-sets as arrays, rather than JSON. This is a faster way to get results. For more information, see Query.
boolean
false
For more information, see the Connection Options documentation.
Connecting to Local Databases
When working with a local database (that is, cases where MariaDB and your Node.js application run on the same host), you can connect to MariaDB through the Unix socket or Windows named pipe for better performance, rather than using the TCP/IP layer.
In order to set this up, you need to assign the connection a socketPath value. When this is done, the Connector ignores the host and port options.
The specific socket path you need to set is defined by the socket server system variable. If you don't know it offhand, you can retrieve it from the server.
It defaults to /tmp/mysql.sock on Unix-like operating systems and MySQL on Windows. Additionally, on Windows, this feature only works when the server is started with the --enable-named-pipe option.
For instance, on Unix a connection might look like this:
It has a similar syntax on Windows:
createPool(options) → Pool
createPool(options) → Pool
options: JSON/String pool optionsReturns a Pool object,
Creates a new pool.
Example:
Pool options
Pool options include connection option documentation that will be used when creating new connections.
Specific options for pools are:
acquireTimeout
Timeout to get a new connection from pool. In order to have connection error information, must be higher than connectTimeout. In milliseconds.
integer
10000
connectionLimit
Maximum number of connection in pool.
integer
10
idleTimeout
Indicate idle time after which a pool connection is released. Value must be lower than @@wait_timeout. In seconds. 0 means never release.
integer
1800
initializationTimeout
Pool will retry creating connection in loop, emitting 'error' event when reaching this timeout. In milliseconds.
integer
acquireTimeout value
minimumIdle
Permit to set a minimum number of connection in pool. Recommendation is to use fixed pool, so not setting this value.
integer
set to connectionLimit value
minDelayValidation
When asking a connection to pool, the pool will validate the connection state. "minDelayValidation" permits disabling this validation if the connection has been borrowed recently avoiding useless verifications in case of frequent reuse of connections. In milliseconds. 0 means validation is done each time the connection is asked.
integer
500
noControlAfterUse
After giving back connection to pool (connection.end) connector will reset or rollback connection to ensure a valid state. This option permit to disable those controls
boolean
false
resetAfterUse
When a connection is given back to pool, reset the connection if the server allows it (only for MariaDB version >= 10.2.22 /10.3.13). If disabled or server version doesn't allows reset, pool will only rollback open transaction if any
boolean
true before version 3, false since
leakDetectionTimeout
Permit to indicate a timeout to log connection borrowed from pool. When a connection is borrowed from pool and this timeout is reached, a message will be logged to console indicating a possible connection leak. Another message will tell if the possible logged leak has been released. In milliseconds. 0 means leak detection is disabled.
integer
0
pingTimeout
Validation timeout (ping) for checking an connection not used recently from pool. In milliseconds.
integer
500
createPoolCluster(options) → PoolCluster
createPoolCluster(options) → PoolCluster
options: JSON poolCluster optionsReturns a PoolCluster object,
Creates a new pool cluster. Cluster handle multiple pools, giving high availability / distributing load (using round robin / random / ordered).
Example:
PoolCluster options
Pool cluster options include pool option documentation that will be used when creating new pools.
Specific options for a pool cluster are:
canRetry
When getting a connection from pool fails, can cluster retry with other pools
boolean
true
removeNodeErrorCount
Maximum number of consecutive connection fail from a pool before pool is removed from cluster configuration. Infinity means node won't be removed. Default to Infinity since 3.0, was 5 before
integer
Infinity
restoreNodeTimeout
delay before a pool can be reused after a connection fails. 0 = can be reused immediately (in ms)
integer
1000
defaultSelector
default pools selector. Can be 'RR' (round-robin), 'RANDOM' or 'ORDER' (use in sequence = always use first pools unless fails)
string
'RR'
importFile(options) → Promise
importFile(options) → Promise
options: JSON/String connection option documentation + one additional optionsfileReturns a promise that:
resolves with an empty result,
raises an Error.
Import an sql file
Example:
version → String
version → StringReturns a String that is a library version. example '2.1.2'.
defaultOptions(options) → Json
defaultOptions(options) → Json
options: JSON/String connection option documentation (non-mandatory)Returns a JSON value containing options default value.
Permits listing the default options that will be used.
Connection API
connection.query(sql[, values]) -> Promise
connection.query(sql[, values]) -> Promise
sql: string | JSON SQL string or JSON object to supersede default connection options. When using JSON object, object must have a "sql" key. For instance,{ dateStrings: true, sql: 'SELECT now()' }
values: array | object Placeholder values. Usually an array, but in cases of only one placeholder, it can be given as is.Returns a promise that:
resolves with a JSON object for update/insert/delete or a result-set object for a result-set.
rejects with an Error.
Sends a query to a database and return a result as a Promise.
For instance, when using an SQL string:
Alternatively, you could use the JSON object:
Placeholder
To prevent SQL Injection attacks, queries permit the use of question marks as placeholders. The Connection escapes values according to their type. Values can be of native JavaScript types, Buffers, Readables, objects with toSQLString methods, or objects that can be stringified (that is, JSON.stringify).
When streaming, objects that implement Readable are streamed automatically. But there are two server system variables that may interfere:
net_read_timeout: The server must receive queries before reaching this timeout, which defaults to 30 seconds.max_allowed_packet: This system variable defines the maximum amount of data the Connector can send to the server.
For instance,
In the case of streaming,
JSON Result-sets
Queries return two different kinds of results, depending on the type of query you execute. When you execute write statements (such as INSERT, DELETE and UPDATE), the method returns a JSON object with the following properties:
affectedRows: The number of rows affected by the operationinsertId: The auto-increment ID generated by the operation (for the first inserted row when multiple rows are inserted)warningStatus: A flag indicating whether the query generated warnings
Array Result-sets
When executing a SELECT statement, the method returns the result-set as an array of JSON objects. Each object in the array represents a row from the result-set, with column names as property keys.
The result also includes a special non-enumerable meta property containing an array of column metadata information.
Query options
The following options can be set at either the query level or the connection level. When set at the connection level, they apply to all subsequent queries.
timeout
number, timeout in ms
Sets a timeout for query execution. Only available for MariaDB server >= 10.1.2.
The driver implements this using SET STATEMENT max_statement_time=<timeout> FOR <command>, which allows the server to cancel operations that exceed the specified timeout.
Important limitation: When using multiple statements (with the multipleStatements option enabled), only the first query will be subject to the timeout.
The implementation of max_statement_time is engine-dependent and may behave differently across storage engines. For example, with the Galera engine, commits ensure replication to other nodes is completed, which might exceed the timeout to maintain proper server state.
namedPlaceholders
boolean, default false
Enables the use of named placeholders instead of question mark placeholders. When enabled, the values parameter must be an object with keys matching the placeholder names in the query.
rowsAsArray
boolean, default false
Returns rows as arrays instead of objects, which can improve performance by 5-10% with local databases and reduces memory usage by avoiding the need to parse column metadata completely.
metaAsArray
boolean, default false
A compatibility option that causes the Promise to return an array [rows, metadata] instead of rows with a meta property. This option is primarily for mysql2 compatibility.
nestTables
boolean / string, default false
Helps resolve column name conflicts in joins by grouping data by table. When set to true, results are grouped by table name. When set to a string value, it's used as a separator between table name and column name.
With boolean value:
With string value:
dateStrings
boolean, default: false
Whether you want the Connector to retrieve date values as strings, rather than Date objects.
bigIntAsNumber
boolean, default: true
Whether the query should return JavaScript ES2020 BigInt for BIGINT data type. This ensures having the expected value even for value > 2^53 (see safe range). This option can be set to query level, supplanting connection option supportBigInt value.
this option is for compatibility for driver version < 3
decimalAsNumber
boolean, default: false
Whether the query should return decimal as Number. If enabled, this might return approximate values.
typeCast
Experimental
function(column, next)
In the event that you need certain values returned as a different type, you can use this function to cast the value into that type yourself.
For instance, casting all TINYINT(1) values as boolean values:
Column Metadata
collation: Object indicates the column collation. It has the properties:index,name,encoding, andmaxlen. For instance,33, "UTF8_GENERAL_CI", "utf8", 3columnLength: Shows the column's maximum length if there's a limit and0if there is no limit, (such as with aBLOBcolumn).type: Shows the column type as a String value. For more information on the relevant values, seefield-type.jscolumnType: Shows the column type as an integer value. For more information on the relevant values, seefield-type.jsscale: Provides the decimal part length.flags: Shows the byte-encoded flags. For more information, seefield-detail.js.db(): Name of the database schema. You can also retrieve this usingschema().table(): Table alias.orgTable(): Real table name.name(): Column alias.orgName(): Real column name.
When using typeCast, additional function are available on Column, in order to decode value :
float(): float: decode FLOAT valuetiny(): int: decode TINY valueshort(): int: decode SMALLINT valueint(): int: decode INTEGER valuelong(): bigint: decode BIGINT valuedecimal(): string: decode DECIMAL valuedate(): date: decode DATE valuegeometry(): geojson: decode GEOMETRY value
connection.queryStream(sql[, values]) → Emitter
connection.queryStream(sql[, values]) → Emitter
sql: string | JSON SQL string value or JSON object to supersede default connections options. JSON objects must have an"sql"property. For instance,{ dateStrings: true, sql: 'SELECT now()' }
values: array | object Defines placeholder values. This is usually an array, but in cases of only one placeholder, it can be given as a string.Returns an Emitter object that emits different types of events:
error: Emits an
Errorobject when the query fails. (No"end"event will then be emitted).fields: Emits when column metadata from the result-set are received (the parameter is an array of Metadata fields).
data: Emits each time a row is received (parameter is a row).
end: Emits when the query ends (no parameter). > a method: close(): permits closing stream (since 3.0)
Streaming large result sets
When using the query() method, the Connector returns the entire result-set with all its data in a single call. While this works well for small result sets, it can become problematic for queries returning millions of rows, potentially causing memory issues.
The queryStream() method solves this by using Node.js's event-driven architecture to process rows one by one, significantly reducing memory usage for large result sets.
Important: The stream handles backpressure automatically, pausing the socket when data handling takes time to prevent Node.js socket buffers from growing indefinitely. If you're using a pipeline and your data handling throws an error, you must explicitly call queryStream.close() to prevent connection hangs.
Streaming implementation options
There are several ways to implement streaming:
Using for-await-of (Node.js 10+)
The simplest approach using modern JavaScript syntax:
Using event listeners
Traditional Node.js event-based approach:
Using Node.js streams
For advanced use cases, you can integrate with Node.js streams API:
connection.prepare(sql) → Promise
connection.prepare(sql) → Promise
sql: string | JSON SQL string value or JSON object to supersede default connections options. JSON objects must have an"sql"property. For instance,{ dateStrings: true, sql: 'SELECT now()' }Returns a promise that :
This permits to PREPARE a command that permits to be executed many times. After use, prepare.close() method MUST be call, in order to properly close object.
Prepare object
Public variables :
id: Prepare statement Identifierquery: sql commanddatabase: database it applies to.parameters: parameter array information.columns: column array information.
Public methods :
execute(values) → Promise
values: array | object Defines placeholder values. This is usually an array, but in cases of only one placeholder, it can be given as a string.Returns a promise that :
resolves with a JSON object for update/insert/delete or a result-set object for a result-set.
rejects with an Error.
executeStream(values) → Promise
values: array | object Defines placeholder values. This is usually an array, but in cases of only one placeholder, it can be given as a string.Returns an Emitter object that emits different types of events:
error: Emits an
Errorobject when the query fails. (No"end"event will then be emitted).data: Emits each time a row is received (parameter is a row).
end: Emits when the query ends (no parameter). > a method: close(): permits closing stream (since 3.0)
This is the equivalent of queryStream using execute.
When using the execute() method, documented above, the Connector returns the entire result-set with all its data in a single call. While this is fine for queries that return small result-sets, it can grow unmanageable in cases of huge result-sets. Instead of retrieving all the data into memory, you can use the executeStream() method, which uses the event drive architecture to process rows one by one, which allows you to avoid putting too much strain on memory.
You may want to consider updating the net_read_timeout server system variable. The resultSet must be totally received before this timeout, which defaults to 30 seconds.
for-await-of
simple use with for-await-of only available since Node.js 10 (note that this must be use within async function) :
Events
close() → void
This closes the prepared statement. Each time a Prepared object is used, it must be closed.
In case prepare cache is enabled (having option prepareCacheLength > 0 (default)), Driver will either really close Prepare or keep it in cache.
connection.execute(sql[, values]) → Promise
connection.execute(sql[, values]) → Promise
sql: string | JSON SQL string or JSON object to supersede default connection options. When using JSON object, an object must have a "sql" key. For instance,{ dateStrings: true, sql: 'SELECT now()' }
values: array | object Placeholder values. Usually an array, but in cases of only one placeholder, it can be given as is.Returns a promise that :
resolves with a JSON object for update/insert/delete or a result-set object for a result-set.
rejects with an Error.
This is quite similar to connection.query(sql [, values]) → Promise method, with a few differences: Execute will in fact PREPARE + EXECUTE + CLOSE command.
It makes sense to use this only if the command often is used and if prepare cache is enabled (default). If a PREPARE result is already in cache, only EXECUTE The command is executed. MariaDB server 10.6 even avoids resending result-set metadata if not changed since, permitting even faster results.
connection.batch(sql, values) → Promise
connection.batch(sql, values) → Promise
sql: string | JSON SQL string value or JSON object to supersede default connections options. JSON objects must have an"sql"property. For instance,{ dateStrings: true, sql: 'SELECT now()' }
values: array Array of parameter (array of array or array of objects if using named placeholders).Returns a promise that :
resolves with a JSON object.
rejects with an Error.
Implementation depends on the server type and version. for MariaDB server version 10.2.7+, the implementation uses dedicated bulk protocol.
For other, insert queries will be rewritten for optimization. example: insert into ab (i) values (?) with first batch values = 1, second = 2 will be rewritten insert into ab (i) values (1), (2).
If a query cannot be re-writen will execute a query for each value.
An option fullResult permit to indicate if user wants to retrieve individual batch results (to retrieve generated ids). This might change the performance of bathing if set, depending on a server version (for server 11.5.1 and above with MDEV-30366, bulk will be use, or pipelining if not)
For instance,
Using the fullResult option
fullResult optionBy default, batch operations aggregate results, combining all individual operations into a single result. You can use the fullResult: true option to retrieve individual results for each parameter set.
When to use fullResult
The fullResult option is particularly useful when:
You need to know which specific parameter sets succeeded or failed
You need to access individual insertId values for each inserted row.
Performance considerations
For MariaDB servers that support it (version 10.2.7+), the connector will use the optimized COM_STMT_BULK_EXECUTE protocol for better performance when possible. The fullResult option with bulk protocol requires 11.5.1.
connection.beginTransaction() → Promise
connection.beginTransaction() → PromiseReturns a promise that :
resolves (no argument)
rejects with an Error.
Begins a new transaction.
connection.commit() → Promise
connection.commit() → PromiseReturns a promise that :
resolves (no argument)
rejects with an Error.
Commits the current transaction if there is one active. The Connector tracks the current transaction state on the server. In the event that you issue the commit() method when there's no active transaction, it ignores the method and sends no commands to MariaDB.
connection.release() → Promise
connection.release() → PromiseWhen a .connection comes from pool, only connection.release() is an async method returning an empty promise success. This function will never throw an error. The default behavior is that if there is a transaction still open, a rollback command will be issued, and the connection will be released to pool.
2 options might interfere:
When resetAfterUseset, the connection will completely be reset like a fresh connectionnoControlAfterUsewhen set, no control (rollback or reset) will be done on release
connection.rollback() → Promise
connection.rollback() → PromiseReturns a promise that :
resolves (no argument)
Rejects with an Error.
Rolls back the current transaction if there is one active. The Connector tracks the current transaction state on the server. In the event that you issue the rollback() method when there's no active transaction, it ignores the method and sends no commands to MariaDB.
connection.changeUser(options) → Promise
connection.changeUser(options) → Promise
options: JSON, subset of connection option dodatabase/charset = database/charset / password/userReturns a promise that :
resolves without result
Rejects with an Error.
Resets the connection and re-authorizes it using the given credentials. It is the equivalent of creating a new connection with a new user, reusing the open socket.
connection.ping() → Promise
connection.ping() → PromiseReturns a promise that :
resolves (no argument)
rejects with an Error.
Sends a packet to the database containing one byte to check that the connection is still active.
connection.reset() → Promise
connection.reset() → PromiseReturns a promise that :
resolves (no argument)
rejects with an Error.
reset the connection. Reset will:
rollback any open transaction
reset transaction isolation level
reset session variables
delete user variables
remove temporary tables
remove all PREPARE statement
This command is only available for MariaDB >=10.2.4 or MySQL >= 5.7.3. the function will be rejected with the error "Reset command not permitted for server XXX" if the server version doesn't permit reset.
For previous MariaDB version, reset connection can be done using connection.changeUser(options) → Promise that do the same + redo authentication phase.
connection.isValid() → boolean
connection.isValid() → booleanReturns a boolean
Indicates the connection state as the Connector knows it. If it returns false, there is an issue with the connection, such as the socket disconnected without the Connector knowing about it.
connection.end() → Promise
connection.end() → PromiseReturns a promise that :
resolves (no argument)
rejects with an Error.
Closes the connection gracefully, after waiting for any currently executing queries to finish.
connection.destroy()
connection.destroy()Closes the connection without waiting for any currently executing queries. These queries are interrupted. MariaDB logs the event as an unexpected socket close.
connection.escape(value) → String
connection.escape(value) → StringThis function permits escaping a parameter properly according to a parameter type to avoid injection. See mariadb String literals for escaping.
Escaping has some limitations:
doesn't permit Stream parameters
this is less efficient compared to using standard conn.query(), that will stream data to socket, avoiding string concatenation and using memory unnecessary
escape per type:
boolean: explicit
trueorfalsenumber: string representation. ex: 123 => '123'
Date: String representation using
YYYY-MM-DD HH:mm:ss.SSSformatBuffer: _binary''
object with toSqlString function: String an escaped result of toSqlString
Array: list of escaped values. ex:
[true, "o'o"]=>('true', 'o\'o')geoJson: MariaDB transformation to corresponding geotype. ex:
{ type: 'Point', coordinates: [20, 10] }=>"ST_PointFromText('POINT(20 10)')"JSON: Stringification of JSON, or if
permitSetMultiParamEntriesis enabled, key escaped as identifier + valueString: escaped value, (\u0000, ', ", \b, \n, \r, \t, \u001A, and \ characters are escaped with '')
Escape is done for sql_mode value without NO_BACKSLASH_ESCAPES that disable \ escaping (default);
Escaping API are meant to prevent SQL injection. However, privilege the use of connection.query(sql [, values]) → Promise and avoid building the command manually.
connection.escapeId(value) → String
connection.escapeId(value) → StringThis function permits escaping an Identifier properly. See Identifier Names for escaping. Value will be enclosed by '`' character if content doesn't satisfy:
ASCII: [0-9,a-z,A-Z$_] (numerals 0–9, basic Latin letters, both lowercase and uppercase, dollar sign, underscore)
Extended: U+0080 .. U+FFFF and escaping '`' character if needed.
connection.pause()
connection.pause()Pauses data reads.
connection.resume()
connection.resume()Resumes data reads from a pause.
connection.serverVersion()
connection.serverVersion()Returns a string
Retrieves the version of the currently connected server. Throws an error when not connected to a server.
connection.importFile(options) → Promise
connection.importFile(options) → Promise
optionsJSON: > ** file: file path (mandatory) > ** database: database if different that current connection database (optional)Returns a promise that :
resolves without a result
rejects with an Error.
Import SQL file. If a database is set, the database will be used, then after file import, the database will be reverted to the previous value.
Error
ErrorWhen the Connector encounters an error, Promise returns an Error object. In addition to the standard properties, this object has the following properties:
fatal: A boolean value indicating whether the connection remains valid.errno: The error number corresponding to the MariaDB/MySQL error code.sqlState: The SQL state code following the ANSI SQL standard.code: The error code as a string identifier.
Error handling best practices
When working with the MariaDB connector, implementing proper error handling is crucial for building robust applications. Here are some recommended practices:
1. Always use try/catch with async/await
2. Check for specific error codes
The connector provides detailed error information that you can use to handle specific error scenarios:
3. Distinguish between fatal and non-fatal errors
The fatal property indicates whether the connection is still usable:
Error example
Here's an example of what an error object might look like when logged:
When the trace option is enabled, errors include the original stack trace, which helps identify where in your code the query was executed.
For a complete list of error codes and their meanings, see the MariaDB Error Codes documentation.
events
eventsConnection object that inherits from the Node.js EventEmitter. Emits an error evthe ent when the connection closes unexpectedly.
Pool API
A connection pool is a cache of database connections maintained so that connections can be reused when future requests to the database are required. Connection pools are used to enhance the performance of executing commands on a database.
Pool overview
Each time a connection is requested, if the pool contains an available connection, the pool will validate the connection by exchanging an empty MySQL packet with the server to ensure the connection is still valid, then provide the connection.
The pool reuses connections intensively to improve performance. This validation is only performed if a connection has been idle for a period (specified by the minDelayValidation option, which defaults to 500ms).
If no connection is available, the request will be queued until either:
A connection becomes available (through creation or release)
The connection timeout (
acquireTimeout) is reached
When a connection is released back to the pool, any remaining transactions will be automatically rolled back to ensure a clean state for the next use.
pool.getConnection() → Promise
pool.getConnection() → Promise
Returns a promise that: > * resolves with a Connection object
rejects with an Error
Retrieves a connection from the pool. If the pool is at its connection limit, the promise will wait until a connection becomes available or the acquireTimeout is reached.
Example: Using a pooled connection with transactions
pool.query(sql[, values]) → Promise
pool.query(sql[, values]) → Promise
sql: string | JSON SQL string or JSON object with query options
values: array | object Placeholder valuesReturns a promise that:
resolves with query results (same as connection.query())
rejects with an Error
Executes a query using a connection from the pool. The connection is automatically acquired and released, making this method ideal for simple queries.
Example: Simple query with error handling
Example: Using query options
pool.batch(sql, values) → Promise
pool.batch(sql, values) → Promise
sql: string | JSON SQL string or JSON object with query options
values: array Array of parameter sets (array of arrays or array of objects for named placeholders)Returns a promise that:
resolves with batch operation results
rejects with an Error
Executes a batch operation using a connection from the pool. The pool automatically handles connection acquisition and release.
For MariaDB server version 10.2.7+, this implementation uses a dedicated bulk protocol for improved performance.
Example: Batch insert with generated IDs
pool.end() → Promise
pool.end() → PromiseReturns a promise that:
resolves when all connections are closed
rejects with an Error if closing fails
Gracefully closes all connections in the pool and ends the pool. This should be called when your application is shutting down to ensure all database resources are properly released.
Example: Application shutdown handler
pool.escape(value) → String
pool.escape(value) → StringThis is an alias for connection.escape(value) → String to escape parameters when building queries manually.
Example:
pool.escapeId(value) → String
pool.escapeId(value) → StringThis is an alias for connection.escapeId(value) → String to escape identifiers like table or column names.
Example:
pool.importFile(options) → Promise
pool.importFile(options) → Promise
options: > *file: file path (mandatory)
database: database if different from current connection database (optional)Returns a promise that:
resolves without result
rejects with an Error
Imports an SQL file. If a database is specified, it will be used for the import and then reverted to the original database afterward.
Example: Import a database dump
Pool events
The pool object inherits from Node.js EventEmitter and emits the following events:
acquire
acquireEmitted when a connection is acquired from the pool.
connection
connectionEmitted when a new connection is created within the pool.
release
releaseEmitted when a connection is released back to the pool.
error
errorEmitted when an error occurs in the pool, such as failure to create a connection.
Pool monitoring methods
The pool provides several methods to monitor its state:
Pool best practices
Right-size your connection pool:
Set
connectionLimitbased on your application's concurrency needs and database server capacityToo few connections can create bottlenecks
Too many connections can overload the database server
Start with a connection limit of 10–20 and adjust based on performance testing
Handle connection leaks:
Always release connections:
Use connection validation wisely:
Prefer pool.query() for simple operations:
For single queries, use
pool.query()instead of manually acquiring and releasing connectionsOnly use
getConnection()when you need to maintain context across multiple queries
Implement proper error handling:
Listen for 'error' events on the pool
Implement reconnection strategies for fatal errors
Consider using a circuit breaker pattern for persistent database issues
Close the pool during application shutdown:
Always call
pool.end()when your application terminatesUse process signal handlers (SIGINT, SIGTERM) to ensure proper cleanup
Pool cluster API
A pool cluster manages multiple database connection pools and provides high availability and load balancing capabilities. It allows your application to:
Connect to multiple database servers (for primary/replica setups)
Automatically handle failover if a database server goes down
Distribute queries across multiple servers
Group servers by pattern for targeted operations
Pool cluster overview
The cluster manages a collection of connection pools, each identified by a name. You can select pools using pattern matching and specify different load balancing strategies (selectors) to determine which pool to use for each connection request.
When a connection fails, the cluster can automatically retry with another pool matching the same pattern. If a pool fails consistently, it can be temporarily blacklisted or even removed from the cluster configuration.
createPoolCluster(options) → PoolCluster
createPoolCluster(options) → PoolCluster
options: JSON poolCluster optionsReturns a PoolCluster object
Creates a new pool cluster to manage multiple database connection pools.
Example: Creating a basic primary/replica setup
poolCluster.add(id, config)
poolCluster.add(id, config)
id: string node identifier. Example:'primary','replica1'
config: JSON pool options to create the poolReturns: void
Adds a new connection pool to the cluster with the specified identifier and configuration.
Example: Adding nodes with descriptive identifiers
poolCluster.remove(pattern)
poolCluster.remove(pattern)
pattern: string Regex pattern to select pools. Example:'replica*'Returns: void
Removes and ends all pools whose identifiers match the specified pattern.
Example: Removing nodes from the cluster
poolCluster.getConnection([pattern], [selector]) → Promise
poolCluster.getConnection([pattern], [selector]) → Promise
pattern: string Regex pattern to select pools. Default:'*'(all pools)
selector: string Selection strategy: 'RR' (round-robin), 'RANDOM', or 'ORDER'. Default: value of thedefaultSelectoroptionReturns a promise that:
resolves with a Connection object
rejects with an Error
Gets a connection from a pool in the cluster that matches the pattern using the specified selection strategy.
Example: Using different selectors for different connection patterns
Example: Handling failover gracefully
poolCluster.of(pattern, [selector]) → FilteredPoolCluster
poolCluster.of(pattern, [selector]) → FilteredPoolCluster
pattern: string Regex pattern to select pools. Example:'replica*'
selector: string Selection strategy: 'RR' (round-robin), 'RANDOM', or 'ORDER'Returns a FilteredPoolCluster object
Creates a new filtered pool cluster that only includes pools matching the specified pattern. This allows you to create specialized interfaces for different database roles.
Example: Creating dedicated interfaces for read and write operations
poolCluster.end() → Promise
poolCluster.end() → PromiseReturns a promise that:
resolves when all pools in the cluster are closed
rejects with an Error if closing fails
Gracefully closes all connection pools in the cluster.
Example: Application shutdown with clustered connections
FilteredPoolCluster
A filtered pool cluster is a subset of the main cluster that only includes pools matching a specific pattern. It provides a simplified interface for working with logically grouped database nodes.
filteredPoolCluster.getConnection() → Promise
filteredPoolCluster.getConnection() → PromiseReturns a promise that:
resolves with a Connection object
rejects with an Error
Gets a connection from one of the pools in the filtered cluster using the selector specified when the filtered cluster was created.
Example:
filteredPoolCluster.query(sql[, values]) → Promise
filteredPoolCluster.query(sql[, values]) → Promise
sql: string | JSON SQL string or JSON object with query options
values: array | object Placeholder valuesReturns a promise that:
resolves with query results
rejects with an Error
Shorthand method to get a connection from the filtered cluster, execute a query, and release the connection.
Example:
Pool Cluster Events
The pool cluster inherits from Node.js EventEmitter and emits the following events:
remove
removeEmitted when a node is removed from the cluster configuration. This happens when a node fails to connect more than removeNodeErrorCount times (if this option is defined).
Selection Strategies
The pool cluster supports three different selection strategies for choosing which database node to use:
Round-Robin (
'RR'): Uses pools in rotation, ensuring an even distribution of connections.Random (
'RANDOM'): Selects a random pool for each connection request.Order (
'ORDER'): Always tries pools in sequence, using the first available one. Useful for primary/fallback setups.
Pool Cluster Best Practices
Use meaningful node identifiers:
Choose clear identifiers that indicate the node's role (e.g., 'primary', 'replica1')
This makes pattern matching more intuitive and maintenance easier
Implement role-based access with patterns:
Use appropriate selectors for different scenarios:
'ORDER'for high availability with failover (tries primary first, then fallbacks)'RR'for load balancing across equivalent nodes (like replicas)'RANDOM'when pure distribution is needed
Configure node removal thresholds appropriately:
Monitor removed nodes:
Implement graceful degradation:
Design your application to function with reduced capabilities when some nodes are unavailable.
Use fallback strategies when specific node patterns become unavailable
Always close the cluster during application shutdown:
Call
cluster.end()to properly release all resourcesUse process signal handlers to ensure cleanup.
Last updated
Was this helpful?

