Skip to content

Commit b313949

Browse files
cjihrigaduh95
authored andcommitted
lib,src,test,doc: add node:sqlite module
PR-URL: #53752 Fixes: #53264 Reviewed-By: Michaël Zasso <[email protected]> Reviewed-By: James M Snell <[email protected]> Reviewed-By: Benjamin Gruenbaum <[email protected]> Reviewed-By: Vinícius Lourenço Claro Cardoso <[email protected]> Reviewed-By: Yagiz Nizipli <[email protected]> Reviewed-By: Paolo Insogna <[email protected]> Reviewed-By: Matteo Collina <[email protected]> Reviewed-By: Stephen Belanger <[email protected]> Reviewed-By: Chemi Atlow <[email protected]>
1 parent 362875b commit b313949

18 files changed

+1872
-3
lines changed

doc/api/cli.md

+10
Original file line numberDiff line numberDiff line change
@@ -1045,6 +1045,14 @@ added:
10451045

10461046
Use this flag to enable [ShadowRealm][] support.
10471047

1048+
### `--experimental-sqlite`
1049+
1050+
<!-- YAML
1051+
added: REPLACEME
1052+
-->
1053+
1054+
Enable the experimental [`node:sqlite`][] module.
1055+
10481056
### `--experimental-test-coverage`
10491057

10501058
<!-- YAML
@@ -2893,6 +2901,7 @@ one is included in the list below.
28932901
* `--experimental-require-module`
28942902
* `--experimental-shadow-realm`
28952903
* `--experimental-specifier-resolution`
2904+
* `--experimental-sqlite`
28962905
* `--experimental-top-level-await`
28972906
* `--experimental-vm-modules`
28982907
* `--experimental-wasi-unstable-preview1`
@@ -3458,6 +3467,7 @@ node --stack-trace-limit=12 -p -e "Error.stackTraceLimit" # prints 12
34583467
[`dnsPromises.lookup()`]: dns.md#dnspromiseslookuphostname-options
34593468
[`import` specifier]: esm.md#import-specifiers
34603469
[`net.getDefaultAutoSelectFamilyAttemptTimeout()`]: net.md#netgetdefaultautoselectfamilyattempttimeout
3470+
[`node:sqlite`]: sqlite.md
34613471
[`process.setUncaughtExceptionCaptureCallback()`]: process.md#processsetuncaughtexceptioncapturecallbackfn
34623472
[`process.setuid()`]: process.md#processsetuidid
34633473
[`setuid(2)`]: https://man7.org/linux/man-pages/man2/setuid.2.html

doc/api/errors.md

+11
Original file line numberDiff line numberDiff line change
@@ -2580,6 +2580,16 @@ disconnected socket.
25802580

25812581
A call was made and the UDP subsystem was not running.
25822582

2583+
<a id="ERR_SQLITE_ERROR"></a>
2584+
2585+
### `ERR_SQLITE_ERROR`
2586+
2587+
<!-- YAML
2588+
added: REPLACEME
2589+
-->
2590+
2591+
An error was returned from [SQLite][].
2592+
25832593
<a id="ERR_SRI_PARSE"></a>
25842594

25852595
### `ERR_SRI_PARSE`
@@ -4013,6 +4023,7 @@ An error occurred trying to allocate memory. This should never happen.
40134023
[Node.js error codes]: #nodejs-error-codes
40144024
[Permission Model]: permissions.md#permission-model
40154025
[RFC 7230 Section 3]: https://tools.ietf.org/html/rfc7230#section-3
4026+
[SQLite]: sqlite.md
40164027
[Subresource Integrity specification]: https://www.w3.org/TR/SRI/#the-integrity-attribute
40174028
[V8's stack trace API]: https://v8.dev/docs/stack-trace-api
40184029
[WHATWG Supported Encodings]: util.md#whatwg-supported-encodings

doc/api/index.md

+1
Original file line numberDiff line numberDiff line change
@@ -53,6 +53,7 @@
5353
* [REPL](repl.md)
5454
* [Report](report.md)
5555
* [Single executable applications](single-executable-applications.md)
56+
* [SQLite](sqlite.md)
5657
* [Stream](stream.md)
5758
* [String decoder](string_decoder.md)
5859
* [Test runner](test.md)

doc/api/sqlite.md

+328
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,328 @@
1+
# SQLite
2+
3+
<!--introduced_in=REPLACEME-->
4+
5+
<!-- YAML
6+
added: REPLACEME
7+
-->
8+
9+
> Stability: 1.1 - Active development
10+
11+
<!-- source_link=lib/sqlite.js -->
12+
13+
The `node:sqlite` module facilitates working with SQLite databases.
14+
To access it:
15+
16+
```mjs
17+
import sqlite from 'node:sqlite';
18+
```
19+
20+
```cjs
21+
const sqlite = require('node:sqlite');
22+
```
23+
24+
This module is only available under the `node:` scheme. The following will not
25+
work:
26+
27+
```mjs
28+
import sqlite from 'sqlite';
29+
```
30+
31+
```cjs
32+
const sqlite = require('sqlite');
33+
```
34+
35+
The following example shows the basic usage of the `node:sqlite` module to open
36+
an in-memory database, write data to the database, and then read the data back.
37+
38+
```mjs
39+
import { DatabaseSync } from 'node:sqlite';
40+
const database = new DatabaseSync(':memory:');
41+
42+
// Execute SQL statements from strings.
43+
database.exec(`
44+
CREATE TABLE data(
45+
key INTEGER PRIMARY KEY,
46+
value TEXT
47+
) STRICT
48+
`);
49+
// Create a prepared statement to insert data into the database.
50+
const insert = database.prepare('INSERT INTO data (key, value) VALUES (?, ?)');
51+
// Execute the prepared statement with bound values.
52+
insert.run(1, 'hello');
53+
insert.run(2, 'world');
54+
// Create a prepared statement to read data from the database.
55+
const query = database.prepare('SELECT * FROM data ORDER BY key');
56+
// Execute the prepared statement and log the result set.
57+
console.log(query.all());
58+
// Prints: [ { key: 1, value: 'hello' }, { key: 2, value: 'world' } ]
59+
```
60+
61+
```cjs
62+
'use strict';
63+
const { DatabaseSync } = require('node:sqlite');
64+
const database = new DatabaseSync(':memory:');
65+
66+
// Execute SQL statements from strings.
67+
database.exec(`
68+
CREATE TABLE data(
69+
key INTEGER PRIMARY KEY,
70+
value TEXT
71+
) STRICT
72+
`);
73+
// Create a prepared statement to insert data into the database.
74+
const insert = database.prepare('INSERT INTO data (key, value) VALUES (?, ?)');
75+
// Execute the prepared statement with bound values.
76+
insert.run(1, 'hello');
77+
insert.run(2, 'world');
78+
// Create a prepared statement to read data from the database.
79+
const query = database.prepare('SELECT * FROM data ORDER BY key');
80+
// Execute the prepared statement and log the result set.
81+
console.log(query.all());
82+
// Prints: [ { key: 1, value: 'hello' }, { key: 2, value: 'world' } ]
83+
```
84+
85+
## Class: `DatabaseSync`
86+
87+
<!-- YAML
88+
added: REPLACEME
89+
-->
90+
91+
This class represents a single [connection][] to a SQLite database. All APIs
92+
exposed by this class execute synchronously.
93+
94+
### `new DatabaseSync(location[, options])`
95+
96+
<!-- YAML
97+
added: REPLACEME
98+
-->
99+
100+
* `location` {string} The location of the database. A SQLite database can be
101+
stored in a file or completely [in memory][]. To use a file-backed database,
102+
the location should be a file path. To use an in-memory database, the location
103+
should be the special name `':memory:'`.
104+
* `options` {Object} Configuration options for the database connection. The
105+
following options are supported:
106+
* `open` {boolean} If `true`, the database is opened by the constructor. When
107+
this value is `false`, the database must be opened via the `open()` method.
108+
**Default:** `true`.
109+
110+
Constructs a new `DatabaseSync` instance.
111+
112+
### `database.close()`
113+
114+
<!-- YAML
115+
added: REPLACEME
116+
-->
117+
118+
Closes the database connection. An exception is thrown if the database is not
119+
open. This method is a wrapper around [`sqlite3_close_v2()`][].
120+
121+
### `database.exec(sql)`
122+
123+
<!-- YAML
124+
added: REPLACEME
125+
-->
126+
127+
* `sql` {string} A SQL string to execute.
128+
129+
This method allows one or more SQL statements to be executed without returning
130+
any results. This method is useful when executing SQL statements read from a
131+
file. This method is a wrapper around [`sqlite3_exec()`][].
132+
133+
### `database.open()`
134+
135+
<!-- YAML
136+
added: REPLACEME
137+
-->
138+
139+
Opens the database specified in the `location` argument of the `DatabaseSync`
140+
constructor. This method should only be used when the database is not opened via
141+
the constructor. An exception is thrown if the database is already open.
142+
143+
### `database.prepare(sql)`
144+
145+
<!-- YAML
146+
added: REPLACEME
147+
-->
148+
149+
* `sql` {string} A SQL string to compile to a prepared statement.
150+
* Returns: {StatementSync} The prepared statement.
151+
152+
Compiles a SQL statement into a [prepared statement][]. This method is a wrapper
153+
around [`sqlite3_prepare_v2()`][].
154+
155+
## Class: `StatementSync`
156+
157+
<!-- YAML
158+
added: REPLACEME
159+
-->
160+
161+
This class represents a single [prepared statement][]. This class cannot be
162+
instantiated via its constructor. Instead, instances are created via the
163+
`database.prepare()` method. All APIs exposed by this class execute
164+
synchronously.
165+
166+
A prepared statement is an efficient binary representation of the SQL used to
167+
create it. Prepared statements are parameterizable, and can be invoked multiple
168+
times with different bound values. Parameters also offer protection against
169+
[SQL injection][] attacks. For these reasons, prepared statements are preferred
170+
over hand-crafted SQL strings when handling user input.
171+
172+
### `statement.all([namedParameters][, ...anonymousParameters])`
173+
174+
<!-- YAML
175+
added: REPLACEME
176+
-->
177+
178+
* `namedParameters` {Object} An optional object used to bind named parameters.
179+
The keys of this object are used to configure the mapping.
180+
* `...anonymousParameters` {null|number|bigint|string|Buffer|Uint8Array} Zero or
181+
more values to bind to anonymous parameters.
182+
* Returns: {Array} An array of objects. Each object corresponds to a row
183+
returned by executing the prepared statement. The keys and values of each
184+
object correspond to the column names and values of the row.
185+
186+
This method executes a prepared statement and returns all results as an array of
187+
objects. If the prepared statement does not return any results, this method
188+
returns an empty array. The prepared statement [parameters are bound][] using
189+
the values in `namedParameters` and `anonymousParameters`.
190+
191+
### `statement.expandedSQL()`
192+
193+
<!-- YAML
194+
added: REPLACEME
195+
-->
196+
197+
* Returns: {string} The source SQL expanded to include parameter values.
198+
199+
This method returns the source SQL of the prepared statement with parameter
200+
placeholders replaced by values. This method is a wrapper around
201+
[`sqlite3_expanded_sql()`][].
202+
203+
### `statement.get([namedParameters][, ...anonymousParameters])`
204+
205+
<!-- YAML
206+
added: REPLACEME
207+
-->
208+
209+
* `namedParameters` {Object} An optional object used to bind named parameters.
210+
The keys of this object are used to configure the mapping.
211+
* `...anonymousParameters` {null|number|bigint|string|Buffer|Uint8Array} Zero or
212+
more values to bind to anonymous parameters.
213+
* Returns: {Object|undefined} An object corresponding to the first row returned
214+
by executing the prepared statement. The keys and values of the object
215+
correspond to the column names and values of the row. If no rows were returned
216+
from the database then this method returns `undefined`.
217+
218+
This method executes a prepared statement and returns the first result as an
219+
object. If the prepared statement does not return any results, this method
220+
returns `undefined`. The prepared statement [parameters are bound][] using the
221+
values in `namedParameters` and `anonymousParameters`.
222+
223+
### `statement.run([namedParameters][, ...anonymousParameters])`
224+
225+
<!-- YAML
226+
added: REPLACEME
227+
-->
228+
229+
* `namedParameters` {Object} An optional object used to bind named parameters.
230+
The keys of this object are used to configure the mapping.
231+
* `...anonymousParameters` {null|number|bigint|string|Buffer|Uint8Array} Zero or
232+
more values to bind to anonymous parameters.
233+
* Returns: {Object}
234+
* `changes`: {number|bigint} The number of rows modified, inserted, or deleted
235+
by the most recently completed `INSERT`, `UPDATE`, or `DELETE` statement.
236+
This field is either a number or a `BigInt` depending on the prepared
237+
statement's configuration. This property is the result of
238+
[`sqlite3_changes64()`][].
239+
* `lastInsertRowid`: {number|bigint} The most recently inserted rowid. This
240+
field is either a number or a `BigInt` depending on the prepared statement's
241+
configuration. This property is the result of
242+
[`sqlite3_last_insert_rowid()`][].
243+
244+
This method executes a prepared statement and returns an object summarizing the
245+
resulting changes. The prepared statement [parameters are bound][] using the
246+
values in `namedParameters` and `anonymousParameters`.
247+
248+
### `statement.setAllowBareNamedParameters(enabled)`
249+
250+
<!-- YAML
251+
added: REPLACEME
252+
-->
253+
254+
* `enabled` {boolean} Enables or disables support for binding named parameters
255+
without the prefix character.
256+
257+
The names of SQLite parameters begin with a prefix character. By default,
258+
`node:sqlite` requires that this prefix character is present when binding
259+
parameters. However, with the exception of dollar sign character, these
260+
prefix characters also require extra quoting when used in object keys.
261+
262+
To improve ergonomics, this method can be used to also allow bare named
263+
parameters, which do not require the prefix character in JavaScript code. There
264+
are several caveats to be aware of when enabling bare named parameters:
265+
266+
* The prefix character is still required in SQL.
267+
* The prefix character is still allowed in JavaScript. In fact, prefixed names
268+
will have slightly better binding performance.
269+
* Using ambiguous named parameters, such as `$k` and `@k`, in the same prepared
270+
statement will result in an exception as it cannot be determined how to bind
271+
a bare name.
272+
273+
### `statement.setReadBigInts(enabled)`
274+
275+
<!-- YAML
276+
added: REPLACEME
277+
-->
278+
279+
* `enabled` {boolean} Enables or disables the use of `BigInt`s when reading
280+
`INTEGER` fields from the database.
281+
282+
When reading from the database, SQLite `INTEGER`s are mapped to JavaScript
283+
numbers by default. However, SQLite `INTEGER`s can store values larger than
284+
JavaScript numbers are capable of representing. In such cases, this method can
285+
be used to read `INTEGER` data using JavaScript `BigInt`s. This method has no
286+
impact on database write operations where numbers and `BigInt`s are both
287+
supported at all times.
288+
289+
### `statement.sourceSQL()`
290+
291+
<!-- YAML
292+
added: REPLACEME
293+
-->
294+
295+
* Returns: {string} The source SQL used to create this prepared statement.
296+
297+
This method returns the source SQL of the prepared statement. This method is a
298+
wrapper around [`sqlite3_sql()`][].
299+
300+
### Type conversion between JavaScript and SQLite
301+
302+
When Node.js writes to or reads from SQLite it is necessary to convert between
303+
JavaScript data types and SQLite's [data types][]. Because JavaScript supports
304+
more data types than SQLite, only a subset of JavaScript types are supported.
305+
Attempting to write an unsupported data type to SQLite will result in an
306+
exception.
307+
308+
| SQLite | JavaScript |
309+
| --------- | -------------------- |
310+
| `NULL` | `null` |
311+
| `INTEGER` | `number` or `BigInt` |
312+
| `REAL` | `number` |
313+
| `TEXT` | `string` |
314+
| `BLOB` | `Uint8Array` |
315+
316+
[SQL injection]: https://en.wikipedia.org/wiki/SQL_injection
317+
[`sqlite3_changes64()`]: https://www.sqlite.org/c3ref/changes.html
318+
[`sqlite3_close_v2()`]: https://www.sqlite.org/c3ref/close.html
319+
[`sqlite3_exec()`]: https://www.sqlite.org/c3ref/exec.html
320+
[`sqlite3_expanded_sql()`]: https://www.sqlite.org/c3ref/expanded_sql.html
321+
[`sqlite3_last_insert_rowid()`]: https://www.sqlite.org/c3ref/last_insert_rowid.html
322+
[`sqlite3_prepare_v2()`]: https://www.sqlite.org/c3ref/prepare.html
323+
[`sqlite3_sql()`]: https://www.sqlite.org/c3ref/expanded_sql.html
324+
[connection]: https://www.sqlite.org/c3ref/sqlite3.html
325+
[data types]: https://www.sqlite.org/datatype3.html
326+
[in memory]: https://www.sqlite.org/inmemorydb.html
327+
[parameters are bound]: https://www.sqlite.org/c3ref/bind_blob.html
328+
[prepared statement]: https://www.sqlite.org/c3ref/stmt.html

0 commit comments

Comments
 (0)