Releases: drizzle-team/drizzle-orm
0.36.3
New Features
Support for UPDATE ... FROM
in PostgreSQL and SQLite
As the SQLite documentation mentions:
Note
The UPDATE-FROM idea is an extension to SQL that allows an UPDATE statement to be driven by other tables in the database.
The "target" table is the specific table that is being updated. With UPDATE-FROM you can join the target table
against other tables in the database in order to help compute which rows need updating and what
the new values should be on those rows
Similarly, the PostgreSQL documentation states:
Note
A table expression allowing columns from other tables to appear in the WHERE condition and update expressions
Drizzle also supports this feature starting from this version
For example, current query:
await db
.update(users)
.set({ cityId: cities.id })
.from(cities)
.where(and(eq(cities.name, 'Seattle'), eq(users.name, 'John')))
Will generate this sql
update "users" set "city_id" = "cities"."id"
from "cities"
where ("cities"."name" = $1 and "users"."name" = $2)
-- params: [ 'Seattle', 'John' ]
You can also alias tables that are joined (in PG, you can also alias the updating table too).
const c = alias(cities, 'c');
await db
.update(users)
.set({ cityId: c.id })
.from(c);
Will generate this sql
update "users" set "city_id" = "c"."id"
from "cities" "c"
In PostgreSQL, you can also return columns from the joined tables.
const updatedUsers = await db
.update(users)
.set({ cityId: cities.id })
.from(cities)
.returning({ id: users.id, cityName: cities.name });
Will generate this sql
update "users" set "city_id" = "cities"."id"
from "cities"
returning "users"."id", "cities"."name"
Support for INSERT INTO ... SELECT
in all dialects
As the SQLite documentation mentions:
Note
The second form of the INSERT statement contains a SELECT statement instead of a VALUES clause.
A new entry is inserted into the table for each row of data returned by executing the SELECT statement.
If a column-list is specified, the number of columns in the result of the SELECT must be the same as
the number of items in the column-list. Otherwise, if no column-list is specified, the number of
columns in the result of the SELECT must be the same as the number of columns in the table.
Any SELECT statement, including compound SELECTs and SELECT statements with ORDER BY and/or LIMIT clauses,
may be used in an INSERT statement of this form.
Caution
To avoid a parsing ambiguity, the SELECT statement should always contain a WHERE clause, even if that clause is simply "WHERE true", if the upsert-clause is present. Without the WHERE clause, the parser does not know if the token "ON" is part of a join constraint on the SELECT, or the beginning of the upsert-clause.
As the PostgreSQL documentation mentions:
Note
A query (SELECT statement) that supplies the rows to be inserted
And as the MySQL documentation mentions:
Note
With INSERT ... SELECT, you can quickly insert many rows into a table from the result of a SELECT statement, which can select from one or many tables
Drizzle supports the current syntax for all dialects, and all of them share the same syntax. Let's review some common scenarios and API usage.
There are several ways to use select inside insert statements, allowing you to choose your preferred approach:
- You can pass a query builder inside the select function.
- You can use a query builder inside a callback.
- You can pass an SQL template tag with any custom select query you want to use
Query Builder
const insertedEmployees = await db
.insert(employees)
.select(
db.select({ name: users.name }).from(users).where(eq(users.role, 'employee'))
)
.returning({
id: employees.id,
name: employees.name
});
const qb = new QueryBuilder();
await db.insert(employees).select(
qb.select({ name: users.name }).from(users).where(eq(users.role, 'employee'))
);
Callback
await db.insert(employees).select(
() => db.select({ name: users.name }).from(users).where(eq(users.role, 'employee'))
);
await db.insert(employees).select(
(qb) => qb.select({ name: users.name }).from(users).where(eq(users.role, 'employee'))
);
SQL template tag
await db.insert(employees).select(
sql`select "users"."name" as "name" from "users" where "users"."role" = 'employee'`
);
await db.insert(employees).select(
() => sql`select "users"."name" as "name" from "users" where "users"."role" = 'employee'`
);
0.36.2
New Features
Bug and typo fixes
-
Fixed typos in repository: thanks @armandsalle, @masto, @wackbyte, @Asher-JH, @MaxLeiter
-
[MySQL] Correct $returningId() implementation to correctly store selected fields
[email protected]
Bug fixes
- Fixed typos in repository: thanks @armandsalle, @masto, @wackbyte, @Asher-JH, @MaxLeiter
- fix: wrong dialect set in mysql/sqlite introspect
0.36.1
Bug Fixes
- [BUG]: Using sql.placeholder with limit and/or offset for a prepared statement produces TS error - thanks @L-Mario564
- [BUG] If a query I am trying to modify with a dynamic query (....$dynamic()) contains any placeholders, I'm getting an error that says No value for placeholder.... provided - thanks @L-Mario564
- [BUG]: Error thrown when trying to insert an array of new rows using generatedAlwaysAsIdentity() for the id column - thanks @L-Mario564
- [BUG]: Unable to Use BigInt Types with Bun and Drizzle - thanks @L-Mario564
[email protected]
Improvements
- Added an OHM static imports checker to identify unexpected imports within a chain of imports in the drizzle-kit repo. For example, it checks if drizzle-orm is imported before drizzle-kit and verifies if the drizzle-orm import is available in your project.
- Adding more columns to Supabase auth.users table schema - thanks @nicholasdly
Bug Fixes
- [BUG]: [drizzle-kit]: Fix breakpoints option cannot be disabled - thanks @klotztech
- [BUG]: drizzle-kit introspect: SMALLINT import missing and incorrect DECIMAL UNSIGNED handling - thanks @L-Mario564
- Unsigned tinyints preventing migrations - thanks @L-Mario564
- [BUG]: Can't parse float(8,2) from database (precision and scale and/or unsigned breaks float types) - thanks @L-Mario564
- [BUG]: PgEnum generated migration doesn't escape single quotes - thanks @L-Mario564
- [BUG]: single quote not escaped correctly in migration file - thanks @L-Mario564
- [BUG]: Migrations does not escape single quotes - thanks @L-Mario564
- [BUG]: Issue with quoted default string values - thanks @L-Mario564
- [BUG]: SQl commands in wrong roder - thanks @L-Mario564
- [BUG]: Time with precision in drizzle-orm/pg-core adds double-quotes around type - thanks @L-Mario564
- [BUG]: Postgres push fails due to lack of quotes - thanks @L-Mario564
- [BUG]: TypeError: Cannot read properties of undefined (reading 'compositePrimaryKeys') - thanks @L-Mario564
- [BUG]: drizzle-kit introspect generates CURRENT_TIMESTAMP without sql operator on date column - thanks @L-Mario564
- [BUG]: Drizzle-kit introspect doesn't pull correct defautl statement - thanks @L-Mario564
- [BUG]: Problem on MacBook - This statement does not return data. Use run() instead - thanks @L-Mario564
- [BUG]: Enum column names that are used as arrays are not quoted - thanks @L-Mario564
- [BUG]: drizzle-kit generate ignores index operators - thanks @L-Mario564
- dialect param config error message is wrong - thanks @L-Mario564
- [BUG]: Error setting default enum field values - thanks @L-Mario564
- [BUG]: drizzle-kit does not respect the order of columns configured in primaryKey() - thanks @L-Mario564
- [BUG]: Cannot drop Unique Constraint MySQL - thanks @L-Mario564
[email protected]
- Fix [BUG]: Undefined properties when using drizzle-kit push
- Fix TypeError: Cannot read properties of undefined (reading 'isRLSEnabled')
- Fix push bugs, when pushing a schema with linked policy to a table from
drizzle-orm/supabase
[email protected]
0.36.0
This version of
drizzle-orm
requires[email protected]
to enable all new features
New Features
The third parameter in Drizzle ORM becomes an array
The object API is still available but deprecated
Instead of this
pgTable('users', {
id: integer().primaryKey(),
}, (t) => ({
index: index('test').on(t.id),
}));
You can now do this
pgTable('users', {
id: integer().primaryKey(),
}, (t) => [index('test').on(t.id)]);
Row-Level Security (RLS)
With Drizzle, you can enable Row-Level Security (RLS) for any Postgres table, create policies with various options, and define and manage the roles those policies apply to.
Drizzle supports a raw representation of Postgres policies and roles that can be used in any way you want. This works with popular Postgres database providers such as Neon
and Supabase
.
In Drizzle, we have specific predefined RLS roles and functions for RLS with both database providers, but you can also define your own logic.
Enable RLS
If you just want to enable RLS on a table without adding policies, you can use .enableRLS()
As mentioned in the PostgreSQL documentation:
If no policy exists for the table, a default-deny policy is used, meaning that no rows are visible or can be modified.
Operations that apply to the whole table, such as TRUNCATE and REFERENCES, are not subject to row security.
import { integer, pgTable } from 'drizzle-orm/pg-core';
export const users = pgTable('users', {
id: integer(),
}).enableRLS();
If you add a policy to a table, RLS will be enabled automatically. So, there’s no need to explicitly enable RLS when adding policies to a table.
Roles
Currently, Drizzle supports defining roles with a few different options, as shown below. Support for more options will be added in a future release.
import { pgRole } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin', { createRole: true, createDb: true, inherit: true });
If a role already exists in your database, and you don’t want drizzle-kit to ‘see’ it or include it in migrations, you can mark the role as existing.
import { pgRole } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin').existing();
Policies
To fully leverage RLS, you can define policies within a Drizzle table.
In PostgreSQL, policies should be linked to an existing table. Since policies are always associated with a specific table, we decided that policy definitions should be defined as a parameter of
pgTable
Example of pgPolicy with all available properties
import { sql } from 'drizzle-orm';
import { integer, pgPolicy, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
pgPolicy('policy', {
as: 'permissive',
to: admin,
for: 'delete',
using: sql``,
withCheck: sql``,
}),
]);
Link Policy to an existing table
There are situations where you need to link a policy to an existing table in your database.
The most common use case is with database providers like Neon
or Supabase
, where you need to add a policy
to their existing tables. In this case, you can use the .link()
API
import { sql } from "drizzle-orm";
import { pgPolicy } from "drizzle-orm/pg-core";
import { authenticatedRole, realtimeMessages } from "drizzle-orm/supabase";
export const policy = pgPolicy("authenticated role insert policy", {
for: "insert",
to: authenticatedRole,
using: sql``,
}).link(realtimeMessages);
Migrations
If you are using drizzle-kit to manage your schema and roles, there may be situations where you want to refer to roles that are not defined in your Drizzle schema. In such cases, you may want drizzle-kit to skip managing these roles without having to define each role in your drizzle schema and marking it with .existing()
.
In these cases, you can use entities.roles
in drizzle.config.ts
. For a complete reference, refer to the the drizzle.config.ts
documentation.
By default, drizzle-kit
does not manage roles for you, so you will need to enable this feature in drizzle.config.ts
.
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
dialect: 'postgresql',
schema: "./drizzle/schema.ts",
dbCredentials: {
url: process.env.DATABASE_URL!
},
verbose: true,
strict: true,
entities: {
roles: true
}
});
In case you need additional configuration options, let's take a look at a few more examples.
You have an admin
role and want to exclude it from the list of manageable roles
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
exclude: ['admin']
}
}
});
You have an admin
role and want to include it in the list of manageable roles
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
include: ['admin']
}
}
});
If you are using Neon
and want to exclude Neon-defined roles, you can use the provider option
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
provider: 'neon'
}
}
});
If you are using Supabase
and want to exclude Supabase-defined roles, you can use the provider option
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
provider: 'supabase'
}
}
});
You may encounter situations where Drizzle is slightly outdated compared to new roles specified by your database provider.
In such cases, you can use theprovider
option andexclude
additional roles:
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
provider: 'supabase',
exclude: ['new_supabase_role']
}
}
});
RLS on views
With Drizzle, you can also specify RLS policies on views. For this, you need to use security_invoker
in the view's WITH options. Here is a small example:
...
export const roomsUsersProfiles = pgView("rooms_users_profiles")
.with({
securityInvoker: true,
})
.as((qb) =>
qb
.select({
...getTableColumns(roomsUsers),
email: profiles.email,
})
.from(roomsUsers)
.innerJoin(profiles, eq(roomsUsers.userId, profiles.id))
);
Using with Neon
The Neon Team helped us implement their vision of a wrapper on top of our raw policies API. We defined a specific
/neon
import with the crudPolicy
function that includes predefined functions and Neon's default roles.
Here's an example of how to use the crudPolicy
function:
import { crudPolicy } from 'drizzle-orm/neon';
import { integer, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
crudPolicy({ role: admin, read: true, modify: false }),
]);
This policy is equivalent to:
import { sql } from 'drizzle-orm';
import { integer, pgPolicy, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
pgPolicy(`crud-${admin.name}-policy-insert`, {
for: 'insert',
to: admin,
withCheck: sql`false`,
}),
pgPolicy(`crud-${admin.name}-policy-update`, {
for: 'update',
to: admin,
using: sql`false`,
withCheck: sql`false`,
}),
pgPolicy(`crud-${admin.name}-policy-delete`, {
for: 'delete',
to: admin,
using: sql`false`,
}),
pgPolicy(`crud-${admin.name}-policy-select`, {
for: 'select',
to: admin,
using: sql`true`,
}),
]);
Neon
exposes predefined authenticated
and anaonymous
roles and related functions. If you are using Neon
for RLS, you can use these roles, which are marked as existing, and the related functions in your RLS queries.
// drizzle-orm/neon
export const authenticatedRole = pgRole('authenticated').existing();
export const anonymousRole = pgRole('anonymous').existing();
export const authUid = (userIdColumn: AnyPgColumn) => sql`(select auth.user_id() = ${userIdColumn})`;
For example, you can use the Neon
predefined roles and functions like this:
import { sql } from 'drizzle-orm';
import { authenticatedRole } from 'drizzle-orm/neon';
import { integer, pgPolicy, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
pgPolicy(`policy-insert`, {
for: 'insert',
to: authenticatedRole,
withCheck: sql`false`,
}),
]);
Using with Supabase
We also have a /supabase
import with a set of predefined roles marked as existing, which you can use in your schema.
This import will be extended in a future release with more functions and helpers to make using RLS and Supabase
simpler.
// drizzle-orm/supabase
export const anonRole = pgRole('anon').existing();
export const authenticatedRole = pgRole('authenticated').existing();
export const serviceRole = pgRole('service_role').existing();
export const postgresRole = pgRole('postgres_role').existing();
export const supabaseAuthAdminRole = pgRole('supabase_auth_admin').existing();
For example, you can use the Supabase
predefined roles like this:
import { sql } fr...
[email protected]
This version of
drizzle-jit
requires[email protected]
to enable all new features
New Features
Row-Level Security (RLS)
With Drizzle, you can enable Row-Level Security (RLS) for any Postgres table, create policies with various options, and define and manage the roles those policies apply to.
Drizzle supports a raw representation of Postgres policies and roles that can be used in any way you want. This works with popular Postgres database providers such as Neon
and Supabase
.
In Drizzle, we have specific predefined RLS roles and functions for RLS with both database providers, but you can also define your own logic.
Enable RLS
If you just want to enable RLS on a table without adding policies, you can use .enableRLS()
As mentioned in the PostgreSQL documentation:
If no policy exists for the table, a default-deny policy is used, meaning that no rows are visible or can be modified.
Operations that apply to the whole table, such as TRUNCATE and REFERENCES, are not subject to row security.
import { integer, pgTable } from 'drizzle-orm/pg-core';
export const users = pgTable('users', {
id: integer(),
}).enableRLS();
If you add a policy to a table, RLS will be enabled automatically. So, there’s no need to explicitly enable RLS when adding policies to a table.
Roles
Currently, Drizzle supports defining roles with a few different options, as shown below. Support for more options will be added in a future release.
import { pgRole } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin', { createRole: true, createDb: true, inherit: true });
If a role already exists in your database, and you don’t want drizzle-kit to ‘see’ it or include it in migrations, you can mark the role as existing.
import { pgRole } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin').existing();
Policies
To fully leverage RLS, you can define policies within a Drizzle table.
In PostgreSQL, policies should be linked to an existing table. Since policies are always associated with a specific table, we decided that policy definitions should be defined as a parameter of
pgTable
Example of pgPolicy with all available properties
import { sql } from 'drizzle-orm';
import { integer, pgPolicy, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
pgPolicy('policy', {
as: 'permissive',
to: admin,
for: 'delete',
using: sql``,
withCheck: sql``,
}),
]);
Link Policy to an existing table
There are situations where you need to link a policy to an existing table in your database.
The most common use case is with database providers like Neon
or Supabase
, where you need to add a policy
to their existing tables. In this case, you can use the .link()
API
import { sql } from "drizzle-orm";
import { pgPolicy } from "drizzle-orm/pg-core";
import { authenticatedRole, realtimeMessages } from "drizzle-orm/supabase";
export const policy = pgPolicy("authenticated role insert policy", {
for: "insert",
to: authenticatedRole,
using: sql``,
}).link(realtimeMessages);
Migrations
If you are using drizzle-kit to manage your schema and roles, there may be situations where you want to refer to roles that are not defined in your Drizzle schema. In such cases, you may want drizzle-kit to skip managing these roles without having to define each role in your drizzle schema and marking it with .existing()
.
In these cases, you can use entities.roles
in drizzle.config.ts
. For a complete reference, refer to the the drizzle.config.ts
documentation.
By default, drizzle-kit
does not manage roles for you, so you will need to enable this feature in drizzle.config.ts
.
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
dialect: 'postgresql',
schema: "./drizzle/schema.ts",
dbCredentials: {
url: process.env.DATABASE_URL!
},
verbose: true,
strict: true,
entities: {
roles: true
}
});
In case you need additional configuration options, let's take a look at a few more examples.
You have an admin
role and want to exclude it from the list of manageable roles
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
exclude: ['admin']
}
}
});
You have an admin
role and want to include it in the list of manageable roles
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
include: ['admin']
}
}
});
If you are using Neon
and want to exclude Neon-defined roles, you can use the provider option
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
provider: 'neon'
}
}
});
If you are using Supabase
and want to exclude Supabase-defined roles, you can use the provider option
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
provider: 'supabase'
}
}
});
You may encounter situations where Drizzle is slightly outdated compared to new roles specified by your database provider.
In such cases, you can use theprovider
option andexclude
additional roles:
// drizzle.config.ts
import { defineConfig } from "drizzle-kit";
export default defineConfig({
...
entities: {
roles: {
provider: 'supabase',
exclude: ['new_supabase_role']
}
}
});
RLS on views
With Drizzle, you can also specify RLS policies on views. For this, you need to use security_invoker
in the view's WITH options. Here is a small example:
...
export const roomsUsersProfiles = pgView("rooms_users_profiles")
.with({
securityInvoker: true,
})
.as((qb) =>
qb
.select({
...getTableColumns(roomsUsers),
email: profiles.email,
})
.from(roomsUsers)
.innerJoin(profiles, eq(roomsUsers.userId, profiles.id))
);
Using with Neon
The Neon Team helped us implement their vision of a wrapper on top of our raw policies API. We defined a specific
/neon
import with the crudPolicy
function that includes predefined functions and Neon's default roles.
Here's an example of how to use the crudPolicy
function:
import { crudPolicy } from 'drizzle-orm/neon';
import { integer, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
crudPolicy({ role: admin, read: true, modify: false }),
]);
This policy is equivalent to:
import { sql } from 'drizzle-orm';
import { integer, pgPolicy, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
pgPolicy(`crud-${admin.name}-policy-insert`, {
for: 'insert',
to: admin,
withCheck: sql`false`,
}),
pgPolicy(`crud-${admin.name}-policy-update`, {
for: 'update',
to: admin,
using: sql`false`,
withCheck: sql`false`,
}),
pgPolicy(`crud-${admin.name}-policy-delete`, {
for: 'delete',
to: admin,
using: sql`false`,
}),
pgPolicy(`crud-${admin.name}-policy-select`, {
for: 'select',
to: admin,
using: sql`true`,
}),
]);
Neon
exposes predefined authenticated
and anaonymous
roles and related functions. If you are using Neon
for RLS, you can use these roles, which are marked as existing, and the related functions in your RLS queries.
// drizzle-orm/neon
export const authenticatedRole = pgRole('authenticated').existing();
export const anonymousRole = pgRole('anonymous').existing();
export const authUid = (userIdColumn: AnyPgColumn) => sql`(select auth.user_id() = ${userIdColumn})`;
For example, you can use the Neon
predefined roles and functions like this:
import { sql } from 'drizzle-orm';
import { authenticatedRole } from 'drizzle-orm/neon';
import { integer, pgPolicy, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
pgPolicy(`policy-insert`, {
for: 'insert',
to: authenticatedRole,
withCheck: sql`false`,
}),
]);
Using with Supabase
We also have a /supabase
import with a set of predefined roles marked as existing, which you can use in your schema.
This import will be extended in a future release with more functions and helpers to make using RLS and Supabase
simpler.
// drizzle-orm/supabase
export const anonRole = pgRole('anon').existing();
export const authenticatedRole = pgRole('authenticated').existing();
export const serviceRole = pgRole('service_role').existing();
export const postgresRole = pgRole('postgres_role').existing();
export const supabaseAuthAdminRole = pgRole('supabase_auth_admin').existing();
For example, you can use the Supabase
predefined roles like this:
import { sql } from 'drizzle-orm';
import { serviceRole } from 'drizzle-orm/supabase';
import { integer, pgPolicy, pgRole, pgTable } from 'drizzle-orm/pg-core';
export const admin = pgRole('admin');
export const users = pgTable('users', {
id: integer(),
}, (t) => [
pgPolicy(`policy-insert`, {
for: 'insert',
to: serviceRole,
withCheck: sql`false`,
}),
]);
The /supabase
import also includes predefined tables and functions that you can use in your application
// drizzle-orm/supabase
const auth = pgSchema('auth');
export const authUsers = auth.table('users', {
id: uuid().primaryKey().notNull(),
});
const realtime = pgSchema('realtime');
export const realtimeMessages = realtime.table(
'...
0.35.3
New LibSQL driver modules
Drizzle now has native support for all @libsql/client
driver variations:
@libsql/client
- defaults to node import, automatically changes to web if target or platform is set for bundler, e.g.esbuild --platform=browser
import { drizzle } from 'drizzle-orm/libsql';
const db = drizzle({ connection: {
url: process.env.DATABASE_URL,
authToken: process.env.DATABASE_AUTH_TOKEN
}});
@libsql/client/node
node compatible module, supports :memory:, file, wss, http and turso connection protocols
import { drizzle } from 'drizzle-orm/libsql/node';
const db = drizzle({ connection: {
url: process.env.DATABASE_URL,
authToken: process.env.DATABASE_AUTH_TOKEN
}});
@libsql/client/web
module for fullstack web frameworks like next, nuxt, astro, etc.
import { drizzle } from 'drizzle-orm/libsql/web';
const db = drizzle({ connection: {
url: process.env.DATABASE_URL,
authToken: process.env.DATABASE_AUTH_TOKEN
}});
@libsql/client/http
module for http and https connection protocols
import { drizzle } from 'drizzle-orm/libsql/http';
const db = drizzle({ connection: {
url: process.env.DATABASE_URL,
authToken: process.env.DATABASE_AUTH_TOKEN
}});
@libsql/client/ws
module for ws and wss connection protocols
import { drizzle } from 'drizzle-orm/libsql/ws';
const db = drizzle({ connection: {
url: process.env.DATABASE_URL,
authToken: process.env.DATABASE_AUTH_TOKEN
}});
@libsql/client/sqlite3
module for :memory: and file connection protocols
import { drizzle } from 'drizzle-orm/libsql/wasm';
const db = drizzle({ connection: {
url: process.env.DATABASE_URL,
authToken: process.env.DATABASE_AUTH_TOKEN
}});
@libsql/client-wasm
Separate experimental package for WASM
import { drizzle } from 'drizzle-orm/libsql';
const db = drizzle({ connection: {
url: process.env.DATABASE_URL,
authToken: process.env.DATABASE_AUTH_TOKEN
}});