mirror of
https://github.com/oven-sh/bun
synced 2026-02-02 15:08:46 +00:00
SQLite in Bun.sql (#21640)
### What does this PR do? Support sqlite in the Bun.sql API Fixes #18951 Fixes #19701 ### How did you verify your code works? tests --------- Co-authored-by: autofix-ci[bot] <114827586+autofix-ci[bot]@users.noreply.github.com> Co-authored-by: Jarred Sumner <jarred@jarredsumner.com>
This commit is contained in:
369
docs/api/sql.md
369
docs/api/sql.md
@@ -1,20 +1,20 @@
|
||||
Bun provides native bindings for working with PostgreSQL databases with a modern, Promise-based API. The interface is designed to be simple and performant, using tagged template literals for queries and offering features like connection pooling, transactions, and prepared statements.
|
||||
Bun provides native bindings for working with SQL databases through a unified Promise-based API that supports both PostgreSQL and SQLite. The interface is designed to be simple and performant, using tagged template literals for queries and offering features like connection pooling, transactions, and prepared statements.
|
||||
|
||||
```ts
|
||||
import { sql } from "bun";
|
||||
import { sql, SQL } from "bun";
|
||||
|
||||
// PostgreSQL (default)
|
||||
const users = await sql`
|
||||
SELECT * FROM users
|
||||
WHERE active = ${true}
|
||||
LIMIT ${10}
|
||||
`;
|
||||
|
||||
// Select with multiple conditions
|
||||
const activeUsers = await sql`
|
||||
SELECT *
|
||||
FROM users
|
||||
WHERE active = ${true}
|
||||
AND age >= ${18}
|
||||
// With a a SQLite db
|
||||
const sqlite = new SQL("sqlite://myapp.db");
|
||||
const results = await sqlite`
|
||||
SELECT * FROM users
|
||||
WHERE active = ${1}
|
||||
`;
|
||||
```
|
||||
|
||||
@@ -44,6 +44,115 @@ const activeUsers = await sql`
|
||||
|
||||
{% /features %}
|
||||
|
||||
## Database Support
|
||||
|
||||
Bun.SQL provides a unified API for multiple database systems:
|
||||
|
||||
### PostgreSQL
|
||||
|
||||
PostgreSQL is used when:
|
||||
|
||||
- The connection string doesn't match SQLite patterns (it's the fallback adapter)
|
||||
- The connection string explicitly uses `postgres://` or `postgresql://` protocols
|
||||
- No connection string is provided and environment variables point to PostgreSQL
|
||||
|
||||
```ts
|
||||
import { sql } from "bun";
|
||||
// Uses PostgreSQL if DATABASE_URL is not set or is a PostgreSQL URL
|
||||
await sql`SELECT ...`;
|
||||
|
||||
import { SQL } from "bun";
|
||||
const pg = new SQL("postgres://user:pass@localhost:5432/mydb");
|
||||
await pg`SELECT ...`;
|
||||
```
|
||||
|
||||
### SQLite
|
||||
|
||||
SQLite support is now built into Bun.SQL, providing the same tagged template literal interface as PostgreSQL:
|
||||
|
||||
```ts
|
||||
import { SQL } from "bun";
|
||||
|
||||
// In-memory database
|
||||
const memory = new SQL(":memory:");
|
||||
const memory2 = new SQL("sqlite://:memory:");
|
||||
|
||||
// File-based database
|
||||
const db = new SQL("sqlite://myapp.db");
|
||||
|
||||
// Using options object
|
||||
const db2 = new SQL({
|
||||
adapter: "sqlite",
|
||||
filename: "./data/app.db",
|
||||
});
|
||||
|
||||
// For simple filenames, specify adapter explicitly
|
||||
const db3 = new SQL("myapp.db", { adapter: "sqlite" });
|
||||
```
|
||||
|
||||
<details>
|
||||
<summary>SQLite Connection String Formats</summary>
|
||||
|
||||
SQLite accepts various URL formats for connection strings:
|
||||
|
||||
```ts
|
||||
// Standard sqlite:// protocol
|
||||
new SQL("sqlite://path/to/database.db");
|
||||
new SQL("sqlite:path/to/database.db"); // Without slashes
|
||||
|
||||
// file:// protocol (also recognized as SQLite)
|
||||
new SQL("file://path/to/database.db");
|
||||
new SQL("file:path/to/database.db");
|
||||
|
||||
// Special :memory: database
|
||||
new SQL(":memory:");
|
||||
new SQL("sqlite://:memory:");
|
||||
new SQL("file://:memory:");
|
||||
|
||||
// Relative and absolute paths
|
||||
new SQL("sqlite://./local.db"); // Relative to current directory
|
||||
new SQL("sqlite://../parent/db.db"); // Parent directory
|
||||
new SQL("sqlite:///absolute/path.db"); // Absolute path
|
||||
|
||||
// With query parameters
|
||||
new SQL("sqlite://data.db?mode=ro"); // Read-only mode
|
||||
new SQL("sqlite://data.db?mode=rw"); // Read-write mode (no create)
|
||||
new SQL("sqlite://data.db?mode=rwc"); // Read-write-create mode (default)
|
||||
```
|
||||
|
||||
**Note:** Simple filenames without a protocol (like `"myapp.db"`) require explicitly specifying `{ adapter: "sqlite" }` to avoid ambiguity with PostgreSQL.
|
||||
|
||||
</details>
|
||||
|
||||
<details>
|
||||
<summary>SQLite-Specific Options</summary>
|
||||
|
||||
SQLite databases support additional configuration options:
|
||||
|
||||
```ts
|
||||
const db = new SQL({
|
||||
adapter: "sqlite",
|
||||
filename: "app.db",
|
||||
|
||||
// SQLite-specific options
|
||||
readonly: false, // Open in read-only mode
|
||||
create: true, // Create database if it doesn't exist
|
||||
readwrite: true, // Open for reading and writing
|
||||
|
||||
// Additional Bun:sqlite options
|
||||
strict: true, // Enable strict mode
|
||||
safeIntegers: false, // Use JavaScript numbers for integers
|
||||
});
|
||||
```
|
||||
|
||||
Query parameters in the URL are parsed to set these options:
|
||||
|
||||
- `?mode=ro` → `readonly: true`
|
||||
- `?mode=rw` → `readonly: false, create: false`
|
||||
- `?mode=rwc` → `readonly: false, create: true` (default)
|
||||
|
||||
</details>
|
||||
|
||||
### Inserting data
|
||||
|
||||
You can pass JavaScript values directly to the SQL template literal and escaping will be handled for you.
|
||||
@@ -251,14 +360,55 @@ await query;
|
||||
|
||||
## Database Environment Variables
|
||||
|
||||
`sql` connection parameters can be configured using environment variables. The client checks these variables in a specific order of precedence.
|
||||
`sql` connection parameters can be configured using environment variables. The client checks these variables in a specific order of precedence and automatically detects the database type based on the connection string format.
|
||||
|
||||
The following environment variables can be used to define the connection URL:
|
||||
### Automatic Database Detection
|
||||
|
||||
When using `Bun.sql()` without arguments or `new SQL()` with a connection string, the adapter is automatically detected based on the URL format. SQLite becomes the default adapter in these cases:
|
||||
|
||||
#### SQLite Auto-Detection
|
||||
|
||||
SQLite is automatically selected when the connection string matches these patterns:
|
||||
|
||||
- `:memory:` - In-memory database
|
||||
- `sqlite://...` - SQLite protocol URLs
|
||||
- `sqlite:...` - SQLite protocol without slashes
|
||||
- `file://...` - File protocol URLs
|
||||
- `file:...` - File protocol without slashes
|
||||
|
||||
```ts
|
||||
// These all use SQLite automatically (no adapter needed)
|
||||
const sql1 = new SQL(":memory:");
|
||||
const sql2 = new SQL("sqlite://app.db");
|
||||
const sql3 = new SQL("file://./database.db");
|
||||
|
||||
// Works with DATABASE_URL environment variable
|
||||
DATABASE_URL=":memory:" bun run app.js
|
||||
DATABASE_URL="sqlite://myapp.db" bun run app.js
|
||||
DATABASE_URL="file://./data/app.db" bun run app.js
|
||||
```
|
||||
|
||||
#### PostgreSQL Auto-Detection
|
||||
|
||||
PostgreSQL is the default for all other connection strings:
|
||||
|
||||
```bash
|
||||
# PostgreSQL is detected for these patterns
|
||||
DATABASE_URL="postgres://user:pass@localhost:5432/mydb" bun run app.js
|
||||
DATABASE_URL="postgresql://user:pass@localhost:5432/mydb" bun run app.js
|
||||
|
||||
# Or any URL that doesn't match SQLite patterns
|
||||
DATABASE_URL="localhost:5432/mydb" bun run app.js
|
||||
```
|
||||
|
||||
### PostgreSQL Environment Variables
|
||||
|
||||
The following environment variables can be used to define the PostgreSQL connection:
|
||||
|
||||
| Environment Variable | Description |
|
||||
| --------------------------- | ------------------------------------------ |
|
||||
| `POSTGRES_URL` | Primary connection URL for PostgreSQL |
|
||||
| `DATABASE_URL` | Alternative connection URL |
|
||||
| `DATABASE_URL` | Alternative connection URL (auto-detected) |
|
||||
| `PGURL` | Alternative connection URL |
|
||||
| `PG_URL` | Alternative connection URL |
|
||||
| `TLS_POSTGRES_DATABASE_URL` | SSL/TLS-enabled connection URL |
|
||||
@@ -274,6 +424,19 @@ If no connection URL is provided, the system checks for the following individual
|
||||
| `PGPASSWORD` | - | (empty) | Database password |
|
||||
| `PGDATABASE` | - | username | Database name |
|
||||
|
||||
### SQLite Environment Variables
|
||||
|
||||
SQLite connections can be configured via `DATABASE_URL` when it contains a SQLite-compatible URL:
|
||||
|
||||
```bash
|
||||
# These are all recognized as SQLite
|
||||
DATABASE_URL=":memory:"
|
||||
DATABASE_URL="sqlite://./app.db"
|
||||
DATABASE_URL="file:///absolute/path/to/db.sqlite"
|
||||
```
|
||||
|
||||
**Note:** PostgreSQL-specific environment variables (`POSTGRES_URL`, `PGHOST`, etc.) are ignored when using SQLite.
|
||||
|
||||
## Runtime Preconnection
|
||||
|
||||
Bun can preconnect to PostgreSQL at startup to improve performance by establishing database connections before your application code runs. This is useful for reducing connection latency on the first database query.
|
||||
@@ -293,16 +456,18 @@ The `--sql-preconnect` flag will automatically establish a PostgreSQL connection
|
||||
|
||||
## Connection Options
|
||||
|
||||
You can configure your database connection manually by passing options to the SQL constructor:
|
||||
You can configure your database connection manually by passing options to the SQL constructor. Options vary depending on the database adapter:
|
||||
|
||||
### PostgreSQL Options
|
||||
|
||||
```ts
|
||||
import { SQL } from "bun";
|
||||
|
||||
const db = new SQL({
|
||||
// Required
|
||||
// Connection details (adapter is auto-detected as PostgreSQL)
|
||||
url: "postgres://user:pass@localhost:5432/dbname",
|
||||
|
||||
// Optional configuration
|
||||
// Alternative connection parameters
|
||||
hostname: "localhost",
|
||||
port: 5432,
|
||||
database: "myapp",
|
||||
@@ -330,14 +495,53 @@ const db = new SQL({
|
||||
|
||||
// Callbacks
|
||||
onconnect: client => {
|
||||
console.log("Connected to database");
|
||||
console.log("Connected to PostgreSQL");
|
||||
},
|
||||
onclose: client => {
|
||||
console.log("Connection closed");
|
||||
console.log("PostgreSQL connection closed");
|
||||
},
|
||||
});
|
||||
```
|
||||
|
||||
### SQLite Options
|
||||
|
||||
```ts
|
||||
import { SQL } from "bun";
|
||||
|
||||
const db = new SQL({
|
||||
// Required for SQLite
|
||||
adapter: "sqlite",
|
||||
filename: "./data/app.db", // or ":memory:" for in-memory database
|
||||
|
||||
// SQLite-specific access modes
|
||||
readonly: false, // Open in read-only mode
|
||||
create: true, // Create database if it doesn't exist
|
||||
readwrite: true, // Allow read and write operations
|
||||
|
||||
// SQLite data handling
|
||||
strict: true, // Enable strict mode for better type safety
|
||||
safeIntegers: false, // Use BigInt for integers exceeding JS number range
|
||||
|
||||
// Callbacks
|
||||
onconnect: client => {
|
||||
console.log("SQLite database opened");
|
||||
},
|
||||
onclose: client => {
|
||||
console.log("SQLite database closed");
|
||||
},
|
||||
});
|
||||
```
|
||||
|
||||
<details>
|
||||
<summary>SQLite Connection Notes</summary>
|
||||
|
||||
- **Connection Pooling**: SQLite doesn't use connection pooling as it's a file-based database. Each `SQL` instance represents a single connection.
|
||||
- **Transactions**: SQLite supports nested transactions through savepoints, similar to PostgreSQL.
|
||||
- **Concurrent Access**: SQLite handles concurrent access through file locking. Use WAL mode for better concurrency.
|
||||
- **Memory Databases**: Using `:memory:` creates a temporary database that exists only for the connection lifetime.
|
||||
|
||||
</details>
|
||||
|
||||
## Dynamic passwords
|
||||
|
||||
When clients need to use alternative authentication schemes such as access tokens or connections to databases with rotating passwords, provide either a synchronous or asynchronous function that will resolve the dynamic password value at connection time.
|
||||
@@ -353,11 +557,66 @@ const sql = new SQL(url, {
|
||||
});
|
||||
```
|
||||
|
||||
## SQLite-Specific Features
|
||||
|
||||
### Query Execution
|
||||
|
||||
SQLite executes queries synchronously, unlike PostgreSQL which uses asynchronous I/O. However, the API remains consistent using Promises:
|
||||
|
||||
```ts
|
||||
const sqlite = new SQL("sqlite://app.db");
|
||||
|
||||
// Works the same as PostgreSQL, but executes synchronously under the hood
|
||||
const users = await sqlite`SELECT * FROM users`;
|
||||
|
||||
// Parameters work identically
|
||||
const user = await sqlite`SELECT * FROM users WHERE id = ${userId}`;
|
||||
```
|
||||
|
||||
### SQLite Pragmas
|
||||
|
||||
You can use PRAGMA statements to configure SQLite behavior:
|
||||
|
||||
```ts
|
||||
const sqlite = new SQL("sqlite://app.db");
|
||||
|
||||
// Enable foreign keys
|
||||
await sqlite`PRAGMA foreign_keys = ON`;
|
||||
|
||||
// Set journal mode to WAL for better concurrency
|
||||
await sqlite`PRAGMA journal_mode = WAL`;
|
||||
|
||||
// Check integrity
|
||||
const integrity = await sqlite`PRAGMA integrity_check`;
|
||||
```
|
||||
|
||||
### Data Type Differences
|
||||
|
||||
SQLite has a more flexible type system than PostgreSQL:
|
||||
|
||||
```ts
|
||||
// SQLite stores data in 5 storage classes: NULL, INTEGER, REAL, TEXT, BLOB
|
||||
const sqlite = new SQL("sqlite://app.db");
|
||||
|
||||
// SQLite is more lenient with types
|
||||
await sqlite`
|
||||
CREATE TABLE flexible (
|
||||
id INTEGER PRIMARY KEY,
|
||||
data TEXT, -- Can store numbers as strings
|
||||
value NUMERIC, -- Can store integers, reals, or text
|
||||
blob BLOB -- Binary data
|
||||
)
|
||||
`;
|
||||
|
||||
// JavaScript values are automatically converted
|
||||
await sqlite`INSERT INTO flexible VALUES (${1}, ${"text"}, ${123.45}, ${Buffer.from("binary")})`;
|
||||
```
|
||||
|
||||
## Transactions
|
||||
|
||||
To start a new transaction, use `sql.begin`. This method reserves a dedicated connection for the duration of the transaction and provides a scoped `sql` instance to use within the callback function. Once the callback completes, `sql.begin` resolves with the return value of the callback.
|
||||
To start a new transaction, use `sql.begin`. This method works for both PostgreSQL and SQLite. For PostgreSQL, it reserves a dedicated connection from the pool. For SQLite, it begins a transaction on the single connection.
|
||||
|
||||
The `BEGIN` command is sent automatically, including any optional configurations you specify. If an error occurs during the transaction, a `ROLLBACK` is triggered to release the reserved connection and ensure the process continues smoothly.
|
||||
The `BEGIN` command is sent automatically, including any optional configurations you specify. If an error occurs during the transaction, a `ROLLBACK` is triggered to ensure the process continues smoothly.
|
||||
|
||||
### Basic Transactions
|
||||
|
||||
@@ -552,9 +811,34 @@ Note that disabling prepared statements may impact performance for queries that
|
||||
|
||||
## Error Handling
|
||||
|
||||
The client provides typed errors for different failure scenarios:
|
||||
The client provides typed errors for different failure scenarios. Errors are database-specific and extend from base error classes:
|
||||
|
||||
### Connection Errors
|
||||
### Error Classes
|
||||
|
||||
```ts
|
||||
import { SQL } from "bun";
|
||||
|
||||
try {
|
||||
await sql`SELECT * FROM users`;
|
||||
} catch (error) {
|
||||
if (error instanceof SQL.PostgresError) {
|
||||
// PostgreSQL-specific error
|
||||
console.log(error.code); // PostgreSQL error code
|
||||
console.log(error.detail); // Detailed error message
|
||||
console.log(error.hint); // Helpful hint from PostgreSQL
|
||||
} else if (error instanceof SQL.SQLiteError) {
|
||||
// SQLite-specific error
|
||||
console.log(error.code); // SQLite error code (e.g., "SQLITE_CONSTRAINT")
|
||||
console.log(error.errno); // SQLite error number
|
||||
console.log(error.byteOffset); // Byte offset in SQL statement (if available)
|
||||
} else if (error instanceof SQL.SQLError) {
|
||||
// Generic SQL error (base class)
|
||||
console.log(error.message);
|
||||
}
|
||||
}
|
||||
```
|
||||
|
||||
### PostgreSQL Connection Errors
|
||||
|
||||
| Connection Errors | Description |
|
||||
| --------------------------------- | ---------------------------------------------------- |
|
||||
@@ -619,6 +903,50 @@ The client provides typed errors for different failure scenarios:
|
||||
| `ERR_POSTGRES_UNSAFE_TRANSACTION` | Unsafe transaction operation detected |
|
||||
| `ERR_POSTGRES_INVALID_TRANSACTION_STATE` | Invalid transaction state |
|
||||
|
||||
### SQLite-Specific Errors
|
||||
|
||||
SQLite errors provide error codes and numbers that correspond to SQLite's standard error codes:
|
||||
|
||||
<details>
|
||||
<summary>Common SQLite Error Codes</summary>
|
||||
|
||||
| Error Code | errno | Description |
|
||||
| ------------------- | ----- | ---------------------------------------------------- |
|
||||
| `SQLITE_CONSTRAINT` | 19 | Constraint violation (UNIQUE, CHECK, NOT NULL, etc.) |
|
||||
| `SQLITE_BUSY` | 5 | Database is locked |
|
||||
| `SQLITE_LOCKED` | 6 | Table in the database is locked |
|
||||
| `SQLITE_READONLY` | 8 | Attempt to write to a readonly database |
|
||||
| `SQLITE_IOERR` | 10 | Disk I/O error |
|
||||
| `SQLITE_CORRUPT` | 11 | Database disk image is malformed |
|
||||
| `SQLITE_FULL` | 13 | Database or disk is full |
|
||||
| `SQLITE_CANTOPEN` | 14 | Unable to open database file |
|
||||
| `SQLITE_PROTOCOL` | 15 | Database lock protocol error |
|
||||
| `SQLITE_SCHEMA` | 17 | Database schema has changed |
|
||||
| `SQLITE_TOOBIG` | 18 | String or BLOB exceeds size limit |
|
||||
| `SQLITE_MISMATCH` | 20 | Data type mismatch |
|
||||
| `SQLITE_MISUSE` | 21 | Library used incorrectly |
|
||||
| `SQLITE_AUTH` | 23 | Authorization denied |
|
||||
|
||||
Example error handling:
|
||||
|
||||
```ts
|
||||
const sqlite = new SQL("sqlite://app.db");
|
||||
|
||||
try {
|
||||
await sqlite`INSERT INTO users (id, name) VALUES (1, 'Alice')`;
|
||||
await sqlite`INSERT INTO users (id, name) VALUES (1, 'Bob')`; // Duplicate ID
|
||||
} catch (error) {
|
||||
if (error instanceof SQL.SQLiteError) {
|
||||
if (error.code === "SQLITE_CONSTRAINT") {
|
||||
console.log("Constraint violation:", error.message);
|
||||
// Handle unique constraint violation
|
||||
}
|
||||
}
|
||||
}
|
||||
```
|
||||
|
||||
</details>
|
||||
|
||||
## Numbers and BigInt
|
||||
|
||||
Bun's SQL client includes special handling for large numbers that exceed the range of a 53-bit integer. Here's how it works:
|
||||
@@ -652,7 +980,6 @@ There's still some things we haven't finished yet.
|
||||
|
||||
- Connection preloading via `--db-preconnect` Bun CLI flag
|
||||
- MySQL support: [we're working on it](https://github.com/oven-sh/bun/pull/15274)
|
||||
- SQLite support: planned, but not started. Ideally, we implement it natively instead of wrapping `bun:sqlite`.
|
||||
- Column name transforms (e.g. `snake_case` to `camelCase`). This is mostly blocked on a unicode-aware implementation of changing the case in C++ using WebKit's `WTF::String`.
|
||||
- Column type transforms
|
||||
|
||||
|
||||
Reference in New Issue
Block a user