Releases: drizzle-team/drizzle-orm
drizzle-kit@0.27.1
0.36.0
This version of
drizzle-orm
requiresdrizzle-kit@0.27.0
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...
drizzle-kit@0.27.0
This version of
drizzle-jit
requiresdrizzle-orm@0.36.0
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
}});
0.35.2
- Fix issues with importing in several environments after updating the Drizzle driver implementation
We've added approximately 240 tests to check the ESM and CJS builds for all the drivers we have. You can check them here
0.35.1
- Updated internal versions for the drizzle-kit and drizzle-orm packages. Changes were introduced in the last minor release, and you are required to upgrade both packages to ensure they work as expected
drizzle-kit@0.26.2
- Updated internal versions for the drizzle-kit and drizzle-orm packages. Changes were introduced in the last minor release, and you are required to upgrade both packages to ensure they work as expected
0.35.0
Important change after 0.34.0 release
Updated the init Drizzle database API
The API from version 0.34.0 turned out to be unusable and needs to be changed. You can read more about our decisions in this discussion
If you still want to use the new API introduced in 0.34.0, which can create driver clients for you under the hood, you can now do so
import { drizzle } from "drizzle-orm/node-postgres";
const db = drizzle(process.env.DATABASE_URL);
// or
const db = drizzle({
connection: process.env.DATABASE_URL
});
const db = drizzle({
connection: {
user: "...",
password: "...",
host: "...",
port: 4321,
db: "...",
},
});
// if you need to pass logger or schema
const db = drizzle({
connection: process.env.DATABASE_URL,
logger: true,
schema: schema,
});
in order to not introduce breaking change - we will still leave support for deprecated API until V1 release.
It will degrade autocomplete performance in connection params due to DatabaseDriver
| ConnectionParams
types collision,
but that's a decent compromise against breaking changes
import { drizzle } from "drizzle-orm/node-postgres";
import { Pool } from "pg";
const client = new Pool({ connectionString: process.env.DATABASE_URL });
const db = drizzle(client); // deprecated but available
// new version
const db = drizzle({
client: client,
});
New Features
New .orderBy() and .limit() functions in update and delete statements SQLite and MySQL
You now have more options for the update
and delete
query builders in MySQL and SQLite
Example
await db.update(usersTable).set({ verified: true }).limit(2).orderBy(asc(usersTable.name));
await db.delete(usersTable).where(eq(usersTable.verified, false)).limit(1).orderBy(asc(usersTable.name));
New drizzle.mock()
function
There were cases where you didn't need to provide a driver to the Drizzle object, and this served as a workaround
const db = drizzle({} as any)
Now you can do this using a mock function
const db = drizzle.mock()
There is no valid production use case for this, but we used it in situations where we needed to check types, etc., without making actual database calls or dealing with driver creation. If anyone was using it, please switch to using mocks now
Internal updates
- Upgraded TS in codebase to the version 5.6.3
Bug fixes
drizzle-kit@0.26.1
- Fix
data is malformed
for views
drizzle-kit@0.26.0
While writing this update, we found one bug that may occur with views in MySQL and SQLite, so please use the
drizzle-kit@0.26.1
release
New Features
Checks support in drizzle-kit
You can use drizzle-kit to manage your check
constraint defined in drizzle-orm schema definition
For example current drizzle table:
import { sql } from "drizzle-orm";
import { check, pgTable } from "drizzle-orm/pg-core";
export const users = pgTable(
"users",
(c) => ({
id: c.uuid().defaultRandom().primaryKey(),
username: c.text().notNull(),
age: c.integer(),
}),
(table) => ({
checkConstraint: check("age_check", sql`${table.age} > 21`),
})
);
will be generated into
CREATE TABLE IF NOT EXISTS "users" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"username" text NOT NULL,
"age" integer,
CONSTRAINT "age_check" CHECK ("users"."age" > 21)
);
The same is supported in all dialects
Limitations
generate
will work as expected for all check constraint changes.push
will detect only check renames and will recreate the constraint. All other changes to SQL won't be detected and will be ignored.
So, if you want to change the constraint's SQL definition using only push
, you would need to manually comment out the constraint, push
, then put it back with the new SQL definition and push
one more time.
Views support in drizzle-kit
You can use drizzle-kit to manage your views
defined in drizzle-orm schema definition. It will work with all existing dialects and view options
PostgreSQL
For example current drizzle table:
import { sql } from "drizzle-orm";
import {
check,
pgMaterializedView,
pgTable,
pgView,
} from "drizzle-orm/pg-core";
export const users = pgTable(
"users",
(c) => ({
id: c.uuid().defaultRandom().primaryKey(),
username: c.text().notNull(),
age: c.integer(),
}),
(table) => ({
checkConstraint: check("age_check", sql`${table.age} > 21`),
})
);
export const simpleView = pgView("simple_users_view").as((qb) =>
qb.select().from(users)
);
export const materializedView = pgMaterializedView(
"materialized_users_view"
).as((qb) => qb.select().from(users));
will be generated into
CREATE TABLE IF NOT EXISTS "users" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"username" text NOT NULL,
"age" integer,
CONSTRAINT "age_check" CHECK ("users"."age" > 21)
);
CREATE VIEW "public"."simple_users_view" AS (select "id", "username", "age" from "users");
CREATE MATERIALIZED VIEW "public"."materialized_users_view" AS (select "id", "username", "age" from "users");
Views supported in all dialects, but materialized views are supported only in PostgreSQL
Limitations
generate
will work as expected for all view changespush
limitations:
- If you want to change the view's SQL definition using only
push
, you would need to manually comment out the view,push
, then put it back with the new SQL definition andpush
one more time.
Updates for PostgreSQL enums behavior
We've updated enum behavior in Drizzle with PostgreSQL:
-
Add value after or before in enum: With this change, Drizzle will now respect the order of values in the enum and allow adding new values after or before a specific one.
-
Support for dropping a value from an enum: In this case, Drizzle will attempt to alter all columns using the enum to text, then drop the existing enum and create a new one with the updated set of values. After that, all columns previously using the enum will be altered back to the new enum.
If the deleted enum value was used by a column, this process will result in a database error.
-
Support for dropping an enum
-
Support for moving enums between schemas
-
Support for renaming enums