SQLite | Node.js v25.2.1 Documentation (original) (raw)

Source Code: lib/sqlite.js

The node:sqlite module facilitates working with SQLite databases. To access it:

import sqlite from 'node:sqlite'; const sqlite = require('node:sqlite');

This module is only available under the node: scheme.

The following example shows the basic usage of the node:sqlite module to open an in-memory database, write data to the database, and then read the data back.

`` import { DatabaseSync } from 'node:sqlite'; const database = new DatabaseSync(':memory:');

// Execute SQL statements from strings. database.exec( CREATE TABLE data( key INTEGER PRIMARY KEY, value TEXT ) STRICT); // Create a prepared statement to insert data into the database. const insert = database.prepare('INSERT INTO data (key, value) VALUES (?, ?)'); // Execute the prepared statement with bound values. insert.run(1, 'hello'); insert.run(2, 'world'); // Create a prepared statement to read data from the database. const query = database.prepare('SELECT * FROM data ORDER BY key'); // Execute the prepared statement and log the result set. console.log(query.all()); // Prints: [ { key: 1, value: 'hello' }, { key: 2, value: 'world' } ] 'use strict'; const { DatabaseSync } = require('node:sqlite'); const database = new DatabaseSync(':memory:');

// Execute SQL statements from strings. database.exec( CREATE TABLE data( key INTEGER PRIMARY KEY, value TEXT ) STRICT); // Create a prepared statement to insert data into the database. const insert = database.prepare('INSERT INTO data (key, value) VALUES (?, ?)'); // Execute the prepared statement with bound values. insert.run(1, 'hello'); insert.run(2, 'world'); // Create a prepared statement to read data from the database. const query = database.prepare('SELECT * FROM data ORDER BY key'); // Execute the prepared statement and log the result set. console.log(query.all()); // Prints: [ { key: 1, value: 'hello' }, { key: 2, value: 'world' } ] ``

Class: DatabaseSync#

This class represents a single connection to a SQLite database. All APIs exposed by this class execute synchronously.

new DatabaseSync(path[, options])#

Constructs a new DatabaseSync instance.

database.aggregate(name, options)#

Added in: v24.0.0, v22.16.0

Registers a new aggregate function with the SQLite database. This method is a wrapper aroundsqlite3_create_window_function().

When used as a window function, the result function will be called multiple times.

`` const { DatabaseSync } = require('node:sqlite');

const db = new DatabaseSync(':memory:'); db.exec( CREATE TABLE t3(x, y); INSERT INTO t3 VALUES ('a', 4), ('b', 5), ('c', 3), ('d', 8), ('e', 1););

db.aggregate('sumint', { start: 0, step: (acc, value) => acc + value, });

db.prepare('SELECT sumint(y) as total FROM t3').get(); // { total: 21 } import { DatabaseSync } from 'node:sqlite';

const db = new DatabaseSync(':memory:'); db.exec( CREATE TABLE t3(x, y); INSERT INTO t3 VALUES ('a', 4), ('b', 5), ('c', 3), ('d', 8), ('e', 1););

db.aggregate('sumint', { start: 0, step: (acc, value) => acc + value, });

db.prepare('SELECT sumint(y) as total FROM t3').get(); // { total: 21 } ``

database.close()#

Added in: v22.5.0

Closes the database connection. An exception is thrown if the database is not open. This method is a wrapper around sqlite3_close_v2().

database.loadExtension(path)#

Added in: v23.5.0, v22.13.0

Loads a shared library into the database connection. This method is a wrapper around sqlite3_load_extension(). It is required to enable theallowExtension option when constructing the DatabaseSync instance.

database.enableLoadExtension(allow)#

Added in: v23.5.0, v22.13.0

Enables or disables the loadExtension SQL function, and the loadExtension()method. When allowExtension is false when constructing, you cannot enable loading extensions for security reasons.

database.enableDefensive(active)#

Added in: v25.1.0

Enables or disables the defensive flag. When the defensive flag is active, language features that allow ordinary SQL to deliberately corrupt the database file are disabled. See SQLITE_DBCONFIG_DEFENSIVE in the SQLite documentation for details.

database.location([dbName])#

Added in: v24.0.0, v22.16.0

This method is a wrapper around sqlite3_db_filename()

database.exec(sql)#

Added in: v22.5.0

This method allows one or more SQL statements to be executed without returning any results. This method is useful when executing SQL statements read from a file. This method is a wrapper around sqlite3_exec().

database.function(name[, options], function)#

Added in: v23.5.0, v22.13.0

This method is used to create SQLite user-defined functions. This method is a wrapper around sqlite3_create_function_v2().

database.setAuthorizer(callback)

Added in: v24.10.0

Sets an authorizer callback that SQLite will invoke whenever it attempts to access data or modify the database schema through prepared statements. This can be used to implement security policies, audit access, or restrict certain operations. This method is a wrapper around sqlite3_set_authorizer().

When invoked, the callback receives five arguments:

The callback must return one of the following constants:

`const { DatabaseSync, constants } = require('node:sqlite'); const db = new DatabaseSync(':memory:');

// Set up an authorizer that denies all table creation db.setAuthorizer((actionCode) => { if (actionCode === constants.SQLITE_CREATE_TABLE) { return constants.SQLITE_DENY; } return constants.SQLITE_OK; });

// This will work db.prepare('SELECT 1').get();

// This will throw an error due to authorization denial try { db.exec('CREATE TABLE blocked (id INTEGER)'); } catch (err) { console.log('Operation blocked:', err.message); } import { DatabaseSync, constants } from 'node:sqlite'; const db = new DatabaseSync(':memory:');

// Set up an authorizer that denies all table creation db.setAuthorizer((actionCode) => { if (actionCode === constants.SQLITE_CREATE_TABLE) { return constants.SQLITE_DENY; } return constants.SQLITE_OK; });

// This will work db.prepare('SELECT 1').get();

// This will throw an error due to authorization denial try { db.exec('CREATE TABLE blocked (id INTEGER)'); } catch (err) { console.log('Operation blocked:', err.message); }`

database.isOpen#

Added in: v23.11.0, v22.15.0

database.isTransaction#

Added in: v24.0.0, v22.16.0

database.open()#

Added in: v22.5.0

Opens the database specified in the path argument of the DatabaseSyncconstructor. This method should only be used when the database is not opened via the constructor. An exception is thrown if the database is already open.

database.createTagStore([maxSize])#

Added in: v24.9.0

Creates a new SQLTagStore, which is an LRU (Least Recently Used) cache for storing prepared statements. This allows for the efficient reuse of prepared statements by tagging them with a unique identifier.

When a tagged SQL literal is executed, the SQLTagStore checks if a prepared statement for that specific SQL string already exists in the cache. If it does, the cached statement is used. If not, a new prepared statement is created, executed, and then stored in the cache for future use. This mechanism helps to avoid the overhead of repeatedly parsing and preparing the same SQL statements.

`` import { DatabaseSync } from 'node:sqlite';

const db = new DatabaseSync(':memory:'); const sql = db.createTagStore();

db.exec('CREATE TABLE users (id INT, name TEXT)');

// Using the 'run' method to insert data. // The tagged literal is used to identify the prepared statement. sql.runINSERT INTO users VALUES (1, 'Alice'); sql.runINSERT INTO users VALUES (2, 'Bob');

// Using the 'get' method to retrieve a single row. const id = 1; const user = sql.getSELECT * FROM users WHERE id = ${id}; console.log(user); // { id: 1, name: 'Alice' }

// Using the 'all' method to retrieve all rows. const allUsers = sql.allSELECT * FROM users ORDER BY id; console.log(allUsers); // [ // { id: 1, name: 'Alice' }, // { id: 2, name: 'Bob' } // ] const { DatabaseSync } = require('node:sqlite');

const db = new DatabaseSync(':memory:'); const sql = db.createTagStore();

db.exec('CREATE TABLE users (id INT, name TEXT)');

// Using the 'run' method to insert data. // The tagged literal is used to identify the prepared statement. sql.runINSERT INTO users VALUES (1, 'Alice'); sql.runINSERT INTO users VALUES (2, 'Bob');

// Using the 'get' method to retrieve a single row. const id = 1; const user = sql.getSELECT * FROM users WHERE id = ${id}; console.log(user); // { id: 1, name: 'Alice' }

// Using the 'all' method to retrieve all rows. const allUsers = sql.allSELECT * FROM users ORDER BY id; console.log(allUsers); // [ // { id: 1, name: 'Alice' }, // { id: 2, name: 'Bob' } // ] ``

database.createSession([options])#

Added in: v23.3.0, v22.12.0

Creates and attaches a session to the database. This method is a wrapper around sqlite3session_create() and sqlite3session_attach().

database.applyChangeset(changeset[, options])#

Added in: v23.3.0, v22.12.0

An exception is thrown if the database is not open. This method is a wrapper around sqlite3changeset_apply().

`import { DatabaseSync } from 'node:sqlite';

const sourceDb = new DatabaseSync(':memory:'); const targetDb = new DatabaseSync(':memory:');

sourceDb.exec('CREATE TABLE data(key INTEGER PRIMARY KEY, value TEXT)'); targetDb.exec('CREATE TABLE data(key INTEGER PRIMARY KEY, value TEXT)');

const session = sourceDb.createSession();

const insert = sourceDb.prepare('INSERT INTO data (key, value) VALUES (?, ?)'); insert.run(1, 'hello'); insert.run(2, 'world');

const changeset = session.changeset(); targetDb.applyChangeset(changeset); // Now that the changeset has been applied, targetDb contains the same data as sourceDb. const { DatabaseSync } = require('node:sqlite');

const sourceDb = new DatabaseSync(':memory:'); const targetDb = new DatabaseSync(':memory:');

sourceDb.exec('CREATE TABLE data(key INTEGER PRIMARY KEY, value TEXT)'); targetDb.exec('CREATE TABLE data(key INTEGER PRIMARY KEY, value TEXT)');

const session = sourceDb.createSession();

const insert = sourceDb.prepare('INSERT INTO data (key, value) VALUES (?, ?)'); insert.run(1, 'hello'); insert.run(2, 'world');

const changeset = session.changeset(); targetDb.applyChangeset(changeset); // Now that the changeset has been applied, targetDb contains the same data as sourceDb.`

database[Symbol.dispose]()#

Closes the database connection. If the database connection is already closed then this is a no-op.

Class: Session#

Added in: v23.3.0, v22.12.0

session.changeset()#

Added in: v23.3.0, v22.12.0

Retrieves a changeset containing all changes since the changeset was created. Can be called multiple times. An exception is thrown if the database or the session is not open. This method is a wrapper around sqlite3session_changeset().

session.patchset()#

Added in: v23.3.0, v22.12.0

Similar to the method above, but generates a more compact patchset. See Changesets and Patchsetsin the documentation of SQLite. An exception is thrown if the database or the session is not open. This method is a wrapper around sqlite3session_patchset().

session.close().#

Closes the session. An exception is thrown if the database or the session is not open. This method is a wrapper around sqlite3session_delete().

Class: StatementSync#

Added in: v22.5.0

This class represents a single prepared statement. This class cannot be instantiated via its constructor. Instead, instances are created via thedatabase.prepare() method. All APIs exposed by this class execute synchronously.

A prepared statement is an efficient binary representation of the SQL used to create it. Prepared statements are parameterizable, and can be invoked multiple times with different bound values. Parameters also offer protection againstSQL injection attacks. For these reasons, prepared statements are preferred over hand-crafted SQL strings when handling user input.

statement.all([namedParameters][, ...anonymousParameters])#

This method executes a prepared statement and returns all results as an array of objects. If the prepared statement does not return any results, this method returns an empty array. The prepared statement parameters are bound using the values in namedParameters and anonymousParameters.

statement.columns()#

Added in: v23.11.0, v22.16.0

This method is used to retrieve information about the columns returned by the prepared statement.

statement.expandedSQL#

Added in: v22.5.0

The source SQL text of the prepared statement with parameter placeholders replaced by the values that were used during the most recent execution of this prepared statement. This property is a wrapper aroundsqlite3_expanded_sql().

statement.get([namedParameters][, ...anonymousParameters])#

This method executes a prepared statement and returns the first result as an object. If the prepared statement does not return any results, this method returns undefined. The prepared statement parameters are bound using the values in namedParameters and anonymousParameters.

statement.iterate([namedParameters][, ...anonymousParameters])#

This method executes a prepared statement and returns an iterator of objects. If the prepared statement does not return any results, this method returns an empty iterator. The prepared statement parameters are bound using the values in namedParameters and anonymousParameters.

statement.run([namedParameters][, ...anonymousParameters])#

This method executes a prepared statement and returns an object summarizing the resulting changes. The prepared statement parameters are bound using the values in namedParameters and anonymousParameters.

statement.setAllowBareNamedParameters(enabled)#

Added in: v22.5.0

The names of SQLite parameters begin with a prefix character. By default,node:sqlite requires that this prefix character is present when binding parameters. However, with the exception of dollar sign character, these prefix characters also require extra quoting when used in object keys.

To improve ergonomics, this method can be used to also allow bare named parameters, which do not require the prefix character in JavaScript code. There are several caveats to be aware of when enabling bare named parameters:

statement.setAllowUnknownNamedParameters(enabled)#

Added in: v23.11.0, v22.15.0

By default, if an unknown name is encountered while binding parameters, an exception is thrown. This method allows unknown named parameters to be ignored.

statement.setReturnArrays(enabled)#

Added in: v24.0.0, v22.16.0

When enabled, query results returned by the all(), get(), and iterate() methods will be returned as arrays instead of objects.

statement.setReadBigInts(enabled)#

Added in: v22.5.0

When reading from the database, SQLite INTEGERs are mapped to JavaScript numbers by default. However, SQLite INTEGERs can store values larger than JavaScript numbers are capable of representing. In such cases, this method can be used to read INTEGER data using JavaScript BigInts. This method has no impact on database write operations where numbers and BigInts are both supported at all times.

statement.sourceSQL#

Added in: v22.5.0

The source SQL text of the prepared statement. This property is a wrapper around sqlite3_sql().

Class: SQLTagStore#

Added in: v24.9.0

This class represents a single LRU (Least Recently Used) cache for storing prepared statements.

Instances of this class are created via the database.createTagStore() method, not by using a constructor. The store caches prepared statements based on the provided SQL query string. When the same query is seen again, the store retrieves the cached statement and safely applies the new values through parameter binding, thereby preventing attacks like SQL injection.

The cache has a maxSize that defaults to 1000 statements, but a custom size can be provided (e.g., database.createTagStore(100)). All APIs exposed by this class execute synchronously.

sqlTagStore.all(sqlTemplate[, ...values])#

Added in: v24.9.0

Executes the given SQL query and returns all resulting rows as an array of objects.

sqlTagStore.get(sqlTemplate[, ...values])#

Added in: v24.9.0

Executes the given SQL query and returns the first resulting row as an object.

sqlTagStore.iterate(sqlTemplate[, ...values])#

Added in: v24.9.0

Executes the given SQL query and returns an iterator over the resulting rows.

sqlTagStore.run(sqlTemplate[, ...values])#

Added in: v24.9.0

Executes the given SQL query, which is expected to not return any rows (e.g., INSERT, UPDATE, DELETE).

sqlTagStore.size()#

Added in: v24.9.0

A read-only property that returns the number of prepared statements currently in the cache.

sqlTagStore.capacity#

Added in: v24.9.0

A read-only property that returns the maximum number of prepared statements the cache can hold.

sqlTagStore.db#

Added in: v24.9.0

A read-only property that returns the DatabaseSync object associated with this SQLTagStore.

sqlTagStore.reset()#

Added in: v24.9.0

Resets the LRU cache, clearing all stored prepared statements.

sqlTagStore.clear()#

Added in: v24.9.0

An alias for sqlTagStore.reset().

Type conversion between JavaScript and SQLite#

When Node.js writes to or reads from SQLite it is necessary to convert between JavaScript data types and SQLite's data types. Because JavaScript supports more data types than SQLite, only a subset of JavaScript types are supported. Attempting to write an unsupported data type to SQLite will result in an exception.

SQLite JavaScript
NULL
INTEGER or
REAL
TEXT
BLOB or

sqlite.backup(sourceDb, path[, options])#

This method makes a database backup. This method abstracts the sqlite3_backup_init(), sqlite3_backup_step()and sqlite3_backup_finish() functions.

The backed-up database can be used normally during the backup process. Mutations coming from the same connection - same - object will be reflected in the backup right away. However, mutations from other connections will cause the backup process to restart.

`const { backup, DatabaseSync } = require('node:sqlite');

(async () => { const sourceDb = new DatabaseSync('source.db'); const totalPagesTransferred = await backup(sourceDb, 'backup.db', { rate: 1, // Copy one page at a time. progress: ({ totalPages, remainingPages }) => { console.log('Backup in progress', { totalPages, remainingPages }); }, });

console.log('Backup completed', totalPagesTransferred); })(); import { backup, DatabaseSync } from 'node:sqlite';

const sourceDb = new DatabaseSync('source.db'); const totalPagesTransferred = await backup(sourceDb, 'backup.db', { rate: 1, // Copy one page at a time. progress: ({ totalPages, remainingPages }) => { console.log('Backup in progress', { totalPages, remainingPages }); }, });

console.log('Backup completed', totalPagesTransferred);`

sqlite.constants#

Added in: v23.5.0, v22.13.0

An object containing commonly used constants for SQLite operations.

SQLite constants#

The following constants are exported by the sqlite.constants object.

Conflict resolution constants#

One of the following constants is available as an argument to the onConflictconflict resolution handler passed to database.applyChangeset(). See alsoConstants Passed To The Conflict Handler in the SQLite documentation.

Constant Description
SQLITE_CHANGESET_DATA The conflict handler is invoked with this constant when processing a DELETE or UPDATE change if a row with the required PRIMARY KEY fields is present in the database, but one or more other (non primary-key) fields modified by the update do not contain the expected "before" values.
SQLITE_CHANGESET_NOTFOUND The conflict handler is invoked with this constant when processing a DELETE or UPDATE change if a row with the required PRIMARY KEY fields is not present in the database.
SQLITE_CHANGESET_CONFLICT This constant is passed to the conflict handler while processing an INSERT change if the operation would result in duplicate primary key values.
SQLITE_CHANGESET_CONSTRAINT If foreign key handling is enabled, and applying a changeset leaves the database in a state containing foreign key violations, the conflict handler is invoked with this constant exactly once before the changeset is committed. If the conflict handler returns SQLITE_CHANGESET_OMIT, the changes, including those that caused the foreign key constraint violation, are committed. Or, if it returns SQLITE_CHANGESET_ABORT, the changeset is rolled back.
SQLITE_CHANGESET_FOREIGN_KEY If any other constraint violation occurs while applying a change (i.e. a UNIQUE, CHECK or NOT NULL constraint), the conflict handler is invoked with this constant.

One of the following constants must be returned from the onConflict conflict resolution handler passed to database.applyChangeset(). See alsoConstants Returned From The Conflict Handler in the SQLite documentation.

Constant Description
SQLITE_CHANGESET_OMIT Conflicting changes are omitted.
SQLITE_CHANGESET_REPLACE Conflicting changes replace existing values. Note that this value can only be returned when the type of conflict is either SQLITE_CHANGESET_DATA or SQLITE_CHANGESET_CONFLICT.
SQLITE_CHANGESET_ABORT Abort when a change encounters a conflict and roll back database.
Authorization constants#

The following constants are used with the database.setAuthorizer() method.

Authorization result codes#

One of the following constants must be returned from the authorizer callback function passed to database.setAuthorizer().

Constant Description
SQLITE_OK Allow the operation to proceed normally.
SQLITE_DENY Deny the operation and cause an error to be returned.
SQLITE_IGNORE Ignore the operation and continue as if it had never been requested.
Authorization action codes#

The following constants are passed as the first argument to the authorizer callback function to indicate what type of operation is being authorized.

Constant Description
SQLITE_CREATE_INDEX Create an index
SQLITE_CREATE_TABLE Create a table
SQLITE_CREATE_TEMP_INDEX Create a temporary index
SQLITE_CREATE_TEMP_TABLE Create a temporary table
SQLITE_CREATE_TEMP_TRIGGER Create a temporary trigger
SQLITE_CREATE_TEMP_VIEW Create a temporary view
SQLITE_CREATE_TRIGGER Create a trigger
SQLITE_CREATE_VIEW Create a view
SQLITE_DELETE Delete from a table
SQLITE_DROP_INDEX Drop an index
SQLITE_DROP_TABLE Drop a table
SQLITE_DROP_TEMP_INDEX Drop a temporary index
SQLITE_DROP_TEMP_TABLE Drop a temporary table
SQLITE_DROP_TEMP_TRIGGER Drop a temporary trigger
SQLITE_DROP_TEMP_VIEW Drop a temporary view
SQLITE_DROP_TRIGGER Drop a trigger
SQLITE_DROP_VIEW Drop a view
SQLITE_INSERT Insert into a table
SQLITE_PRAGMA Execute a PRAGMA statement
SQLITE_READ Read from a table
SQLITE_SELECT Execute a SELECT statement
SQLITE_TRANSACTION Begin, commit, or rollback a transaction
SQLITE_UPDATE Update a table
SQLITE_ATTACH Attach a database
SQLITE_DETACH Detach a database
SQLITE_ALTER_TABLE Alter a table
SQLITE_REINDEX Reindex
SQLITE_ANALYZE Analyze the database
SQLITE_CREATE_VTABLE Create a virtual table
SQLITE_DROP_VTABLE Drop a virtual table
SQLITE_FUNCTION Use a function
SQLITE_SAVEPOINT Create, release, or rollback a savepoint
SQLITE_COPY Copy data (legacy)
SQLITE_RECURSIVE Recursive query