# Drizzle > Drizzle is a modern TypeScript ORM developers wanna use in their next project. It is lightweight at only ~7.4kb minified+gzipped, and it's tree shakeable with exactly 0 dependencies. It supports every PostgreSQL, MySQL, SQLite and SingleStore database and is serverless-ready by design. Source: https://orm.drizzle.team/docs/batch-api import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; # Batch API **LibSQL Batch API explanation**: _[source](https://docs.turso.tech/sdk/ts/reference#batch-transactions)_ > With the libSQL client library, a batch is one or more SQL statements executed in order in an implicit transaction. The transaction is controlled by the libSQL backend. If all of the statements are successful, the transaction is committed. If any of the statements fail, the entire transaction is rolled back and no changes are made. **D1 Batch API explanation**: _[source](https://developers.cloudflare.com/d1/worker-api/d1-database/#batch)_ > Batching sends multiple SQL statements inside a single call to the database. This can have a huge performance impact as it reduces latency from network round trips to D1. D1 operates in auto-commit. Our implementation guarantees that each statement in the list will execute and commit, sequentially, non-concurrently. Batched statements are SQL transactions. If a statement in the sequence fails, then an error is returned for that specific statement, and it aborts or rolls back the entire sequence. Drizzle ORM provides APIs to run SQL statements in batch for `LibSQL`, `Neon` and `D1`: ```ts const batchResponse: BatchResponse = await db.batch([ db.insert(usersTable).values({ id: 1, name: 'John' }).returning({ id: usersTable.id }), db.update(usersTable).set({ name: 'Dan' }).where(eq(usersTable.id, 1)), db.query.usersTable.findMany({}), db.select().from(usersTable).where(eq(usersTable.id, 1)), db.select({ id: usersTable.id, invitedBy: usersTable.invitedBy }).from(usersTable), ]); ``` Type for `batchResponse` in this example would be: ```ts type BatchResponse = [ { id: number; }[], ResultSet, { id: number; name: string; verified: number; invitedBy: number | null; }[], { id: number; name: string; verified: number; invitedBy: number | null; }[], { id: number; invitedBy: number | null; }[], ] ``` ```ts type BatchResponse = [ { id: number; }[], NeonHttpQueryResult, { id: number; name: string; verified: number; invitedBy: number | null; }[], { id: number; name: string; verified: number; invitedBy: number | null; }[], { id: number; invitedBy: number | null; }[], ] ``` ```ts type BatchResponse = [ { id: number; }[], D1Result, { id: number; name: string; verified: number; invitedBy: number | null; }[], { id: number; name: string; verified: number; invitedBy: number | null; }[], { id: number; invitedBy: number | null; }[], ] ``` All possible builders that can be used inside `db.batch`: ```ts db.all(), db.get(), db.values(), db.run(), db.execute(), db.query..findMany(), db.query.
.findFirst(), db.select()..., db.update()..., db.delete()..., db.insert()..., ``` Source: https://orm.drizzle.team/docs/column-types/mysql import Section from '@mdx/Section.astro'; import Callout from '@mdx/Callout.astro'; We have native support for all of them, yet if that's not enough for you, feel free to create **[custom types](/docs/custom-types)**. All examples in this part of the documentation do not use database column name aliases, and column names are generated from TypeScript keys. You can use database aliases in column names if you want, and you can also use the `casing` parameter to define a mapping strategy for Drizzle. You can read more about it [here](/docs/sql-schema-declaration#shape-your-data-schema) ### integer A signed integer, stored in `0`, `1`, `2`, `3`, `4`, `6`, or `8` bytes depending on the magnitude of the value.
```typescript import { int, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { int: int() }); ``` ```sql CREATE TABLE `table` ( `int` int, ); ```
### tinyint
```typescript import { tinyint, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { tinyint: tinyint() }); ``` ```sql CREATE TABLE `table` ( `tinyint` tinyint, ); ```
### smallint
```typescript import { smallint, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { smallint: smallint() }); ``` ```sql CREATE TABLE `table` ( `smallint` smallint, ); ```
### mediumint
```typescript import { mediumint, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { mediumint: mediumint() }); ``` ```sql CREATE TABLE `table` ( `mediumint` mediumint, ); ```
### bigint
```typescript import { bigint, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { bigint: bigint({ mode: 'number' }) bigintUnsigned: bigint({ mode: 'number', unsigned: true }) }); bigint('...', { mode: 'number' | 'bigint' }); // You can also specify unsigned option for bigint bigint('...', { mode: 'number' | 'bigint', unsigned: true }) ``` ```sql CREATE TABLE `table` ( `bigint` bigint, `bigintUnsigned` bigint unsigned, ); ```
We've omitted config of `M` in `bigint(M)`, since it indicates the display width of the numeric type ## --- ### real
```typescript import { real, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { real: real() }); ``` ```sql CREATE TABLE `table` ( `real` real, ); ```
```typescript import { real, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { realPrecision: real({ precision: 1,}), realPrecisionScale: real({ precision: 1, scale: 1,}), }); ``` ```sql CREATE TABLE `table` ( `realPrecision` real(1), `realPrecisionScale` real(1, 1), ); ```
### decimal
```typescript import { decimal, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { decimal: decimal() }); ``` ```sql CREATE TABLE `table` ( `decimal` decimal, ); ```
```typescript import { decimal, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { decimalPrecision: decimal({ precision: 1,}), decimalPrecisionScale: decimal({ precision: 1, scale: 1,}), }); ``` ```sql CREATE TABLE `table` ( `decimalPrecision` decimal(1), `decimalPrecisionScale` decimal(1, 1), ); ```
### double
```typescript import { double, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { double: double('double') }); ``` ```sql CREATE TABLE `table` ( `double` double, ); ```
```typescript import { double, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { doublePrecision: double({ precision: 1,}), doublePrecisionScale: double({ precision: 1, scale: 1,}), }); ``` ```sql CREATE TABLE `table` ( `doublePrecision` double(1), `doublePrecisionScale` double(1, 1), ); ```
### float
```typescript import { float, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { float: float() }); ``` ```sql CREATE TABLE `table` ( `float` float, ); ```
## --- ### serial
`SERIAL` is an alias for `BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE`. ```typescript import { serial, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { serial: serial() }); ``` ```sql CREATE TABLE `table` ( `serial` serial AUTO_INCREMENT, ); ```
## --- ### binary
```typescript import { binary, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { binary: binary() }); ``` ```sql CREATE TABLE `table` ( `binary` binary, ); ```
### varbinary
```typescript import { varbinary, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { varbinary: varbinary({ length: 2}), }); ``` ```sql CREATE TABLE `table` ( `varbinary` varbinary(2), ); ```
## --- ### char
```typescript import { char, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { char: char(), }); ``` ```sql CREATE TABLE `table` ( `char` char, ); ```
### varchar You can define `{ enum: ["value1", "value2"] }` config to infer `insert` and `select` types, it **won't** check runtime values.
```typescript import { varchar, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { varchar: varchar({ length: 2 }), }); // will be inferred as text: "value1" | "value2" | null varchar: varchar({ length: 6, enum: ["value1", "value2"] }) ``` ```sql CREATE TABLE `table` ( `varchar` varchar(2), ); ```
### text You can define `{ enum: ["value1", "value2"] }` config to infer `insert` and `select` types, it **won't** check runtime values.
```typescript import { text, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { text: text(), }); // will be inferred as text: "value1" | "value2" | null text: text({ enum: ["value1", "value2"] }); ``` ```sql CREATE TABLE `table` ( `text` text, ); ```
## --- ### boolean
```typescript import { boolean, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { boolean: boolean(), }); ``` ```sql CREATE TABLE `table` ( `boolean` boolean, ); ```
## --- ### date
```typescript import { boolean, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { date: date(), }); ``` ```sql CREATE TABLE `table` ( `date` date, ); ```
### datetime
```typescript import { datetime, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { datetime: datetime(), }); datetime('...', { mode: 'date' | "string"}), datetime('...', { fsp : 0..6}), ``` ```sql CREATE TABLE `table` ( `datetime` datetime, ); ```
```typescript import { datetime, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { datetime: datetime({ mode: 'date', fsp: 6 }), }); ``` ```sql CREATE TABLE `table` ( `datetime` datetime(6), ); ```
### time
```typescript import { time, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { time: time(), timefsp: time({ fsp: 6 }), }); time('...', { fsp: 0..6 }), ``` ```sql CREATE TABLE `table` ( `time` time, `timefsp` time(6), ); ```
### year
```typescript import { year, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { year: year(), }); ``` ```sql CREATE TABLE `table` ( `year` year, ); ```
### timestamp
```typescript import { timestamp, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { timestamp: timestamp(), }); timestamp('...', { mode: 'date' | "string"}), timestamp('...', { fsp : 0..6}), ``` ```sql CREATE TABLE `table` ( `timestamp` timestamp, ); ```
```typescript import { timestamp, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { timestamp: timestamp({ mode: 'date', fsp: 6 }), }); ``` ```sql CREATE TABLE `table` ( `timestamp` timestamp(6), ); ```
```typescript import { timestamp, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { timestamp: timestamp().defaultNow(), }); ``` ```sql CREATE TABLE `table` ( `timestamp` timestamp DEFAULT (now()), ); ```
## --- ### json
```typescript import { json, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { json: json(), }); ``` ```sql CREATE TABLE `table` ( `json` json, ); ```
You can specify `.$type<..>()` for json object inference, it **won't** check runtime values. It provides compile time protection for default values, insert and select schemas. ```typescript // will be inferred as { foo: string } json: json().$type<{ foo: string }>(); // will be inferred as string[] json: json().$type(); // won't compile json: json().$type().default({}); ``` ## --- ### enum
```typescript import { mysqlEnum, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { mysqlEnum: mysqlEnum(['unknown', 'known', 'popular']), }); ``` ```sql CREATE TABLE `table` ( `popularity` enum('unknown','known','popular'), ); ```
## --- ### Customizing data type Every column builder has a `.$type()` method, which allows you to customize the data type of the column. This is useful, for example, with unknown or branded types. ```ts type UserId = number & { __brand: 'user_id' }; type Data = { foo: string; bar: number; }; const users = mysqlTable('users', { id: int().$type().primaryKey(), jsonField: json().$type(), }); ``` ### Not null `NOT NULL` constraint dictates that the associated column may not contain a `NULL` value.
```typescript import { int, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { int: int().notNull(), }); ``` ```sql CREATE TABLE `table` ( `int` int NOT NULL, ); ```
### Default value The `DEFAULT` clause specifies a default value to use for the column if no value is explicitly provided by the user when doing an `INSERT`. If there is no explicit `DEFAULT` clause attached to a column definition, then the default value of the column is `NULL`. An explicit `DEFAULT` clause may specify that the default value is `NULL`, a string constant, a blob constant, a signed-number, or any constant expression enclosed in parentheses.
```typescript import { int, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { int: int().default(3), }); ``` ```sql CREATE TABLE `table` ( `int` int DEFAULT 3, ); ```
When using `$default()` or `$defaultFn()`, which are simply different aliases for the same function, you can generate defaults at runtime and use these values in all insert queries. These functions can assist you in utilizing various implementations such as `uuid`, `cuid`, `cuid2`, and many more. Note: This value does not affect the `drizzle-kit` behavior, it is only used at runtime in `drizzle-orm` ```ts import { varchar, mysqlTable } from "drizzle-orm/mysql-core"; import { createId } from '@paralleldrive/cuid2'; const table = mysqlTable('table', { id: varchar({ length: 128 }).$defaultFn(() => createId()), }); ``` When using `$onUpdate()` or `$onUpdateFn()`, which are simply different aliases for the same function, you can generate defaults at runtime and use these values in all update queries. Adds a dynamic update value to the column. The function will be called when the row is updated, and the returned value will be used as the column value if none is provided. If no default (or $defaultFn) value is provided, the function will be called when the row is inserted as well, and the returned value will be used as the column value. Note: This value does not affect the `drizzle-kit` behavior, it is only used at runtime in `drizzle-orm` ```ts import { text, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { alwaysNull: text().$type().$onUpdate(() => null), }); ``` ### Primary key
```typescript import { int, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { int: int().primaryKey(), }); ``` ```sql CREATE TABLE `table` ( `int` int PRIMARY KEY NOT NULL, ); ```
### Auto increment
```typescript import { int, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { int: int().autoincrement(), }); ``` ```sql CREATE TABLE `table` ( `int` int AUTO_INCREMENT ); ```
Source: https://orm.drizzle.team/docs/column-types/pg import Section from '@mdx/Section.astro'; import Callout from '@mdx/Callout.astro'; We have native support for all of them, yet if that's not enough for you, feel free to create **[custom types](/docs/custom-types)**. All examples in this part of the documentation do not use database column name aliases, and column names are generated from TypeScript keys. You can use database aliases in column names if you want, and you can also use the `casing` parameter to define a mapping strategy for Drizzle. You can read more about it [here](/docs/sql-schema-declaration#shape-your-data-schema) ### integer `integer` `int` `int4` Signed 4-byte integer If you need `integer autoincrement` please refer to **[serial.](#serial)**
```typescript import { integer, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { int: integer() }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "int" integer ); ```
```typescript import { sql } from "drizzle-orm"; import { integer, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { int1: integer().default(10), int2: integer().default(sql`'10'::int`) }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "int1" integer DEFAULT 10 "int2" integer DEFAULT '10'::int ); ```
### smallint `smallint` `int2` Small-range signed 2-byte integer If you need `smallint autoincrement` please refer to **[smallserial.](#smallserial)**
```typescript import { smallint, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { smallint: smallint() }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "smallint" smallint ); ```
```typescript import { sql } from "drizzle-orm"; import { smallint, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { smallint1: smallint().default(10), smallint2: smallint().default(sql`'10'::smallint`) }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "smallint1" smallint DEFAULT 10 "smallint2" smallint DEFAULT '10'::smallint ); ```
### bigint `bigint` `int8` Signed 8-byte integer If you need `bigint autoincrement` please refer to **[bigserial.](#bigserial)** If you're expecting values above 2^31 but below 2^53, you can utilise `mode: 'number'` and deal with javascript number as opposed to bigint.
```typescript import { bigint, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { bigint: bigint({ mode: 'number' }) }); // will be inferred as `number` bigint: bigint({ mode: 'number' }) // will be inferred as `bigint` bigint: bigint({ mode: 'bigint' }) ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "bigint" bigint ); ```
```typescript import { sql } from "drizzle-orm"; import { bigint, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { bigint1: bigint().default(10), bigint2: bigint().default(sql`'10'::bigint`) }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "bigint1" bigint DEFAULT 10 "bigint2" bigint DEFAULT '10'::bigint ); ```
## --- ### serial `serial` `serial4` Auto incrementing 4-bytes integer, notational convenience for creating unique identifier columns (similar to the `AUTO_INCREMENT` property supported by some other databases). For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-numeric.html#DATATYPE-SERIAL)**
```typescript import { serial, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { serial: serial(), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "serial" serial NOT NULL, ); ```
### smallserial `smallserial` `serial2` Auto incrementing 2-bytes integer, notational convenience for creating unique identifier columns (similar to the `AUTO_INCREMENT` property supported by some other databases). For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-numeric.html#DATATYPE-SERIAL)**
```typescript import { smallserial, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { smallserial: smallserial(), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "smallserial" smallserial NOT NULL, ); ```
### bigserial `bigserial` `serial8` Auto incrementing 8-bytes integer, notational convenience for creating unique identifier columns (similar to the `AUTO_INCREMENT` property supported by some other databases). For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-numeric.html#DATATYPE-SERIAL)** If you're expecting values above 2^31 but below 2^53, you can utilise `mode: 'number'` and deal with javascript number as opposed to bigint.
```typescript import { bigserial, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { bigserial: bigserial({ mode: 'number' }), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "bigserial" bigserial NOT NULL, ); ```
### --- ### boolean PostgreSQL provides the standard SQL type boolean. For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-boolean.html)**
```typescript import { boolean, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { boolean: boolean() }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "boolean" boolean, ); ```
## --- ### text `text` Variable-length(unlimited) character string. For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-character.html)** You can define `{ enum: ["value1", "value2"] }` config to infer `insert` and `select` types, it **won't** check runtime values.
```typescript import { text, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { text: text() }); // will be inferred as text: "value1" | "value2" | null text: text({ enum: ["value1", "value2"] }) ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "text" text, ); ```
### varchar `character varying(n)` `varchar(n)` Variable-length character string, can store strings up to **`n`** characters (not bytes). For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-character.html)** You can define `{ enum: ["value1", "value2"] }` config to infer `insert` and `select` types, it **won't** check runtime values. The `length` parameter is optional according to PostgreSQL docs.
```typescript import { varchar, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { varchar1: varchar(), varchar2: varchar({ length: 256 }), }); // will be inferred as text: "value1" | "value2" | null varchar: varchar({ enum: ["value1", "value2"] }), ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "varchar1" varchar, "varchar2" varchar(256), ); ```
### char `character(n)` `char(n)` Fixed-length, blank padded character string, can store strings up to **`n`** characters(not bytes). For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-character.html)** You can define `{ enum: ["value1", "value2"] }` config to infer `insert` and `select` types, it **won't** check runtime values. The `length` parameter is optional according to PostgreSQL docs.
```typescript import { char, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { char1: char(), char2: char({ length: 256 }), }); // will be inferred as text: "value1" | "value2" | null char: char({ enum: ["value1", "value2"] }), ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "char1" char, "char2" char(256), ); ```
## --- ### numeric `numeric` `decimal` Exact numeric of selectable precision. Can store numbers with a very large number of digits, up to 131072 digits before the decimal point and up to 16383 digits after the decimal point. For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-numeric.html#DATATYPE-NUMERIC-DECIMAL)**
```typescript import { numeric, pgTable } from "drizzle-orm/pg-core"; export const table = pgTable('table', { numeric1: numeric(), numeric2: numeric({ precision: 100 }), numeric3: numeric({ precision: 100, scale: 20 }), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "numeric1" numeric, "numeric2" numeric(100), "numeric3" numeric(100, 20), ); ```
### decimal An alias of **[numeric.](#numeric)** ### real `real` `float4` Single precision floating-point number (4 bytes) For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-numeric.html)**
```typescript import { sql } from "drizzle-orm"; import { real, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { real1: real(), real2: real().default(10.10), real2: real().default(sql`'10.10'::real`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "real1" real, "real2" real default 10.10, "real2" real default '10.10'::real ); ```
### double precision `double precision` `float8` Double precision floating-point number (8 bytes) For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-numeric.html)**
```typescript import { sql } from "drizzle-orm"; import { doublePrecision, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { double1: doublePrecision(), double2: doublePrecision().default(10.10), double3: doublePrecision().default(sql`'10.10'::double precision`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "double1" double precision, "double2" double precision default 10.10, "double3" double precision default '10.10'::double precision, ); ```
## --- ### json `json` Textual JSON data, as specified in **[RFC 7159.](https://tools.ietf.org/html/rfc7159)** For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-json.html)**
```typescript import { sql } from "drizzle-orm"; import { json, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { json1: json(), json2: json().default({ foo: "bar" }), json3: json().default(sql`'{foo: "bar"}'::json`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "json1" json, "json2" json default '{"foo": "bar"}'::json, "json3" json default '{"foo": "bar"}'::json, ); ```
You can specify `.$type<..>()` for json object inference, it **won't** check runtime values. It provides compile time protection for default values, insert and select schemas. ```typescript // will be inferred as { foo: string } json: json().$type<{ foo: string }>(); // will be inferred as string[] json: json().$type(); // won't compile json: json().$type().default({}); ``` ### jsonb `jsonb` Binary JSON data, decomposed. For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-json.html)**
```typescript import { jsonb, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { jsonb1: jsonb(), jsonb2: jsonb().default({ foo: "bar" }), jsonb3: jsonb().default(sql`'{foo: "bar"}'::jsonb`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "jsonb1" jsonb, "jsonb2" jsonb default '{"foo": "bar"}'::jsonb, "jsonb3" jsonb default '{"foo": "bar"}'::jsonb, ); ```
You can specify `.$type<..>()` for json object inference, it **won't** check runtime values. It provides compile time protection for default values, insert and select schemas. ```typescript // will be inferred as { foo: string } jsonb: jsonb().$type<{ foo: string }>(); // will be inferred as string[] jsonb: jsonb().$type(); // won't compile jsonb: jsonb().$type().default({}); ``` ## --- ### time `time` `timetz` `time with timezone` `time without timezone` Time of day with or without time zone. For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-datetime.html)**
```typescript import { time, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { time1: time(), time2: time({ withTimezone: true }), time3: time({ precision: 6 }), time4: time({ precision: 6, withTimezone: true }) }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "time1" time, "time2" time with timezone, "time3" time(6), "time4" time(6) with timezone, ); ```
### timestamp `timestamp` `timestamptz` `timestamp with time zone` `timestamp without time zone` Date and time with or without time zone. For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-datetime.html)**
```typescript import { sql } from "drizzle-orm"; import { timestamp, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { timestamp1: timestamp(), timestamp2: timestamp({ precision: 6, withTimezone: true }), timestamp3: timestamp().defaultNow(), timestamp4: timestamp().default(sql`now()`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "timestamp1" timestamp, "timestamp2" timestamp (6) with time zone, "timestamp3" timestamp default now(), "timestamp4" timestamp default now(), ); ```
You can specify either `date` or `string` infer modes: ```typescript // will infer as date timestamp: timestamp({ mode: "date" }), // will infer as string timestamp: timestamp({ mode: "string" }), ``` > The `string` mode does not perform any mappings for you. This mode was added to Drizzle ORM to provide developers with the possibility to handle dates and date mappings themselves, depending on their needs. Drizzle will pass raw dates as strings `to` and `from` the database, so the behavior should be as predictable as possible and aligned 100% with the database behavior > The `date` mode is the regular way to work with dates. Drizzle will take care of all mappings between the database and the JS Date object How mapping works for `timestamp` and `timestamp with timezone`: As PostgreSQL docs stated: > In a literal that has been determined to be timestamp without time zone, PostgreSQL will silently ignore any time zone indication. > That is, the resulting value is derived from the date/time fields in the input value, and is not adjusted for time zone. > > For timestamp with time zone, the internally stored value is always in UTC (Universal Coordinated Time, traditionally known as Greenwich Mean Time, GMT). An input value that has an explicit time zone specified is converted to UTC using the appropriate offset for that time zone. If no time zone is stated in the input string, then it is assumed to be in the time zone indicated by the system's TimeZone parameter, and is converted to UTC using the offset for the timezone zone. So for `timestamp with timezone` you will get back string converted to a timezone set in you Postgres instance. You can check timezone using this sql query: ```sql show timezone; ``` ### date `date` Calendar date (year, month, day) For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-datetime.html)**
```typescript import { date, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { date: date(), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "date" date, ); ```
You can specify either `date` or `string` infer modes: ```typescript // will infer as date date: date({ mode: "date" }), // will infer as string date: date({ mode: "string" }), ``` ### interval `interval` Time span For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-datetime.html)**
```typescript import { interval, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { interval1: interval(), interval2: interval({ fields: 'day' }), interval3: interval({ fields: 'month' , precision: 6 }), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "interval1" interval, "interval2" interval day, "interval3" interval(6) month, ); ```
## --- ### point `point` Geometric point type For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-geometric.html#DATATYPE-GEOMETRIC-POINTS)** Type `point` has 2 modes for mappings from the database: `tuple` and `xy`. - `tuple` will be accepted for insert and mapped on select to a tuple. So, the database Point(1,2) will be typed as [1,2] with drizzle. - `xy` will be accepted for insert and mapped on select to an object with x, y coordinates. So, the database Point(1,2) will be typed as `{ x: 1, y: 2 }` with drizzle
```typescript const items = pgTable('items', { point: point(), pointObj: point({ mode: 'xy' }), }); ``` ```sql CREATE TABLE IF NOT EXISTS "items" ( "point" point, "pointObj" point, ); ```
### line `line` Geometric line type For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-geometric.html#DATATYPE-LINE)** Type `line` has 2 modes for mappings from the database: `tuple` and `abc`. - `tuple` will be accepted for insert and mapped on select to a tuple. So, the database Line{1,2,3} will be typed as [1,2,3] with drizzle. - `abc` will be accepted for insert and mapped on select to an object with a, b, and c constants from the equation `Ax + By + C = 0`. So, the database Line{1,2,3} will be typed as `{ a: 1, b: 2, c: 3 }` with drizzle.
```typescript const items = pgTable('items', { line: line(), lineObj: point({ mode: 'abc' }), }); ``` ```sql CREATE TABLE IF NOT EXISTS "items" ( "line" line, "lineObj" line, ); ```
## --- ### enum `enum` `enumerated types` Enumerated (enum) types are data types that comprise a static, ordered set of values. They are equivalent to the enum types supported in a number of programming languages. An example of an enum type might be the days of the week, or a set of status values for a piece of data. For more info please refer to the official PostgreSQL **[docs.](https://www.postgresql.org/docs/current/datatype-enum.html)**
```typescript import { pgEnum, pgTable } from "drizzle-orm/pg-core"; export const moodEnum = pgEnum('mood', ['sad', 'ok', 'happy']); export const table = pgTable('table', { mood: moodEnum(), }); ``` ```sql CREATE TYPE mood AS ENUM ('sad', 'ok', 'happy'); CREATE TABLE IF NOT EXISTS "table" ( "mood" mood, ); ```
## --- ### Customizing data type Every column builder has a `.$type()` method, which allows you to customize the data type of the column. This is useful, for example, with unknown or branded types: ```ts type UserId = number & { __brand: 'user_id' }; type Data = { foo: string; bar: number; }; const users = pgTable('users', { id: serial().$type().primaryKey(), jsonField: json().$type(), }); ``` ### Identity Columns To use this feature you would need to have `drizzle-orm@0.32.0` or higher and `drizzle-kit@0.23.0` or higher PostgreSQL supports identity columns as a way to automatically generate unique integer values for a column. These values are generated using sequences and can be defined using the GENERATED AS IDENTITY clause. **Types of Identity Columns** - `GENERATED ALWAYS AS IDENTITY`: The database always generates a value for the column. Manual insertion or updates to this column are not allowed unless the OVERRIDING SYSTEM VALUE clause is used. - `GENERATED BY DEFAULT AS IDENTITY`: The database generates a value by default, but manual values can also be inserted or updated. If a manual value is provided, it will be used instead of the system-generated value. **Key Features** - Automatic Value Generation: Utilizes sequences to generate unique values for each new row. - Customizable Sequence Options: You can define starting values, increments, and other sequence options. - Support for Multiple Identity Columns: PostgreSQL allows more than one identity column per table. **Limitations** - Manual Insertion Restrictions: For columns defined with GENERATED ALWAYS AS IDENTITY, manual insertion or updates require the OVERRIDING SYSTEM VALUE clause. - Sequence Constraints: Identity columns depend on sequences, which must be managed correctly to avoid conflicts or gaps. **Usage example** ```ts import { pgTable, integer, text } from 'drizzle-orm/pg-core' export const ingredients = pgTable("ingredients", { id: integer().primaryKey().generatedAlwaysAsIdentity({ startWith: 1000 }), name: text().notNull(), description: text(), }); ``` You can specify all properties available for sequences in the `.generatedAlwaysAsIdentity()` function. Additionally, you can specify custom names for these sequences PostgreSQL docs [reference](https://www.postgresql.org/docs/current/sql-createtable.html#SQL-CREATETABLE-PARMS-GENERATED-IDENTITY). ### Default value The `DEFAULT` clause specifies a default value to use for the column if no value is explicitly provided by the user when doing an `INSERT`. If there is no explicit `DEFAULT` clause attached to a column definition, then the default value of the column is `NULL`. An explicit `DEFAULT` clause may specify that the default value is `NULL`, a string constant, a blob constant, a signed-number, or any constant expression enclosed in parentheses.
```typescript import { sql } from "drizzle-orm"; import { integer, pgTable, uuid } from "drizzle-orm/pg-core"; const table = pgTable('table', { integer1: integer().default(42), integer2: integer().default(sql`'42'::integer`), uuid1: uuid().defaultRandom(), uuid2: uuid().default(sql`gen_random_uuid()`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "integer1" integer DEFAULT 42, "integer2" integer DEFAULT '42'::integer, "uuid1" uuid DEFAULT gen_random_uuid(), "uuid2" uuid DEFAULT gen_random_uuid() ); ```
When using `$default()` or `$defaultFn()`, which are simply different aliases for the same function, you can generate defaults at runtime and use these values in all insert queries. These functions can assist you in utilizing various implementations such as `uuid`, `cuid`, `cuid2`, and many more. Note: This value does not affect the `drizzle-kit` behavior, it is only used at runtime in `drizzle-orm` ```ts import { text, pgTable } from "drizzle-orm/pg-core"; import { createId } from '@paralleldrive/cuid2'; const table = pgTable('table', { id: text().$defaultFn(() => createId()), }); ``` When using `$onUpdate()` or `$onUpdateFn()`, which are simply different aliases for the same function, you can generate defaults at runtime and use these values in all update queries. Adds a dynamic update value to the column. The function will be called when the row is updated, and the returned value will be used as the column value if none is provided. If no default (or $defaultFn) value is provided, the function will be called when the row is inserted as well, and the returned value will be used as the column value. Note: This value does not affect the `drizzle-kit` behavior, it is only used at runtime in `drizzle-orm` ```ts import { integer, timestamp, text, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { updateCounter: integer().default(sql`1`).$onUpdateFn((): SQL => sql`${table.update_counter} + 1`), updatedAt: timestamp({ mode: 'date', precision: 3 }).$onUpdate(() => new Date()), alwaysNull: text().$type().$onUpdate(() => null), }); ``` ### Not null `NOT NULL` constraint dictates that the associated column may not contain a `NULL` value.
```typescript import { integer, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { integer: integer().notNull(), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "integer" integer NOT NULL, ); ```
### Primary key A primary key constraint indicates that a column, or group of columns, can be used as a unique identifier for rows in the table. This requires that the values be both unique and not null.
```typescript import { serial, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { id: serial().primaryKey(), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "id" serial PRIMARY KEY NOT NULL, ); ```
Source: https://orm.drizzle.team/docs/column-types/singlestore import Section from '@mdx/Section.astro'; import Callout from '@mdx/Callout.astro'; We have native support for all of them, yet if that's not enough for you, feel free to create **[custom types](/docs/custom-types)**. All examples in this part of the documentation do not use database column name aliases, and column names are generated from TypeScript keys. You can use database aliases in column names if you want, and you can also use the `casing` parameter to define a mapping strategy for Drizzle. You can read more about it [here](/docs/sql-schema-declaration#shape-your-data-schema) ### integer A signed integer, stored in `0`, `1`, `2`, `3`, `4`, `6`, or `8` bytes depending on the magnitude of the value.
```typescript import { int, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { int: int() }); ``` ```sql CREATE TABLE `table` ( `int` int, ); ```
### tinyint
```typescript import { tinyint, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { tinyint: tinyint() }); ``` ```sql CREATE TABLE `table` ( `tinyint` tinyint, ); ```
### smallint
```typescript import { smallint, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { smallint: smallint() }); ``` ```sql CREATE TABLE `table` ( `smallint` smallint, ); ```
### mediumint
```typescript import { mediumint, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { mediumint: mediumint() }); ``` ```sql CREATE TABLE `table` ( `mediumint` mediumint, ); ```
### bigint
```typescript import { bigint, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { bigint: bigint({ mode: 'number' }) bigintUnsigned: bigint({ mode: 'number', unsigned: true }) }); bigint('...', { mode: 'number' | 'bigint' }); // You can also specify unsigned option for bigint bigint('...', { mode: 'number' | 'bigint', unsigned: true }) ``` ```sql CREATE TABLE `table` ( `bigint` bigint, `bigintUnsigned` bigint unsigned, ); ```
We've omitted config of `M` in `bigint(M)`, since it indicates the display width of the numeric type ## --- ### real
```typescript import { real, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { real: real() }); ``` ```sql CREATE TABLE `table` ( `real` real, ); ```
```typescript import { real, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { realPrecision: real({ precision: 1,}), realPrecisionScale: real({ precision: 1, scale: 1,}), }); ``` ```sql CREATE TABLE `table` ( `realPrecision` real(1), `realPrecisionScale` real(1, 1), ); ```
### decimal
```typescript import { decimal, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { decimal: decimal() }); ``` ```sql CREATE TABLE `table` ( `decimal` decimal, ); ```
```typescript import { decimal, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { decimalPrecision: decimal({ precision: 1,}), decimalPrecisionScale: decimal({ precision: 1, scale: 1,}), }); ``` ```sql CREATE TABLE `table` ( `decimalPrecision` decimal(1), `decimalPrecisionScale` decimal(1, 1), ); ```
### double
```typescript import { double, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { double: double('double') }); ``` ```sql CREATE TABLE `table` ( `double` double, ); ```
```typescript import { double, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { doublePrecision: double({ precision: 1,}), doublePrecisionScale: double({ precision: 1, scale: 1,}), }); ``` ```sql CREATE TABLE `table` ( `doublePrecision` double(1), `doublePrecisionScale` double(1, 1), ); ```
### float
```typescript import { float, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { float: float() }); ``` ```sql CREATE TABLE `table` ( `float` float, ); ```
## --- ### serial
`SERIAL` is an alias for `BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE`. ```typescript import { serial, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { serial: serial() }); ``` ```sql CREATE TABLE `table` ( `serial` serial AUTO_INCREMENT, ); ```
## --- ### binary
```typescript import { binary, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { binary: binary() }); ``` ```sql CREATE TABLE `table` ( `binary` binary, ); ```
### varbinary
```typescript import { varbinary, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { varbinary: varbinary({ length: 2}), }); ``` ```sql CREATE TABLE `table` ( `varbinary` varbinary(2), ); ```
## --- ### char
```typescript import { char, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { char: char(), }); ``` ```sql CREATE TABLE `table` ( `char` char, ); ```
### varchar You can define `{ enum: ["value1", "value2"] }` config to infer `insert` and `select` types, it **won't** check runtime values.
```typescript import { varchar, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { varchar: varchar({ length: 2 }), }); // will be inferred as text: "value1" | "value2" | null varchar: varchar({ length: 6, enum: ["value1", "value2"] }) ``` ```sql CREATE TABLE `table` ( `varchar` varchar(2), ); ```
### text You can define `{ enum: ["value1", "value2"] }` config to infer `insert` and `select` types, it **won't** check runtime values.
```typescript import { text, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { text: text(), }); // will be inferred as text: "value1" | "value2" | null text: text({ enum: ["value1", "value2"] }); ``` ```sql CREATE TABLE `table` ( `text` text, ); ```
## --- ### boolean
```typescript import { boolean, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { boolean: boolean(), }); ``` ```sql CREATE TABLE `table` ( `boolean` boolean, ); ```
## --- ### date
```typescript import { boolean, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { date: date(), }); ``` ```sql CREATE TABLE `table` ( `date` date, ); ```
### datetime
```typescript import { datetime, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { datetime: datetime(), }); datetime('...', { mode: 'date' | "string"}), ``` ```sql CREATE TABLE `table` ( `datetime` datetime, ); ```
### time
```typescript import { time, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { time: time(), }); ``` ```sql CREATE TABLE `table` ( `time` time ); ```
### year
```typescript import { year, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { year: year(), }); ``` ```sql CREATE TABLE `table` ( `year` year, ); ```
### timestamp
```typescript import { timestamp, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { timestamp: timestamp(), }); timestamp('...', { mode: 'date' | "string"}), ``` ```sql CREATE TABLE `table` ( `timestamp` timestamp, ); ```
```typescript import { timestamp, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { timestamp: timestamp().defaultNow(), }); ``` ```sql CREATE TABLE `table` ( `timestamp` timestamp DEFAULT (now()), ); ```
## --- ### json
```typescript import { json, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { json: json(), }); ``` ```sql CREATE TABLE `table` ( `json` json, ); ```
You can specify `.$type<..>()` for json object inference, it **won't** check runtime values. It provides compile time protection for default values, insert and select schemas. ```typescript // will be inferred as { foo: string } json: json().$type<{ foo: string }>(); // will be inferred as string[] json: json().$type(); // won't compile json: json().$type().default({}); ``` ## --- ### enum
```typescript import { mysqlEnum, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { mysqlEnum: mysqlEnum(['unknown', 'known', 'popular']), }); ``` ```sql CREATE TABLE `table` ( `popularity` enum('unknown','known','popular'), ); ```
## --- ### Customizing data type Every column builder has a `.$type()` method, which allows you to customize the data type of the column. This is useful, for example, with unknown or branded types. ```ts type UserId = number & { __brand: 'user_id' }; type Data = { foo: string; bar: number; }; const users = singlestoreTable('users', { id: int().$type().primaryKey(), jsonField: json().$type(), }); ``` ### Not null `NOT NULL` constraint dictates that the associated column may not contain a `NULL` value.
```typescript import { int, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { int: int().notNull(), }); ``` ```sql CREATE TABLE `table` ( `int` int NOT NULL, ); ```
### Default value The `DEFAULT` clause specifies a default value to use for the column if no value is explicitly provided by the user when doing an `INSERT`. If there is no explicit `DEFAULT` clause attached to a column definition, then the default value of the column is `NULL`. An explicit `DEFAULT` clause may specify that the default value is `NULL`, a string constant, a blob constant, a signed-number, or any constant expression enclosed in parentheses.
```typescript import { int, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { int: int().default(3), }); ``` ```sql CREATE TABLE `table` ( `int` int DEFAULT 3, ); ```
When using `$default()` or `$defaultFn()`, which are simply different aliases for the same function, you can generate defaults at runtime and use these values in all insert queries. These functions can assist you in utilizing various implementations such as `uuid`, `cuid`, `cuid2`, and many more. Note: This value does not affect the `drizzle-kit` behavior, it is only used at runtime in `drizzle-orm` ```ts import { varchar, singlestoreTable } from "drizzle-orm/mysql-core"; import { createId } from '@paralleldrive/cuid2'; const table = singlestoreTable('table', { id: varchar({ length: 128 }).$defaultFn(() => createId()), }); ``` When using `$onUpdate()` or `$onUpdateFn()`, which are simply different aliases for the same function, you can generate defaults at runtime and use these values in all update queries. Adds a dynamic update value to the column. The function will be called when the row is updated, and the returned value will be used as the column value if none is provided. If no default (or $defaultFn) value is provided, the function will be called when the row is inserted as well, and the returned value will be used as the column value. Note: This value does not affect the `drizzle-kit` behavior, it is only used at runtime in `drizzle-orm` ```ts import { text, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { alwaysNull: text().$type().$onUpdate(() => null), }); ``` ### Primary key
```typescript import { int, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { int: int().primaryKey(), }); ``` ```sql CREATE TABLE `table` ( `int` int PRIMARY KEY NOT NULL, ); ```
### Auto increment
```typescript import { int, singlestoreTable } from "drizzle-orm/mysql-core"; const table = singlestoreTable('table', { int: int().autoincrement(), }); ``` ```sql CREATE TABLE `table` ( `int` int AUTO_INCREMENT ); ```
Source: https://orm.drizzle.team/docs/column-types/sqlite import Section from '@mdx/Section.astro'; import Callout from '@mdx/Callout.astro'; Based on the official **[SQLite docs](https://www.sqlite.org/datatype3.html)**, each value stored in an SQLite database (or manipulated by the database engine) has one of the following storage classes `NULL`, `INTEGER`, `REAL`, `TEXT` and `BLOB`. We have native support for all of them, yet if that's not enough for you, feel free to create **[custom types](/docs/custom-types)**. All examples in this part of the documentation do not use database column name aliases, and column names are generated from TypeScript keys. You can use database aliases in column names if you want, and you can also use the `casing` parameter to define a mapping strategy for Drizzle. You can read more about it [here](/docs/sql-schema-declaration#shape-your-data-schema) ### Integer A signed integer, stored in `0`, `1`, `2`, `3`, `4`, `6`, or `8` bytes depending on the magnitude of the value.
```typescript import { integer, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { id: integer() }); // you can customize integer mode to be number, boolean, timestamp, timestamp_ms integer({ mode: 'number' }) integer({ mode: 'boolean' }) integer({ mode: 'timestamp_ms' }) integer({ mode: 'timestamp' }) // Date ``` ```sql CREATE TABLE `table` ( `id` integer ); ```
```typescript // to make integer primary key auto increment integer({ mode: 'number' }).primaryKey({ autoIncrement: true }) ``` ```sql CREATE TABLE `table` ( `id` integer PRIMARY KEY AUTOINCREMENT NOT NULL ); ```
### Real A floating point value, stored as an `8-byte IEEE` floating point number.
```typescript import { real, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { real: real() }); ``` ```sql CREATE TABLE `table` ( `real` real ); ```
### Text A text string, stored using the database encoding (`UTF-8`, `UTF-16BE` or `UTF-16LE`). You can define `{ enum: ["value1", "value2"] }` config to infer `insert` and `select` types, it **won't** check runtime values.
```typescript import { text, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { text: text() }); // will be inferred as text: "value1" | "value2" | null text({ enum: ["value1", "value2"] }) text({ mode: 'json' }) text({ mode: 'json' }).$type<{ foo: string }>() ``` ```sql CREATE TABLE `table` ( `text` text ); ```
### Blob A blob of data, stored exactly as it was input. It's recommended to use `text('', { mode: 'json' })` instead of `blob('', { mode: 'json' })`, because it supports JSON functions: All JSON functions currently throw an error if any of their arguments are BLOBs because BLOBs are reserved for a future enhancement in which BLOBs will store the binary encoding for JSON. See **https://www.sqlite.org/json1.html**.
```typescript import { blob, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { blob: blob() }); blob() blob({ mode: 'buffer' }) blob({ mode: 'bigint' }) blob({ mode: 'json' }) blob({ mode: 'json' }).$type<{ foo: string }>() ``` ```sql CREATE TABLE `table` ( `blob` blob ); ``` You can specify `.$type<..>()` for blob inference, it **won't** check runtime values. It provides compile time protection for default values, insert and select schemas. ```typescript // will be inferred as { foo: string } json: blob({ mode: 'json' }).$type<{ foo: string }>(); // will be inferred as string[] json: blob({ mode: 'json' }).$type(); // won't compile json: blob({ mode: 'json' }).$type().default({}); ```
### Boolean SQLite does not have native `boolean` data type, yet you can specify `integer` column to be in a `boolean` mode. This allows you to operate boolean values in your code and Drizzle stores them as 0 and 1 integer values in the database.
```typescript import { integer, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { id: integer({ mode: 'boolean' }) }); ``` ```sql CREATE TABLE `table` ( `id` integer ); ```
### Bigint Since there is no `bigint` data type in SQLite, Drizzle offers a special `bigint` mode for `blob` columns. This mode allows you to work with BigInt instances in your code, and Drizzle stores them as blob values in the database.
```typescript import { blob, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { id: blob({ mode: 'bigint' }) }); ``` ```sql CREATE TABLE `table` ( `id` blob ); ```
## --- ### Customizing data type Every column builder has a `.$type()` method, which allows you to customize the data type of the column. This is useful, for example, with unknown or branded types. ```ts type UserId = number & { __brand: 'user_id' }; type Data = { foo: string; bar: number; }; const users = sqliteTable('users', { id: integer().$type().primaryKey(), jsonField: blob().$type(), }); ``` ### Not null `NOT NULL` constraint dictates that the associated column may not contain a `NULL` value.
```typescript const table = sqliteTable('table', { numInt: integer().notNull() }); ``` ```sql CREATE TABLE table ( `numInt` integer NOT NULL ); ```
### Default value The `DEFAULT` clause specifies a default value to use for the column if no value is explicitly provided by the user when doing an `INSERT`. If there is no explicit `DEFAULT` clause attached to a column definition, then the default value of the column is `NULL`. An explicit `DEFAULT` clause may specify that the default value is `NULL`, a string constant, a blob constant, a signed-number, or any constant expression enclosed in parentheses.
```typescript import { sql } from "drizzle-orm"; import { integer, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { int1: integer().default(42), int2: integer().default(sql`(abs(42))`) }); ``` ```sql CREATE TABLE `table` ( `int1` integer DEFAULT 42 `int2` integer DEFAULT (abs(42)) ); ```
A default value may also be one of the special case-independent keywords `CURRENT_TIME`, `CURRENT_DATE` or `CURRENT_TIMESTAMP`.
```typescript import { sql } from "drizzle-orm"; import { text, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable("table", { time: text().default(sql`(CURRENT_TIME)`), date: text().default(sql`(CURRENT_DATE)`), timestamp: text().default(sql`(CURRENT_TIMESTAMP)`), }); ``` ```sql CREATE TABLE `table` ( `time` text DEFAULT (CURRENT_TIME) `date` text DEFAULT (CURRENT_DATE) `timestamp` text DEFAULT (CURRENT_TIMESTAMP) ); ```
When using `$default()` or `$defaultFn()`, which are simply different aliases for the same function, you can generate defaults at runtime and use these values in all insert queries. These functions can assist you in utilizing various implementations such as `uuid`, `cuid`, `cuid2`, and many more. Note: This value does not affect the `drizzle-kit` behavior, it is only used at runtime in `drizzle-orm` ```ts import { text, sqliteTable } from "drizzle-orm/sqlite-core"; import { createId } from '@paralleldrive/cuid2'; const table = sqliteTable('table', { id: text().$defaultFn(() => createId()), }); ``` When using `$onUpdate()` or `$onUpdateFn()`, which are simply different aliases for the same function, you can generate defaults at runtime and use these values in all update queries. Adds a dynamic update value to the column. The function will be called when the row is updated, and the returned value will be used as the column value if none is provided. If no default (or $defaultFn) value is provided, the function will be called when the row is inserted as well, and the returned value will be used as the column value. Note: This value does not affect the `drizzle-kit` behavior, it is only used at runtime in `drizzle-orm` ```ts import { text, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { alwaysNull: text().$type().$onUpdate(() => null), }); ``` Source: https://orm.drizzle.team/docs/connect-aws-data-api-mysql import Callout from '@mdx/Callout.astro'; # Drizzle \<\> AWS Data API MySQL Currently AWS Data API for MySQL is not implemented in Drizzle ORM Source: https://orm.drizzle.team/docs/connect-aws-data-api-pg import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; # Drizzle \<\> AWS Data API Postgres - Database [connection basics](/docs/connect-overview) with Drizzle - AWS Data API - [website](https://docs.aws.amazon.com/AmazonRDS/latest/AuroraUserGuide/data-api.html) - AWS SDK - [website](https://docs.aws.amazon.com/AWSJavaScriptSDK/v3/latest/Package/-aws-sdk-client-rds-data/) #### Step 1 - Install packages drizzle-orm @aws-sdk/client-rds-data -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy import { drizzle } from 'drizzle-orm/aws-data-api-pg'; // These three properties are required. You can also specify // any property from the RDSDataClient type inside the connection object. const db = drizzle({ connection: { database: process.env['DATABASE']!, secretArn: process.env['SECRET_ARN']!, resourceArn: process.env['RESOURCE_ARN']!, }}); await db.select().from(...); ``` If you need to provide your existing driver: ```typescript copy import { drizzle } from 'drizzle-orm/aws-data-api/pg'; import { RDSDataClient } from '@aws-sdk/client-rds-data'; const rdsClient = new RDSDataClient({ region: 'us-east-1' }); const db = drizzle(rdsClient, { database: process.env['DATABASE']!, secretArn: process.env['SECRET_ARN']!, resourceArn: process.env['RESOURCE_ARN']!, }); await db.select().from(...); ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-bun-sql import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; # Drizzle \<\> Bun SQL - Database [connection basics](/docs/connect-overview) with Drizzle - Bun - [website](https://bun.sh/docs) - Bun SQL - native bindings for working with PostgreSQL databases - [read here](https://bun.sh/docs/api/sql) According to the **[official website](https://bun.sh/)**, Bun is a fast all-in-one JavaScript runtime. Drizzle ORM natively supports **[`bun sql`](https://bun.sh/docs/api/sql)** module and it's crazy fast 🚀 In version `1.2.0`, Bun has issues with executing concurrent statements, which may lead to errors if you try to run several queries simultaneously. We've created a [github issue](https://github.com/oven-sh/bun/issues/16774) that you can track. Once it's fixed, you should no longer encounter any such errors on Bun's SQL side #### Step 1 - Install packages drizzle-orm -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy import 'dotenv/config'; import { drizzle } from 'drizzle-orm/bun-sql'; const db = drizzle(process.env.DATABASE_URL); const result = await db.select().from(...); ``` If you need to provide your existing driver: ```typescript copy import 'dotenv/config'; import { drizzle } from 'drizzle-orm/bun-sql'; import { SQL } from 'bun'; const client = new SQL(process.env.DATABASE_URL!); const db = drizzle({ client }); ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-bun-sqlite import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; # Drizzle \<\> Bun SQLite - Database [connection basics](/docs/connect-overview) with Drizzle - Bun - [website](https://bun.sh/docs) - Bun SQLite driver - [docs](https://bun.sh/docs/api/sqlite) According to the **[official website](https://bun.sh/)**, Bun is a fast all-in-one JavaScript runtime. Drizzle ORM natively supports **[`bun:sqlite`](https://bun.sh/docs/api/sqlite)** module and it's crazy fast 🚀 We embraces SQL dialects and dialect specific drivers and syntax and unlike any other ORM, for synchronous drivers like `bun:sqlite` we have both **async** and **sync** APIs and we mirror most popular SQLite-like `all`, `get`, `values` and `run` query methods syntax. #### Step 1 - Install packages drizzle-orm -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy import { drizzle } from 'drizzle-orm/bun-sqlite'; const db = drizzle(); const result = await db.select().from(...); ``` If you need to provide your existing driver: ```typescript copy import { drizzle } from 'drizzle-orm/bun-sqlite'; import { Database } from 'bun:sqlite'; const sqlite = new Database('sqlite.db'); const db = drizzle({ client: sqlite }); const result = await db.select().from(...); ``` If you want to use **sync** APIs: ```typescript copy import { drizzle } from 'drizzle-orm/bun-sqlite'; import { Database } from 'bun:sqlite'; const sqlite = new Database('sqlite.db'); const db = drizzle({ client: sqlite }); const result = db.select().from(users).all(); const result = db.select().from(users).get(); const result = db.select().from(users).values(); const result = db.select().from(users).run(); ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-cloudflare-d1 import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; # Drizzle \<\> Cloudflare D1 - Database [connection basics](/docs/connect-overview) with Drizzle - D1 Database - [website](https://developers.cloudflare.com/d1/) - D1 driver - [website](https://developers.cloudflare.com/d1/build-with-d1/d1-client-api/) According to the **[official website](https://developers.cloudflare.com/d1/)**, D1 is Cloudflare's first queryable relational database. Drizzle ORM fully supports the Cloudflare D1 database and Cloudflare Workers environment. We embrace SQL dialects and dialect specific drivers and syntax and mirror most popular SQLite-like `all`, `get`, `values` and `run` query methods syntax. To setup project for your Cloudflare D1 please refer to **[official docs.](https://developers.cloudflare.com/d1/)** #### Step 1 - Install packages drizzle-orm -D drizzle-kit #### Step 2 - Initialize the driver and make a query You would need to have either a `wrangler.json` or a `wrangler.toml` file for D1 database and will look something like this: ```json { "name": "YOUR_PROJECT_NAME", "main": "src/index.ts", "compatibility_date": "2024-09-26", "compatibility_flags": [ "nodejs_compat" ], "d1_databases": [ { "binding": "BINDING_NAME", "database_name": "YOUR_DB_NAME", "database_id": "YOUR_DB_ID", "migrations_dir": "drizzle/migrations" } ] } ``` ```toml name = "YOUR_PROJECT_NAME" main = "src/index.ts" compatibility_date = "2022-11-07" node_compat = true [[ d1_databases ]] binding = "BINDING_NAME" database_name = "YOUR_DB_NAME" database_id = "YOUR_DB_ID" migrations_dir = "drizzle/migrations" ``` Make your first D1 query: ```typescript copy import { drizzle } from 'drizzle-orm/d1'; export interface Env { : D1Database; } export default { async fetch(request: Request, env: Env) { const db = drizzle(env.); const result = await db.select().from(users).all() return Response.json(result); }, }; ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-cloudflare-do import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; # Drizzle \<\> Cloudflare Durable Objects SQLite - Database [connection basics](/docs/connect-overview) with Drizzle - **Cloudflare SQLite Durable Objects** - SQLite database embedded within a Durable Object - [read here](https://developers.cloudflare.com/durable-objects/best-practices/access-durable-objects-storage/#sqlite-storage-backend) Drizzle ORM fully supports the Cloudflare Durable Objects database and Cloudflare Workers environment. We embrace SQL dialects and dialect specific drivers and syntax and mirror most popular SQLite-like `all`, `get`, `values` and `run` query methods syntax. To setup project for your Cloudflare Durable Objects please refer to **[official docs.](https://developers.cloudflare.com/durable-objects)** #### Step 1 - Install packages drizzle-orm -D drizzle-kit #### Step 2 - Initialize the driver and make a query You would need to have a `wrangler.toml` file for Durable Objects database and will look something like this: ```toml {16-18,21-24} #:schema node_modules/wrangler/config-schema.json name = "sqlite-durable-objects" main = "src/index.ts" compatibility_date = "2024-11-12" compatibility_flags = [ "nodejs_compat" ] # Bind a Durable Object. Durable objects are a scale-to-zero compute primitive based on the actor model. # Durable Objects can live for as long as needed. Use these when you need a long-running "server", such as in realtime apps. # Docs: https://developers.cloudflare.com/workers/wrangler/configuration/#durable-objects [[durable_objects.bindings]] name = "MY_DURABLE_OBJECT" class_name = "MyDurableObject" # Durable Object migrations. # Docs: https://developers.cloudflare.com/workers/wrangler/configuration/#migrations [[migrations]] tag = "v1" new_sqlite_classes = ["MyDurableObject"] # We need rules so we can import migrations in the next steps [[rules]] type = "Text" globs = ["**/*.sql"] fallthrough = true ``` Make your first Durable Objects SQLite query: ```typescript copy /// import { drizzle, DrizzleSqliteDODatabase } from 'drizzle-orm/durable-sqlite'; import { DurableObject } from 'cloudflare:workers' import { migrate } from 'drizzle-orm/durable-sqlite/migrator'; import migrations from '../drizzle/migrations'; import { usersTable } from './db/schema'; export class MyDurableObject extends DurableObject { storage: DurableObjectStorage; db: DrizzleSqliteDODatabase; constructor(ctx: DurableObjectState, env: Env) { super(ctx, env); this.storage = ctx.storage; this.db = drizzle(this.storage, { logger: false }); // Make sure all migrations complete before accepting queries. // Otherwise you will need to run `this.migrate()` in any function // that accesses the Drizzle database `this.db`. ctx.blockConcurrencyWhile(async () => { await this._migrate(); }); } async insertAndList(user: typeof usersTable.$inferInsert) { await this.insert(user); return this.select(); } async insert(user: typeof usersTable.$inferInsert) { await this.db.insert(usersTable).values(user); } async select() { return this.db.select().from(usersTable); } async _migrate() { migrate(this.db, migrations); } } export default { /** * This is the standard fetch handler for a Cloudflare Worker * * @param request - The request submitted to the Worker from the client * @param env - The interface to reference bindings declared in wrangler.toml * @param ctx - The execution context of the Worker * @returns The response to be sent back to the client */ async fetch(request: Request, env: Env): Promise { const id: DurableObjectId = env.MY_DURABLE_OBJECT.idFromName('durable-object'); const stub = env.MY_DURABLE_OBJECT.get(id); // Option A - Maximum performance. // Prefer to bundle all the database interaction within a single Durable Object call // for maximum performance, since database access is fast within a DO. const usersAll = await stub.insertAndList({ name: 'John', age: 30, email: 'john@example.com', }); console.log('New user created. Getting all users from the database: ', users); // Option B - Slow but maybe useful sometimes for debugging. // You can also directly call individual Drizzle queries if they are exposed // but keep in mind every query is a round-trip to the Durable Object instance. await stub.insert({ name: 'John', age: 30, email: 'john@example.com', }); console.log('New user created!'); const users = await stub.select(); console.log('Getting all users from the database: ', users); return Response.json(users); } } ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-drizzle-proxy import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; # Drizzle HTTP proxy - Database [connection basics](/docs/connect-overview) with Drizzle How an HTTP Proxy works and why you might need it Drizzle Proxy is used when you need to implement your own driver communication with the database. It can be used in several cases, such as adding custom logic at the query stage with existing drivers. The most common use is with an HTTP driver, which sends queries to your server with the database, executes the query on your database, and responds with raw data that Drizzle ORM can then map to results ``` ┌───────────────────────────┐ ┌─────────────────────────────┐ │ Drizzle ORM │ │ HTTP Server with Database │ └─┬─────────────────────────┘ └─────────────────────────┬───┘ │ ^ │ │-- 1. Build query 2. Send built query --│ │ │ │ │ │ ┌───────────────────────────┐ │ │ └─────────────>│ │─────┘ │ │ HTTP Proxy Driver │ │ ┌──────────────│ │<─────────────┬───────────┘ │ └───────────────────────────┘ │ │ 3. Execute a query + send raw results back │-- 4. Map data and return │ v ``` Drizzle ORM also supports simply using asynchronous callback function for executing SQL. - `sql` is a query string with placeholders. - `params` is an array of parameters. - One of the following values will set for `method` depending on the SQL statement - `run`, `all`, `values` or `get`. Drizzle always waits for `{rows: string[][]}` or `{rows: string[]}` for the return value. - When the `method` is `get`, you should return a value as `{rows: string[]}`. - Otherwise, you should return `{rows: string[][]}`.
```typescript copy // Example of driver implementation import { drizzle } from 'drizzle-orm/pg-proxy'; const db = drizzle(async (sql, params, method) => { try { const rows = await axios.post('http://localhost:3000/query', { sql, params, method }); return { rows: rows.data }; } catch (e: any) { console.error('Error from pg proxy server: ', e.response.data) return { rows: [] }; } }); ``` ```ts // Example of server implementation import { Client } from 'pg'; import express from 'express'; const app = express(); app.use(express.json()); const port = 3000; const client = new Client('postgres://postgres:postgres@localhost:5432/postgres'); app.post('/query', async (req, res) => { const { sql, params, method } = req.body; // prevent multiple queries const sqlBody = sql.replace(/;/g, ''); try { const result = await client.query({ text: sqlBody, values: params, rowMode: method === 'all' ? 'array': undefined, }); res.send(result.rows); } catch (e: any) { res.status(500).json({ error: e }); } res.status(500).json({ error: 'Unknown method value' }); }); app.listen(port, () => { console.log(`Example app listening on port ${port}`); }); ```
```typescript copy // Example of driver implementation import { drizzle } from 'drizzle-orm/mysql-proxy'; const db = drizzle(async (sql, params, method) => { try { const rows = await axios.post('http://localhost:3000/query', { sql, params, method }); return { rows: rows.data }; } catch (e: any) { console.error('Error from mysql proxy server: ', e.response.data) return { rows: [] }; } }); ``` ```ts // Example of server implementation import * as mysql from 'mysql2/promise'; import express from 'express'; const app = express(); app.use(express.json()); const port = 3000; const main = async () => { const connection = await mysql.createConnection('mysql://root:mysql@127.0.0.1:5432/drizzle'); app.post('/query', async (req, res) => { const { sql, params, method } = req.body; // prevent multiple queries const sqlBody = sql.replace(/;/g, ''); try { const result = await connection.query({ sql: sqlBody, values: params, rowsAsArray: method === 'all', typeCast: function(field: any, next: any) { if (field.type === 'TIMESTAMP' || field.type === 'DATETIME' || field.type === 'DATE') { return field.string(); } return next(); }, }); } catch (e: any) { res.status(500).json({ error: e }); } if (method === 'all') { res.send(result[0]); } else if (method === 'execute') { res.send(result); } res.status(500).json({ error: 'Unknown method value' }); }); app.listen(port, () => { console.log(`Example app listening on port ${port}`); }); } main(); ```
```typescript copy import { drizzle } from 'drizzle-orm/sqlite-proxy'; const db = drizzle(async (sql, params, method) => { try { const rows = await axios.post('http://localhost:3000/query', { sql, params, method }); return { rows: rows.data }; } catch (e: any) { console.error('Error from sqlite proxy server: ', e.response.data) return { rows: [] }; } }); ``` **Batch support** Sqlite Proxy supports batch requests, the same as it's done for all other drivers. Check full [docs](/docs/batch-api) You will need to specify a specific callback for batch queries and handle requests to proxy server: ```ts import { drizzle } from 'drizzle-orm/sqlite-proxy'; type ResponseType = { rows: any[][] | any[] }[]; const db = drizzle(async (sql, params, method) => { // single queries logic. Same as in code above }, async (queries: { sql: string, params: any[], method: 'all' | 'run' | 'get' | 'values'}[]) => { try { const result: ResponseType = await axios.post('http://localhost:3000/batch', { queries }); return result; } catch (e: any) { console.error('Error from sqlite proxy server:', e); throw e; } }); ``` And then you can use `db.batch([])` method, that will proxy all queries Response from the batch should be an array of raw values (an array within an array), in the same order as they were sent to the proxy server Unless you plan on writing every SQL query by hand, a table declaration is helpful: ```typescript copy import { sql } from "drizzle-orm"; import { text, integer, sqliteTable } from "drizzle-orm/sqlite-core"; const users = sqliteTable('users', { id: text('id'), textModifiers: text('text_modifiers').notNull().default(sql`CURRENT_TIMESTAMP`), intModifiers: integer('int_modifiers', { mode: 'boolean' }).notNull().default(false), }); ``` For more details about column types, see the **[SQLite column types in Drizzle.](/docs/column-types/sqlite)**
Source: https://orm.drizzle.team/docs/connect-expo-sqlite import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; # Drizzle \<\> Expo SQLite According to the **[official website](https://expo.dev/)**, Expo is an ecosystem of tools to develop, build and ship applications on React Native. It's powered by Hermes JavaScript runtime and Metro bundler, Drizzle Expo driver is built to natively support both. Drizzle ORM has the best in class toolkit for Expo SQLite: - Native ORM driver for Expo SQLite ✅ - [Drizzle Kit](/docs/kit-overview) support for migration generation and bundling in application ✅ - [Drizzle Studio](https://github.com/drizzle-team/drizzle-studio-expo) dev tools plugin to browse on device database ✅ - Live Queries ✅ drizzle-orm expo-sqlite@next -D drizzle-kit ```ts import { drizzle } from "drizzle-orm/expo-sqlite"; import { openDatabaseSync } from "expo-sqlite/next"; const expo = openDatabaseSync("db.db"); const db = drizzle(expo); await db.select().from(users); ``` #### Live Queries With `useLiveQuery` hook you can make any Drizzle query reactive: ```ts import { useLiveQuery, drizzle } from 'drizzle-orm/expo-sqlite'; import { openDatabaseSync } from 'expo-sqlite/next'; import { Text } from 'react-native'; import * as schema from './schema'; const expo = openDatabaseSync('db.db', { enableChangeListener: true }); // <-- enable change listeners const db = drizzle(expo); const App = () => { // Re-renders automatically when data changes const { data } = useLiveQuery(db.select().from(schema.users)); return {JSON.stringify(data)}; }; export default App; ``` #### Expo SQLite migrations with Drizzle Kit You can use Drizzle Kit for SQL migration generation. Please make sure to check how [Drizzle migrations](/docs/kit-overview) work before proceeding. Expo / React Native requires you to have SQL migrations bundled into the app and we've got you covered. #### Install babel plugin It's necessary to bundle SQL migration files as string directly to your bundle. ```shell npm install babel-plugin-inline-import ``` #### Update config files. You will need to update `babel.config.js`, `metro.config.js` and `drizzle.config.ts` files ```js filename='babel.config.js' module.exports = function(api) { api.cache(true); return { presets: ['babel-preset-expo'], plugins: [["inline-import", { "extensions": [".sql"] }]] // <-- add this }; }; ``` ```js filename="metro.config.js" const { getDefaultConfig } = require('expo/metro-config'); /** @type {import('expo/metro-config').MetroConfig} */ const config = getDefaultConfig(__dirname); config.resolver.sourceExts.push('sql'); // <--- add this module.exports = config; ``` Make sure to have `dialect: 'sqlite'` and `driver: 'expo'` in Drizzle Kit config ```ts filename="drizzle.config.ts" import type { Config } from 'drizzle-kit'; export default { schema: './db/schema.ts', out: './drizzle', dialect: 'sqlite', driver: 'expo', // <--- very important } satisfies Config; ``` #### Generate migrations After creating SQL schema file and drizzle.config.ts file, you can generate migrations ```bash npx drizzle-kit generate ``` #### Add migrations to your app Now you need to import `migrations.js` file into your Expo/React Native app from `./drizzle` folder. You can run migrations on application startup using our custom `useMigrations` migrations hook on in `useEffect` hook manually as you want. ```ts filename="App.tsx" import { drizzle } from "drizzle-orm/expo-sqlite"; import { openDatabaseSync } from "expo-sqlite/next"; import { useMigrations } from 'drizzle-orm/expo-sqlite/migrator'; import migrations from './drizzle/migrations'; const expoDb = openDatabaseSync("db.db"); const db = drizzle(expoDb); export default function App() { const { success, error } = useMigrations(db, migrations); if (error) { return ( Migration error: {error.message} ); } if (!success) { return ( Migration is in progress... ); } return ...your application component; } ``` Source: https://orm.drizzle.team/docs/connect-neon import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> Neon Postgres - Database [connection basics](/docs/connect-overview) with Drizzle - Neon serverless database - [website](https://neon.tech) - Neon serverless driver - [docs](https://neon.tech/docs/serverless/serverless-driver) & [GitHub](https://github.com/neondatabase/serverless) - Drizzle PostgreSQL drivers - [docs](/docs/get-started-postgresql) Drizzle has native support for Neon connections with the `neon-http` and `neon-websockets` drivers. These use the **neon-serverless** driver under the hood. With the `neon-http` and `neon-websockets` drivers, you can access a Neon database from serverless environments over HTTP or WebSockets instead of TCP. Querying over HTTP is faster for single, non-interactive transactions. If you need session or interactive transaction support, or a fully compatible drop-in replacement for the `pg` driver, you can use the WebSocket-based `neon-serverless` driver. You can connect to a Neon database directly using [Postgres](/docs/get-started/postgresql-new) For an example of using Drizzle ORM with the Neon Serverless driver in a Cloudflare Worker, **[see here.](http://driz.link/neon-cf-ex)** To use Neon from a serverful environment, you can use the PostgresJS driver, as described in Neon's **[official Node.js docs](https://neon.tech/docs/guides/node)** — see **[docs](#postgresjs)**. #### Step 1 - Install packages drizzle-orm @neondatabase/serverless -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript import { drizzle } from 'drizzle-orm/neon-http'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ```
```typescript import { drizzle } from 'drizzle-orm/neon-serverless'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ``` ```typescript // For Node.js - make sure to install the 'ws' and 'bufferutil' packages import { drizzle } from 'drizzle-orm/neon-serverless'; import ws from 'ws'; const db = drizzle({ connection: process.env.DATABASE_URL, ws: ws, }); const result = await db.execute('select 1'); ``` Additional configuration is required to use WebSockets in environments where the `WebSocket` global is not defined, such as Node.js. Add the `ws` and `bufferutil` packages to your project's dependencies, and set `ws` in the Drizzle config.
```typescript // Make sure to install the 'pg' package import { drizzle } from 'drizzle-orm/node-postgres'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ``` ```typescript // Make sure to install the 'postgres' package import { drizzle } from 'drizzle-orm/postgres-js'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ```
If you need to provide your existing drivers: ```typescript import { neon } from '@neondatabase/serverless'; import { drizzle } from 'drizzle-orm/neon-http'; const sql = neon(process.env.DATABASE_URL!); const db = drizzle({ client: sql }); const result = await db.execute('select 1'); ```
```typescript import { Pool } from '@neondatabase/serverless'; import { drizzle } from 'drizzle-orm/neon-serverless'; const pool = new Pool({ connectionString: process.env.DATABASE_URL }); const db = drizzle({ client: pool }) const result = await db.execute('select 1'); ``` ```typescript // For Node.js - make sure to install the 'ws' and 'bufferutil' packages import { Pool, neonConfig } from '@neondatabase/serverless'; import { drizzle } from 'drizzle-orm/neon-serverless'; neonConfig.webSocketConstructor = ws; const pool = new Pool({ connectionString: process.env.DATABASE_URL }); const db = drizzle({ client: pool }) const result = await db.execute('select 1'); ``` Additional configuration is required to use WebSockets in environments where the `WebSocket` global is not defined, such as Node.js. Add the `ws` and `bufferutil` packages to your project's dependencies, and set `ws` in the Drizzle config.
```typescript // Make sure to install the 'pg' package import { pgTable, serial, text, varchar } from "drizzle-orm/pg-core"; import { drizzle } from "drizzle-orm/node-postgres"; import { Pool } from "pg"; const pool = new Pool({ connectionString: process.env.DATABASE_URL, }); const db = drizzle({ client: pool }); const result = await db.execute('select 1'); ``` ```typescript // Make sure to install the 'postgres' package import { drizzle } from 'drizzle-orm/postgres-js'; import postgres from 'postgres'; const queryClient = postgres(process.env.DATABASE_URL); const db = drizzle({ client: queryClient }); const result = await db.execute('select 1'); ```
#### What's next? Source: https://orm.drizzle.team/docs/connect-nile import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> Nile - Database [connection basics](/docs/connect-overview) with Drizzle - Nile Database - [website](https://thenile.dev) - Drizzle PostgreSQL drivers - [docs](/docs/get-started-postgresql) According to the **[official website](https://thenile.dev)**, Nile is PostgreSQL re-engineered for multi-tenant apps. Checkout official **[Nile + Drizzle Quickstart](https://www.thenile.dev/docs/getting-started/languages/drizzle)** and **[Migration](https://www.thenile.dev/docs/getting-started/schema_migrations/drizzle)** docs. You can use Nile with any of Drizzle's Postgres drivers, we'll be showing the use of `node-postgres` below. #### Step 1 - Install packages drizzle-orm postgres -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy filename="index.ts" // Make sure to install the 'pg' package import { drizzle } from 'drizzle-orm/node-postgres' const db = drizzle(process.env.NILEDB_URL); const response = await db.select().from(...); ``` If you need to provide your existing driver: ```typescript copy filename="index.ts" // Make sure to install the 'pg' package import { pgTable, serial, text, varchar } from "drizzle-orm/pg-core"; import { drizzle } from "drizzle-orm/node-postgres"; import { Pool } from "pg"; const pool = new Pool({ connectionString: process.env.DATABASE_URL, }); const db = drizzle({ client: pool }); const response = await db.select().from(...); ``` #### Connecting to a virtual tenant database Nile provides virtual tenant databases, when you set the tenant context, Nile will direct your queries to the virtual database for this particular tenant and all queries will apply to that tenant (i.e. `select * from table` will result records only for this tenant). In order to set the tenant context, we wrap each query in a transaction that sets the appropriate tenant context before running the transaction. The tenant ID can simply be passed into the wrapper as an argument: ```typescript copy filename="index.ts" import { drizzle } from 'drizzle-orm/node-postgres'; import { todosTable, tenants } from "./db/schema"; import { sql } from 'drizzle-orm'; import 'dotenv/config'; const db = drizzle(process.env.NILEDB_URL); function tenantDB(tenantId: string, cb: (tx: any) => T | Promise): Promise { return db.transaction(async (tx) => { if (tenantId) { await tx.execute(sql`set local nile.tenant_id = '${sql.raw(tenantId)}'`); } return cb(tx); }) as Promise; } // In a webapp, you'll likely get it from the request path parameters or headers const tenantId = '01943e56-16df-754f-a7b6-6234c368b400' const response = await tenantDB(tenantId, async (tx) => { // No need for a "where" clause here return await tx.select().from(todosTable); }); console.log(response); ``` If you are using a web framwork that supports it, you can set up [AsyncLocalStorage](https://nodejs.org/api/async_context.html) and use middleware to populate it with the tenant ID. In this case, your Drizzle client setup will be: ```typescript copy filename="db/index.ts import { drizzle } from 'drizzle-orm/node-postgres'; import dotenv from "dotenv/config"; import { sql } from "drizzle-orm"; import { AsyncLocalStorage } from "async_hooks"; export const db = drizzle(process.env.NILEDB_URL); export const tenantContext = new AsyncLocalStorage(); export function tenantDB(cb: (tx: any) => T | Promise): Promise { return db.transaction(async (tx) => { const tenantId = tenantContext.getStore(); console.log("executing query with tenant: " + tenantId); // if there's a tenant ID, set it in the transaction context if (tenantId) { await tx.execute(sql`set local nile.tenant_id = '${sql.raw(tenantId)}'`); } return cb(tx); }) as Promise; } ``` And then, configure a middleware to populate the the AsyncLocalStorage and use `tenantDB` method when handling requests: ```typescript copy filename="app.ts" // Middleware to set tenant context app.use("/api/tenants/:tenantId/*", async (c, next) => { const tenantId = c.req.param("tenantId"); console.log("setting context to tenant: " + tenantId); return tenantContext.run(tenantId, () => next()); }); // Route handler app.get("/api/tenants/:tenantId/todos", async (c) => { const todos = await tenantDB(c, async (tx) => { return await tx .select({ id: todoSchema.id, tenant_id: todoSchema.tenantId, title: todoSchema.title, estimate: todoSchema.estimate, }) .from(todoSchema); }); return c.json(todos); }); ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-op-sqlite import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; # Drizzle \<\> OP SQLite According to the **[official github page](https://github.com/OP-Engineering/op-sqlite)**, OP-SQLite embeds the latest version of SQLite and provides a low-level API to execute SQL queries. drizzle-orm @op-engineering/op-sqlite -D drizzle-kit ```ts import { drizzle } from "drizzle-orm/op-sqlite"; import { open } from '@op-engineering/op-sqlite'; const opsqlite = open({ name: 'myDB', }); const db = drizzle(opsqlite); await db.select().from(users); ``` You can use Drizzle Kit for SQL migration generation. Please make sure to check how [Drizzle Kit migrations](/docs/kit-overview) work before proceeding. OP SQLite requires you to have SQL migrations bundled into the app and we've got you covered. #### Install babel plugin It's necessary to bundle SQL migration files as string directly to your bundle. ```shell npm install babel-plugin-inline-import ``` #### Update config files. You will need to update `babel.config.js`, `metro.config.js` and `drizzle.config.ts` files ```js filename='babel.config.js' module.exports = { presets: ['module:@react-native/babel-preset'], plugins: [ [ 'inline-import', { extensions: ['.sql'], }, ], ], }; ``` ```js filename="metro.config.js" const { getDefaultConfig } = require('@react-native/metro-config'); const config = getDefaultConfig(__dirname); config.resolver.sourceExts.push('sql'); module.exports = config; ``` Make sure to have `dialect: 'sqlite'` and `driver: 'expo'` in Drizzle Kit config ```ts filename="drizzle.config.ts" import type { Config } from 'drizzle-kit'; export default { schema: './db/schema.ts', out: './drizzle', dialect: 'sqlite', driver: 'expo', // <--- very important } satisfies Config; ``` #### Generate migrations After creating SQL schema file and drizzle.config.ts file, you can generate migrations ```bash npx drizzle-kit generate ``` #### Add migrations to your app Now you need to import `migrations.js` file into your Expo/React Native app from `./drizzle` folder. You can run migrations on application startup using our custom `useMigrations` migrations hook on in `useEffect` hook manually as you want. ```ts filename="App.tsx" import { drizzle } from "drizzle-orm/op-sqlite"; import { open } from '@op-engineering/op-sqlite'; import { useMigrations } from 'drizzle-orm/op-sqlite/migrator'; import migrations from './drizzle/migrations'; const opsqliteDb = open({ name: 'myDB', }); const db = drizzle(opsqliteDb); export default function App() { const { success, error } = useMigrations(db, migrations); if (error) { return ( Migration error: {error.message} ); } if (!success) { return ( Migration is in progress... ); } return ...your application component; } ``` Source: https://orm.drizzle.team/docs/connect-overview import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Section from "@mdx/Section.astro"; import LinksList from "@mdx/LinksList.astro" import Flex from "@mdx/Flex.astro" # Database connection with Drizzle Drizzle ORM runs SQL queries on your database via **database drivers**. ```ts import { drizzle } from "drizzle-orm/node-postgres" import { users } from "./schema" const db = drizzle(process.env.DATABASE_URL); const usersCount = await db.$count(users); ``` ``` ┌──────────────────────┐ │ db.$count(users) │ <--- drizzle query └──────────────────────┘ │ ʌ select count(*) from users -│ │ │ │- [{ count: 0 }] v │ ┌─────────────────────┐ │ node-postgres │ <--- database driver └─────────────────────┘ │ ʌ 01101000 01100101 01111001 -│ │ │ │- 01110011 01110101 01110000 v │ ┌────────────────────┐ │ Database │ └────────────────────┘ ``` ```ts import { pgTable, integer, text } from "drizzle-orm"; export const users = pgTable("users", { id: integer("id").generateAlwaysAsIdentity(), name: text("name"), }) ``` Under the hood Drizzle will create a **node-postgres** driver instance which you can access via `db.$client` if necessary
```ts import { drizzle } from "drizzle-orm/node-postgres" const db = drizzle(process.env.DATABASE_URL); const pool = db.$client; ``` ```ts // above is equivalent to import { drizzle } from "drizzle-orm/node-postgres"; import { Pool } from "pg"; const pool = new Pool({ connectionString: process.env.DATABASE_URL, }); const db = drizzle({ client: pool }); ```
Drizzle is by design natively compatible with every **edge** or **serverless** runtime, whenever you'd need access to a serverless database - we've got you covered ```ts import { drizzle } from "drizzle-orm/neon-http"; const db = drizzle(process.env.DATABASE_URL); ``` ```ts import { drizzle } from "drizzle-orm/neon-serverless"; const db = drizzle(process.env.DATABASE_URL); ``` ```ts import { drizzle } from "drizzle-orm/vercel-postgres"; const db = drizzle(); ``` ```ts import { drizzle } from "drizzle-orm/planetscale"; const db = drizzle(process.env.DATABASE_URL); ``` ```ts import { drizzle } from "drizzle-orm/d1"; const db = drizzle({ connection: env.DB }); ``` And yes, we do support runtime specific drivers like [Bun SQLite](/docs/connect-bun-sqlite) or [Expo SQLite](/docs/connect-expo-sqlite):
```ts import { drizzle } from "drizzle-orm/bun-sqlite" const db = drizzle(); // <--- will create an in-memory db const db = drizzle("./sqlite.db"); ``` ```ts import { drizzle } from "drizzle-orm/expo-sqlite"; import { openDatabaseSync } from "expo-sqlite/next"; const expo = openDatabaseSync("db.db"); const db = drizzle(expo); ```
#### Database connection URL Just in case if you're not familiar with database connection URL concept ``` postgresql://alex:AbC123dEf@ep-cool-darkness-123456.us-east-2.aws.neon.tech/dbname └──┘ └───────┘ └─────────────────────────────────────────────┘ └────┘ ʌ ʌ ʌ ʌ role -│ │ │- hostname │- database │ │- password ``` #### Next steps Feel free to check out per-driver documentations {/* TODO: @AndriiSherman ["AWS Data API", "/docs/get-started/aws-data-api"], */} Source: https://orm.drizzle.team/docs/connect-pglite import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> PGlite - Database [connection basics](/docs/connect-overview) with Drizzle - ElectricSQL - [website](https://electric-sql.com/) - PgLite driver - [docs](https://pglite.dev/) & [GitHub](https://github.com/electric-sql/pglite) According to the **[official repo](https://github.com/electric-sql/pglite)**, PGlite is a WASM Postgres build packaged into a TypeScript client library that enables you to run Postgres in the browser, Node.js and Bun, with no need to install any other dependencies. It is only 2.6mb gzipped. It can be used as an ephemeral in-memory database, or with persistence either to the file system (Node/Bun) or indexedDB (Browser). Unlike previous "Postgres in the browser" projects, PGlite does not use a Linux virtual machine - it is simply Postgres in WASM. #### Step 1 - Install packages drizzle-orm @electric-sql/pglite -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy" import { drizzle } from 'drizzle-orm/pglite'; const db = drizzle(); await db.select().from(...); ``` ```typescript copy" import { drizzle } from 'drizzle-orm/pglite'; const db = drizzle('path-to-dir'); await db.select().from(...); ``` ```typescript copy" import { drizzle } from 'drizzle-orm/pglite'; // connection is a native PGLite configuration const db = drizzle({ connection: { dataDir: 'path-to-dir' }}); await db.select().from(...); ``` If you need to provide your existing driver: ```typescript copy" import { PGlite } from '@electric-sql/pglite'; import { drizzle } from 'drizzle-orm/pglite'; // In-memory Postgres const client = new PGlite(); const db = drizzle({ client }); await db.select().from(users); ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-planetscale import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Tabs from '@mdx/Tabs.astro'; import Tab from '@mdx/Tab.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; # Drizzle \<\> PlanetScale - Database [connection basics](/docs/connect-overview) with Drizzle - PlanetScale database - [website](https://planetscale.com/docs) - PlanetScale http driver - [GitHub](https://github.com/planetscale/database-js) - Drizzle MySQL drivers - [docs](/docs/get-started-mysql) According to the **[official website](https://planetscale.com/)**, PlanetScale is the world's most advanced serverless MySQL platform. With Drizzle ORM you can access PlanetScale over http through their official **[`database-js`](https://github.com/planetscale/database-js)** driver from serverless and serverfull environments with our `drizzle-orm/planetscale-serverless` package. You can also access PlanetScale through TCP with `mysql2` driver — **[see here.](/docs/get-started-mysql)** #### Step 1 - Install packages drizzle-orm @planetscale/database -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy" import { drizzle } from "drizzle-orm/planetscale-serverless"; const db = drizzle({ connection: { host: process.env["DATABASE_HOST"], username: process.env["DATABASE_USERNAME"], password: process.env["DATABASE_PASSWORD"], }}); const response = await db.select().from(...) ``` If you need to provide your existing driver ```typescript copy" import { drizzle } from "drizzle-orm/planetscale-serverless"; import { Client } from "@planetscale/database"; const client = new Client({ host: process.env["DATABASE_HOST"], username: process.env["DATABASE_USERNAME"], password: process.env["DATABASE_PASSWORD"], }); const db = drizzle({ client }); ``` Make sure to checkout the PlanetScale official **[MySQL courses](https://planetscale.com/courses/mysql-for-developers/introduction/course-introduction)**, we think they're outstanding 🙌 #### What's next? Source: https://orm.drizzle.team/docs/connect-react-native-sqlite import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; # Drizzle \<\> React Native SQLite Please use [`Expo SQLite`](#expo-sqlite) to run Drizzle ORM with React Native apps. The only [popular library](https://github.com/andpor/react-native-sqlite-storage) we've found does not support new Hermes JavaScript runtime, which is a standard out of the box runtime for React Native and Expo now. Source: https://orm.drizzle.team/docs/connect-supabase import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> Supabase - Database [connection basics](/docs/connect-overview) with Drizzle - Drizzle PostgreSQL drivers - [docs](/docs/get-started-postgresql) According to the **[official website](https://supabase.com/docs)**, Supabase is an open source Firebase alternative for building secure and performant Postgres backends with minimal configuration. Checkout official **[Supabase + Drizzle](https://supabase.com/docs/guides/database/connecting-to-postgres#connecting-with-drizzle)** docs. #### Step 1 - Install packages drizzle-orm postgres -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy filename="index.ts" import { drizzle } from 'drizzle-orm/postgres-js' const db = drizzle(process.env.DATABASE_URL); const allUsers = await db.select().from(...); ``` If you need to provide your existing driver: ```typescript copy filename="index.ts" import { drizzle } from 'drizzle-orm/postgres-js' import postgres from 'postgres' const client = postgres(process.env.DATABASE_URL) const db = drizzle({ client }); const allUsers = await db.select().from(...); ``` If you decide to use connection pooling via Supabase (described [here](https://supabase.com/docs/guides/database/connecting-to-postgres#connection-pooler)), and have "Transaction" pool mode enabled, then ensure to turn off prepare, as prepared statements are not supported. ```typescript copy filename="index.ts" import { drizzle } from 'drizzle-orm/postgres-js' import postgres from 'postgres' // Disable prefetch as it is not supported for "Transaction" pool mode const client = postgres(process.env.DATABASE_URL, { prepare: false }) const db = drizzle({ client }); const allUsers = await db.select().from(...); ``` Connect to your database using the Connection Pooler for **serverless environments**, and the Direct Connection for **long-running servers**. #### What's next? Source: https://orm.drizzle.team/docs/connect-tidb import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Tabs from '@mdx/Tabs.astro'; import Tab from '@mdx/Tab.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; # Drizzle \<\> TiDB Serverless - Database [connection basics](/docs/connect-overview) with Drizzle - TiDB database - [website](https://docs.pingcap.com/) - TiDB HTTP Driver - [website](https://docs.pingcap.com/tidbcloud/serverless-driver) - Drizzle MySQL drivers - [docs](/docs/get-started-mysql) According to the **[official website](https://www.pingcap.com/tidb-serverless/)**, TiDB Serverless is a fully-managed, autonomous DBaaS with split-second cluster provisioning and consumption-based pricing. TiDB Serverless is compatible with MySQL, so you can use [MySQL connection guide](/docs/get-started-mysql) to connect to it. TiDB Serverless provides an [HTTP driver](https://docs.pingcap.com/tidbcloud/serverless-driver) for edge environments. It is natively supported by Drizzle ORM via `drizzle-orm/tidb-serverless` package. #### Step 1 - Install packages drizzle-orm @tidbcloud/serverless -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy filename="index.ts" import { drizzle } from 'drizzle-orm/tidb-serverless'; const db = drizzle({ connection: { url: process.env.TIDB_URL }}); const response = await db.select().from(...) ``` If you need to provide your existing driver: ```typescript copy" import { connect } from '@tidbcloud/serverless'; import { drizzle } from 'drizzle-orm/tidb-serverless'; const client = connect({ url: process.env.TIDB_URL }); const db = drizzle({ client }); ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-turso import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import LibsqlTable from "@mdx/LibsqlTable.mdx"; import LibsqlTabs from "@mdx/LibsqlTabs.mdx"; # Drizzle \<\> Turso - Database [connection basics](/docs/connect-overview) with Drizzle - Turso Database - [website](https://docs.turso.tech/introduction) - LibSQL driver - [website](https://docs.turso.tech/sdk/ts/reference) & [GitHub](https://github.com/tursodatabase/libsql-client-ts) According to the **[official website](https://turso.tech/drizzle)**, Turso is a **[libSQL](https://github.com/libsql/libsql)** powered edge SQLite database as a service. Drizzle ORM natively supports libSQL driver, we embrace SQL dialects and dialect specific drivers and syntax and mirror most popular SQLite-like `all`, `get`, `values` and `run` query methods syntax. #### Step 1 - Install packages drizzle-orm @libsql/client -D drizzle-kit #### Step 2 - Initialize the driver Drizzle has native support for all `@libsql/client` driver variations:
If you need to provide your existing driver: ```typescript copy import { drizzle } from 'drizzle-orm/libsql'; import { createClient } from '@libsql/client'; const client = createClient({ url: process.env.DATABASE_URL, authToken: process.env.DATABASE_AUTH_TOKEN }); const db = drizzle({ client }); const result = await db.select().from(users).all() ``` ```typescript copy import { drizzle } from 'drizzle-orm/libsql/web'; import { createClient } from '@libsql/client/web'; const client = createClient({ url: process.env.DATABASE_URL, authToken: process.env.DATABASE_AUTH_TOKEN }); const db = drizzle({ client }); const result = await db.select().from(users).all() ``` #### Step 3 - make a query ```ts import { drizzle } from 'drizzle-orm/libsql'; import * as s from 'drizzle-orm/sqlite-core'; const db = drizzle({ connection: { url: process.env.DATABASE_URL, authToken: process.env.DATABASE_AUTH_TOKEN }}); const users = s.sqliteTable("users", { id: s.integer(), name: s.text(), }) const result = await db.select().from(users); ``` #### What's next? Source: https://orm.drizzle.team/docs/connect-vercel-postgres import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> Vercel Postgres - Database [connection basics](/docs/connect-overview) with Drizzle - Vercel Postgres database - [website](https://vercel.com/docs/storage/vercel-postgres) - Vercel Postgres driver - [docs](https://vercel.com/docs/storage/vercel-postgres/sdk) & [GitHub](https://github.com/vercel/storage/tree/main/packages/postgres) - Drizzle PostgreSQL drivers - [docs](/docs/get-started-postgresql) According to their **[official website](https://vercel.com/docs/storage/vercel-postgres)**, Vercel Postgres is a serverless SQL database designed to integrate with Vercel Functions. Drizzle ORM natively supports both **[@vercel/postgres](https://vercel.com/docs/storage/vercel-postgres)** serverless driver with `drizzle-orm/vercel-postgres` package and **[`postgres`](#postgresjs)** or **[`pg`](#node-postgres)** drivers to access Vercel Postgres through `postgesql://` Check out the official **[Vercel Postgres + Drizzle](https://vercel.com/docs/storage/vercel-postgres/using-an-orm#drizzle)** docs. #### Step 1 - Install packages drizzle-orm @vercel/postgres -D drizzle-kit #### Step 2 - Prepare Vercel Postgres Setup a project according to the **[official docs.](https://vercel.com/docs/storage/vercel-postgres/quickstart)** #### Step 3 - Initialize the driver and make a query ```typescript copy import { drizzle } from 'drizzle-orm/vercel-postgres'; const db = drizzle(); const result = await db.execute('select 1'); ``` If you need to provide your existing driver: ```typescript copy import { sql } from '@vercel/postgres'; import { drizzle } from 'drizzle-orm/vercel-postgres'; const db = drizzle({ client: sql }) const result = await db.execute('select 1'); ``` With **[@vercel/postgres](https://vercel.com/docs/storage/vercel-postgres)** severless package you can access Vercel Postgres from either serverful or serverless environments with no TCP available, like Cloudflare Workers, through websockets. If you're about to use Vercel Postgres from a _serverfull_ environment, you can do it either with `@vercel/postgres` or directly access the DB through `postgesql://` with either **[`postgres`](#postgresjs)** or **[`pg`](#node-postgres)**. #### What's next? Source: https://orm.drizzle.team/docs/connect-xata import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; # Drizzle \<\> Xata - Database [connection basics](/docs/connect-overview) with Drizzle - Xata database - [website](https://xata.io/docs) - Xata driver - [docs](https://xata.io/docs/sdk/typescript/overview) & [GitHub](https://github.com/xataio/client-ts) - Drizzle PostgreSQL drivers - [docs](/docs/get-started-postgresql) According their **[official website](https://xata.io)**, Xata is a Postgres data platform with a focus on reliability, scalability, and developer experience. The Xata Postgres service is currently in beta, please see the [Xata docs](https://xata.io/docs/postgres) on how to enable it in your account. Drizzle ORM natively supports both the `xata` driver with `drizzle-orm/xata` package and the **[`postgres`](#postgresjs)** or **[`pg`](#node-postgres)** drivers for accessing a Xata Postgres database. #### Step 1 - Install packages drizzle-orm @xata.io/client -D drizzle-kit You can use Drizzle with Xata with a HTTP client or a TCP client. The HTTP client doesn't create a persistent connection to the Xata server, while the TCP client does and can be used for better performance with a higher number of requests. The HTTP client is usually recommended from serverless environments like Cloudflare Workers or Vercel Edge Functions. The TCP client is typically used from long-running servers like Express.js or Fastify. The following example use the Xata generated client, which you obtain by running the [xata init](https://xata.io/docs/getting-started/installation) CLI command. ```typescript copy" import { drizzle } from 'drizzle-orm/xata-http'; import { getXataClient } from './xata'; // Generated client const xata = getXataClient(); const db = drizzle(xata); const result = await db.select().from(...); ``` ```typescript copy" import { drizzle } from 'drizzle-orm/node-postgres'; import { getXataClient } from './xata'; // Generated client import { Client } from 'pg'; const xata = getXataClient(); const client = new Client({ connectionString: xata.sql.connectionString }); const db = drizzle(client); ``` ```typescript copy" import { drizzle } from 'drizzle-orm/node-postgres'; import { getXataClient } from './xata'; // Generated client import { Pool } from 'pg'; const xata = getXataClient(); const pool = new Pool({ connectionString: xata.sql.connectionString, max: 10 }); const db = drizzle(pool); ``` If you prefer to not use the generated Xata client, it is also possible to use Xata with the **[`postgres`](#postgresjs)** or **[`pg`](#node-postgres)** drivers, in this case you can copy the connection string from the Settings page of your Xata database. For more information, please check our [PostgreSQL connections section](/docs/get-started-postgresql) For more details about using Drizzle with Xata, see the official [Xata docs](https://xata.io/docs/integrations/drizzle). #### What's next? Source: https://orm.drizzle.team/docs/custom-types import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; # Common way of defining custom types ## Examples The best way to see how `customType` definition is working is to check how existing data types in postgres and mysql could be defined using `customType` function from Drizzle ORM. **Serial** ```typescript copy import { customType } from 'drizzle-orm/pg-core'; const customSerial = customType<{ data: number; notNull: true; default: true }>( { dataType() { return 'serial'; }, }, ); ``` **Text** ```typescript copy import { customType } from 'drizzle-orm/pg-core'; const customText = customType<{ data: string }>({ dataType() { return 'text'; }, }); ``` **Boolean** ```typescript copy import { customType } from 'drizzle-orm/pg-core'; const customBoolean = customType<{ data: boolean }>({ dataType() { return 'boolean'; }, }); ``` **Jsonb** ```typescript copy import { customType } from 'drizzle-orm/pg-core'; const customJsonb = (name: string) => customType<{ data: TData; driverData: string }>({ dataType() { return 'jsonb'; }, toDriver(value: TData): string { return JSON.stringify(value); }, })(name); ``` **Timestamp** ```typescript copy import { customType } from 'drizzle-orm/pg-core'; const customTimestamp = customType< { data: Date; driverData: string; config: { withTimezone: boolean; precision?: number }; } >({ dataType(config) { const precision = typeof config.precision !== 'undefined' ? ` (${config.precision})` : ''; return `timestamp${precision}${ config.withTimezone ? ' with time zone' : '' }`; }, fromDriver(value: string): Date { return new Date(value); }, }); ``` Usage for all types will be same as defined functions in Drizzle ORM. For example: ```typescript copy const usersTable = pgTable('users', { id: customSerial('id').primaryKey(), name: customText('name').notNull(), verified: customBoolean('verified').notNull().default(false), jsonb: customJsonb('jsonb'), createdAt: customTimestamp('created_at', { withTimezone: true }).notNull() .default(sql`now()`), }); ``` **Serial** ```typescript copy import { customType } from 'drizzle-orm/mysql-core'; const customInt = customType<{ data: number; notNull: false; default: false }>( { dataType() { return 'int'; }, }, ); ``` **Text** ```typescript copy import { customType } from 'drizzle-orm/mysql-core'; const customText = customType<{ data: string }>({ dataType() { return 'text'; }, }); ``` **Boolean** ```typescript copy import { customType } from 'drizzle-orm/mysql-core'; const customBoolean = customType<{ data: boolean }>({ dataType() { return 'boolean'; }, fromDriver(value) { if (typeof value === 'boolean') { return value; } return value === 1; }, }); ``` **Json** ```typescript copy import { customType } from 'drizzle-orm/mysql-core'; const customJson = (name: string) => customType<{ data: TData; driverData: string }>({ dataType() { return 'json'; }, toDriver(value: TData): string { return JSON.stringify(value); }, })(name); ``` **Timestamp** ```typescript copy import { customType } from 'drizzle-orm/mysql-core'; const customTimestamp = customType< { data: Date; driverData: string; config: { fsp: number } } >({ dataType(config) { const precision = typeof config.fsp !== 'undefined' ? ` (${config.fsp})` : ''; return `timestamp${precision}`; }, fromDriver(value: string): Date { return new Date(value); }, }); ``` Usage for all types will be same as defined functions in Drizzle ORM. For example: ```typescript copy const usersTable = mysqlTable('userstest', { id: customInt('id').primaryKey(), name: customText('name').notNull(), verified: customBoolean('verified').notNull().default(false), jsonb: customJson('jsonb'), createdAt: customTimestamp('created_at', { fsp: 2 }).notNull().default( sql`now()`, ), }); ``` ## TS-doc for type definitions You can check ts-doc for `types` and `param` definition. ```typescript export type CustomTypeValues = { /** * Required type for custom column, that will infer proper type model * * Examples: * * If you want your column to be `string` type after selecting/or on inserting - use `data: string`. Like `text`, `varchar` * * If you want your column to be `number` type after selecting/or on inserting - use `data: number`. Like `integer` */ data: unknown; /** * Type helper, that represents what type database driver is accepting for specific database data type */ driverData?: unknown; /** * What config type should be used for {@link CustomTypeParams} `dataType` generation */ config?: Record; /** * If your custom data type should be notNull by default you can use `notNull: true` * * @example * const customSerial = customType<{ data: number, notNull: true, default: true }>({ * dataType() { * return 'serial'; * }, * }); */ notNull?: boolean; /** * If your custom data type has default you can use `default: true` * * @example * const customSerial = customType<{ data: number, notNull: true, default: true }>({ * dataType() { * return 'serial'; * }, * }); */ default?: boolean; }; export interface CustomTypeParams { /** * Database data type string representation, that is used for migrations * @example * ``` * `jsonb`, `text` * ``` * * If database data type needs additional params you can use them from `config` param * @example * ``` * `varchar(256)`, `numeric(2,3)` * ``` * * To make `config` be of specific type please use config generic in {@link CustomTypeValues} * * @example * Usage example * ``` * dataType() { * return 'boolean'; * }, * ``` * Or * ``` * dataType(config) { * return typeof config.length !== 'undefined' ? `varchar(${config.length})` : `varchar`; * } * ``` */ dataType: (config: T['config']) => string; /** * Optional mapping function, between user input and driver * @example * For example, when using jsonb we need to map JS/TS object to string before writing to database * ``` * toDriver(value: TData): string { * return JSON.stringify(value); * } * ``` */ toDriver?: (value: T['data']) => T['driverData']; /** * Optional mapping function, that is responsible for data mapping from database to JS/TS code * @example * For example, when using timestamp we need to map string Date representation to JS Date * ``` * fromDriver(value: string): Date { * return new Date(value); * }, * ``` */ fromDriver?: (value: T['driverData']) => T['data']; } ``` Source: https://orm.drizzle.team/docs/data-querying import Callout from '@mdx/Callout.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from '@mdx/Section.astro'; import Flex from "@mdx/Flex.astro" import LinksList from "@mdx/LinksList.astro" import Prerequisites from "@mdx/Prerequisites.astro"; # Drizzle Queries + CRUD - How to define your schema - [Schema Fundamentals](/docs/sql-schema-declaration) - How to connect to the database - [Connection Fundamentals](/docs/connect-overview) Drizzle gives you a few ways for querying you database and it's up to you to decide which one you'll need in your next project. It can be either SQL-like syntax or Relational Syntax. Let's check them: ## Why SQL-like? \ **If you know SQL, you know Drizzle.** Other ORMs and data frameworks tend to deviate from or abstract away SQL, leading to a double learning curve: you need to learn both SQL and the framework's API. Drizzle is the opposite. We embrace SQL and built Drizzle to be SQL-like at its core, so you have little to no learning curve and full access to the power of SQL.
```typescript copy // Access your data await db .select() .from(posts) .leftJoin(comments, eq(posts.id, comments.post_id)) .where(eq(posts.id, 10)) ``` ```sql SELECT * FROM posts LEFT JOIN comments ON posts.id = comments.post_id WHERE posts.id = 10 ```
With SQL-like syntax, you can replicate much of what you can do with pure SQL and know exactly what Drizzle will do and what query will be generated. You can perform a wide range of queries, including select, insert, update, delete, as well as using aliases, WITH clauses, subqueries, prepared statements, and more. Let's look at more examples
```ts await db.insert(users).values({ email: 'user@gmail.com' }) ``` ```sql INSERT INTO users (email) VALUES ('user@gmail.com') ```
```ts await db.update(users) .set({ email: 'user@gmail.com' }) .where(eq(users.id, 1)) ``` ```sql UPDATE users SET email = 'user@gmail.com' WHERE users.id = 1 ```
```ts await db.delete(users).where(eq(users.id, 1)) ``` ```sql DELETE FROM users WHERE users.id = 1 ```
## Why not SQL-like? We're always striving for a perfectly balanced solution. While SQL-like queries cover 100% of your needs, there are certain common scenarios where data can be queried more efficiently. We've built the Queries API so you can fetch relational, nested data from the database in the most convenient and performant way, without worrying about joins or data mapping. **Drizzle always outputs exactly one SQL query**. Feel free to use it with serverless databases, and never worry about performance or roundtrip costs!
```ts const result = await db.query.users.findMany({ with: { posts: true }, }); ``` {/* ```sql SELECT * FROM users ... ``` */}
## Advanced With Drizzle, queries can be composed and partitioned in any way you want. You can compose filters independently from the main query, separate subqueries or conditional statements, and much more. Let's check a few advanced examples: #### Compose a WHERE statement and then use it in a query ```ts async function getProductsBy({ name, category, maxPrice, }: { name?: string; category?: string; maxPrice?: string; }) { const filters: SQL[] = []; if (name) filters.push(ilike(products.name, name)); if (category) filters.push(eq(products.category, category)); if (maxPrice) filters.push(lte(products.price, maxPrice)); return db .select() .from(products) .where(and(...filters)); } ``` #### Separate subqueries into different variables, and then use them in the main query ```ts const subquery = db .select() .from(internalStaff) .leftJoin(customUser, eq(internalStaff.userId, customUser.id)) .as('internal_staff'); const mainQuery = await db .select() .from(ticket) .leftJoin(subquery, eq(subquery.internal_staff.userId, ticket.staffId)); ``` #### What's next?
Source: https://orm.drizzle.team/docs/delete import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; # SQL Delete You can delete all rows in the table: ```typescript copy await db.delete(users); ``` And you can delete with filters and conditions: ```typescript copy await db.delete(users).where(eq(users.name, 'Dan')); ``` ### Limit Use `.limit()` to add `limit` clause to the query - for example:
```typescript await db.delete(users).where(eq(users.name, 'Dan')).limit(2); ``` ```sql delete from "users" where "users"."name" = $1 limit $2; ```
### Order By Use `.orderBy()` to add `order by` clause to the query, sorting the results by the specified fields:
```typescript import { asc, desc } from 'drizzle-orm'; await db.delete(users).where(eq(users.name, 'Dan')).orderBy(users.name); await db.delete(users).where(eq(users.name, 'Dan')).orderBy(desc(users.name)); // order by multiple fields await db.delete(users).where(eq(users.name, 'Dan')).orderBy(users.name, users.name2); await db.delete(users).where(eq(users.name, 'Dan')).orderBy(asc(users.name), desc(users.name2)); ``` ```sql delete from "users" where "users"."name" = $1 order by "name"; delete from "users" where "users"."name" = $1 order by "name" desc; delete from "users" where "users"."name" = $1 order by "name", "name2"; delete from "users" where "users"."name" = $1 order by "name" asc, "name2" desc; ```
### Delete with return You can delete a row and get it back in PostgreSQL and SQLite: ```typescript copy const deletedUser = await db.delete(users) .where(eq(users.name, 'Dan')) .returning(); // partial return const deletedUserIds: { deletedId: number }[] = await db.delete(users) .where(eq(users.name, 'Dan')) .returning({ deletedId: users.id }); ``` ## WITH DELETE clause Check how to use WITH statement with [select](/docs/select#with-clause), [insert](/docs/insert#with-insert-clause), [update](/docs/update#with-update-clause) Using the `with` clause can help you simplify complex queries by splitting them into smaller subqueries called common table expressions (CTEs):
```typescript copy const averageAmount = db.$with('average_amount').as( db.select({ value: sql`avg(${orders.amount})`.as('value') }).from(orders) ); const result = await db .with(averageAmount) .delete(orders) .where(gt(orders.amount, sql`(select * from ${averageAmount})`)) .returning({ id: orders.id }); ``` ```sql with "average_amount" as (select avg("amount") as "value" from "orders") delete from "orders" where "orders"."amount" > (select * from "average_amount") returning "id" ```
Source: https://orm.drizzle.team/docs/drizzle-config-file import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import SchemaFilePaths from "@mdx/SchemaFilePaths.mdx" import Prerequisites from "@mdx/Prerequisites.astro" import Dialects from "@mdx/Dialects.mdx" import Drivers from "@mdx/Drivers.mdx" import DriversExamples from "@mdx/DriversExamples.mdx" import Npx from "@mdx/Npx.astro" # Drizzle Kit configuration file - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file) Drizzle Kit lets you declare configuration options in `TypeScript` or `JavaScript` configuration files.
```plaintext {5} 📦 ├ ... ├ 📂 drizzle ├ 📂 src ├ 📜 drizzle.config.ts └ 📜 package.json ``` ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", out: "./drizzle", }); ``` ```js import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", out: "./drizzle", }); ```
Example of an extended config file ```ts collapsable import { defineConfig } from "drizzle-kit"; export default defineConfig({ out: "./drizzle", dialect: "postgresql", schema: "./src/schema.ts", driver: "pglite", dbCredentials: { url: "./database/", }, extensionsFilters: ["postgis"], schemaFilter: "public", tablesFilter: "*", introspect: { casing: "camel", }, migrations: { prefix: "timestamp", table: "__drizzle_migrations__", schema: "public", }, entities: { roles: { provider: '', exclude: [], include: [] } } breakpoints: true, strict: true, verbose: true, }); ``` ### Multiple configuration files You can have multiple config files in the project, it's very useful when you have multiple database stages or multiple databases or different databases on the same project: drizzle-kit generate --config=drizzle-dev.config.ts drizzle-kit generate --config=drizzle-prod.config.ts ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ### Migrations folder `out` param lets you define folder for your migrations, it's optional and `drizzle` by default. It's very useful since you can have many separate schemas for different databases in the same project and have different migration folders for them. Migration folder contains `.sql` migration files and `_meta` folder which is used by `drizzle-kit`
```plaintext {3} 📦 ├ ... ├ 📂 drizzle │ ├ 📂 _meta │ ├ 📜 user.ts │ ├ 📜 post.ts │ └ 📜 comment.ts ├ 📂 src ├ 📜 drizzle.config.ts └ 📜 package.json ``` ```ts {5} import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", // "mysql" | "sqlite" | "postgresql" | "turso" | "singlestore" schema: "./src/schema/*", out: "./drizzle", }); ```
## --- ### `dialect` Dialect of the database you're using | | | | :------------ | :----------------------------------- | | type | | | default | -- | | commands | `generate` `migrate` `push` `pull` `check` `up` | ```ts {4} import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "mysql", }); ``` ### `schema` [`glob`](https://www.digitalocean.com/community/tools/glob?comments=true&glob=/**/*.js&matches=false&tests=//%20This%20will%20match%20as%20it%20ends%20with%20'.js'&tests=/hello/world.js&tests=//%20This%20won't%20match!&tests=/test/some/globs) based path to drizzle schema file(s) or folder(s) contaning schema files. | | | | :------------ | :----------------- | | type | `string` `string[]` | | default | -- | | commands | `generate` `push` | ### `out` Defines output folder of your SQL migration files, json snapshots of your schema and `schema.ts` from `drizzle-kit pull` command. | | | | :------------ | :----------------- | | type | `string` `string[]` | | default | `drizzle` | | commands | `generate` `migrate` `push` `pull` `check` `up` | ```ts {4} import { defineConfig } from "drizzle-kit"; export default defineConfig({ out: "./drizzle", }); ``` ### `driver` Drizzle Kit automatically picks available database driver from your current project based on the provided `dialect`, yet some vendor specific databases require a different subset of connection params. `driver` option let's you explicitely pick those exceptions drivers. | | | | :------------ | :----------------- | | type | | | default | -- | | commands | `migrate` `push` `pull` | ## --- ### `dbCredentials` Database connection credentials in a form of `url`, `user:password@host:port/db` params or exceptions drivers() specific connection options. | | | | :------------ | :----------------- | | type | union of drivers connection options | | default | -- | | commands | `migrate` `push` `pull` |
```ts import { defineConfig } from 'drizzle-kit' export default defineConfig({ dialect: "postgresql", dbCredentials: { url: "postgres://user:password@host:port/db", } }) ``` ```ts import { defineConfig } from 'drizzle-kit' // via connection params export default defineConfig({ dialect: "postgresql", dbCredentials: { host: "host", port: 5432, user: "user", password: "password", database: "dbname", ssl: true, // can be boolean | "require" | "allow" | "prefer" | "verify-full" | options from node:tls } }) ```
```ts import { defineConfig } from 'drizzle-kit' export default defineConfig({ dialect: "mysql", dbCredentials: { url: "postgres://user:password@host:port/db", } }) ``` ```ts import { defineConfig } from 'drizzle-kit' // via connection params export default defineConfig({ dialect: "mysql", dbCredentials: { host: "host", port: 5432, user: "user", password: "password", database: "dbname", ssl: "...", // can be: string | SslOptions (ssl options from mysql2 package) } }) ```
```ts import { defineConfig } from 'drizzle-kit' export default defineConfig({ dialect: "sqlite", dbCredentials: { url: ":memory:", // inmemory database // or url: "sqlite.db", // or url: "file:sqlite.db" // file: prefix is required by libsql } }) ``` ```ts import { defineConfig } from 'drizzle-kit' export default defineConfig({ dialect: "turso", dbCredentials: { url: "libsql://acme.turso.io" // remote Turso database url authToken: "...", // or if you need local db url: ":memory:", // inmemory database // or url: "file:sqlite.db", // file: prefix is required by libsql } }) ``` ```ts import { defineConfig } from 'drizzle-kit' export default defineConfig({ dialect: "sqlite", driver: "d1-http", dbCredentials: { accountId: "", databaseId: "", token: "", } }) ``` ```ts import { defineConfig } from 'drizzle-kit' export default defineConfig({ dialect: "postgresql", driver: "aws-data-api", dbCredentials: { database: "database", resourceArn: "resourceArn", secretArn: "secretArn", }, }); ``` ```ts import { defineConfig } from 'drizzle-kit' export default defineConfig({ dialect: "postgresql", driver: "pglite", dbCredentials: { url: "./database/", // database folder path } }) ```
### `migrations` When running `drizzle-kit migrate` - drizzle will records about successfully applied migrations in your database in log table named `__drizzle_migrations` in `public` schema(PostgreSQL only). `migrations` config options lets you change both migrations log `table` name and `schema`. | | | | :------------ | :----------------- | | type | `{ table: string, schema: string }` | | default | `{ table: "__drizzle_migrations", schema: "drizzle" }` | | commands | `migrate` | ```ts export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", migrations: { table: 'my-migrations-table', // `__drizzle_migrations` by default schema: 'public', // used in PostgreSQL only, `drizzle` by default }, }); ``` ### `introspect` Cofiguration for `drizzle-kit pull` command. `casing` is responsible for in-code column keys casing | | | | :------------ | :----------------- | | type | `{ casing: "preserve" \| "camel" }` | | default | `{ casing: "camel" }` | | commands | `pull` |
```ts import * as p from "drizzle-orm/pg-core" export const users = p.pgTable("users", { id: p.serial(), firstName: p.text("first-name"), lastName: p.text("LastName"), email: p.text(), phoneNumber: p.text("phone_number"), }); ``` ```sql SELECT a.attname AS column_name, format_type(a.atttypid, a.atttypmod) as data_type FROM pg_catalog.pg_attribute a; ``` ``` column_name | data_type ---------------+------------------------ id | serial first-name | text LastName | text email | text phone_number | text ```
```ts import * as p from "drizzle-orm/pg-core" export const users = p.pgTable("users", { id: p.serial(), "first-name": p.text("first-name"), LastName: p.text("LastName"), email: p.text(), phone_number: p.text("phone_number"), }); ``` ```sql SELECT a.attname AS column_name, format_type(a.atttypid, a.atttypmod) as data_type FROM pg_catalog.pg_attribute a; ``` ``` column_name | data_type ---------------+------------------------ id | serial first-name | text LastName | text email | text phone_number | text ```
## --- ### `tablesFilter` If you want to run multiple projects with one database - check out [our guide](/docs/goodies#multi-project-schema). `drizzle-kit push` and `drizzle-kit pull` will by default manage all tables in `public` schema. You can configure list of tables, schemas and extensions via `tablesFilters`, `schemaFilter` and `extensionFilters` options. `tablesFilter` option lets you specify [`glob`](https://www.digitalocean.com/community/tools/glob?comments=true&glob=/**/*.js&matches=false&tests=//%20This%20will%20match%20as%20it%20ends%20with%20'.js'&tests=/hello/world.js&tests=//%20This%20won't%20match!&tests=/test/some/globs) based table names filter, e.g. `["users", "user_info"]` or `"user*"` | | | | :------------ | :----------------- | | type | `string` `string[]` | | default | -- | | commands | `generate` `push` `pull` | ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", tablesFilter: ["users", "posts", "project1_*"], }); ``` ### `schemaFilter` If you want to run multiple projects with one database - check out [our guide](/docs/goodies#multi-project-schema). `drizzle-kit push` and `drizzle-kit pull` will by default manage all tables in `public` schema. You can configure list of tables, schemas and extensions via `tablesFilters`, `schemaFilter` and `extensionFilters` options. `schemaFilter` option lets you specify list of schemas for Drizzle Kit to manage | | | | :------------ | :----------------- | | type | `string[]` | | default | `["public"]` | | commands | `generate` `push` `pull` | ```ts export default defineConfig({ dialect: "postgresql", schemaFilter: ["public", "schema1", "schema2"], }); ``` ### `extensionsFilters` Some extensions like [`postgis`](https://postgis.net/), when installed on the database, create its own tables in public schema. Those tables have to be ignored by `drizzle-kit push` or `drizzle-kit pull`. `extensionsFilters` option lets you declare list of installed extensions for drizzle kit to ignore their tables in the schema. | | | | :------------ | :----------------- | | type | `["postgis"]` | | default | `[]` | | commands | `push` `pull` | ```ts export default defineConfig({ dialect: "postgresql", extensionsFilters: ["postgis"], }); ``` ## --- ### `entities` This configuration is created to set up management settings for specific `entities` in the database. For now, it only includes `roles`, but eventually all database entities will migrate here, such as `tables`, `schemas`, `extensions`, `functions`, `triggers`, etc #### `roles` If you are using Drizzle Kit to manage your schema and especially the defined roles, there may be situations where you have some roles that are not defined in the Drizzle schema. In such cases, you may want Drizzle Kit to skip those `roles` without the need to write each role in your Drizzle schema and mark it with `.existing()`. The `roles` option lets you: - Enable or disable role management with Drizzle Kit. - Exclude specific roles from management by Drizzle Kit. - Include specific roles for management by Drizzle Kit. - Enable modes for providers like `Neon` and `Supabase`, which do not manage their specific roles. - Combine all the options above | | | | :------------ | :----------------- | | type | `boolean \| { provider: "neon" \| "supabase", include: string[], exclude: string[]}`| | default | `false` | | commands | `push` `pull` `generate` | By default, `drizzle-kit` won't manage roles for you, so you will need to enable that. in `drizzle.config.ts` ```ts export default defineConfig({ dialect: "postgresql", extensionsFilters: entities: { roles: true } }); ``` **You have a role `admin` and want to exclude it from the list of manageable roles** ```ts // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ ... entities: { roles: { exclude: ['admin'] } } }); ``` **You have a role `admin` and want to include to the list of manageable roles** ```ts // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ ... entities: { roles: { include: ['admin'] } } }); ``` **If you are using `Neon` and want to exclude roles defined by `Neon`, you can use the provider option** ```ts // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ ... entities: { roles: { provider: 'neon' } } }); ``` **If you are using `Supabase` and want to exclude roles defined by `Supabase`, you can use the provider option** ```ts // 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 database providers, so you may need to use both the `provider` option and `exclude` additional roles. You can easily do this with Drizzle: ```ts // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ ... entities: { roles: { provider: 'supabase', exclude: ['new_supabase_role'] } } }); ``` ## --- ### `strict` Prompts confirmation to run printed SQL statements when running `drizzle-kit push` command. | | | | :------------ | :----------------- | | type | `boolean` | | default | `false` | | commands | `push` | ```ts export default defineConfig({ dialect: "postgresql", breakpoints: false, }); ``` ### `verbose` Print all SQL statements during `drizzle-kit push` command. | | | | :------------ | :----------------- | | type | `boolean` | | default | `true` | | commands | `generate` `pull` | ```ts export default defineConfig({ dialect: "postgresql", breakpoints: false, }); ``` ### `breakpoints` Drizzle Kit will automatically embed `--> statement-breakpoint` into generated SQL migration files, that's necessary for databases that do not support multiple DDL alternation statements in one transaction(MySQL and SQLite). `breakpoints` option flag lets you switch it on and off | | | | :------------ | :----------------- | | type | `boolean` | | default | `true` | | commands | `generate` `pull` | ```ts export default defineConfig({ dialect: "postgresql", breakpoints: false, }); ``` Source: https://orm.drizzle.team/docs/drizzle-kit-check import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from "@mdx/Npm.astro"; import Npx from "@mdx/Npx.astro"; # `drizzle-kit check` - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file) - `drizzle-kit generate` command - [read here](/docs/drizzle-kit-generate) `drizzle-kit check` command lets you check consistency of your generated SQL migrations history. That's extremely useful when you have multiple developers working on the project and altering database schema on different branches - read more about [migrations for teams](/docs/kit-migrations-for-teams).


`drizzle-kit check` command requires you to specify both `dialect` and database connection credentials, you can provide them either via [drizzle.config.ts](/docs/drizzle-config-file) config file or via CLI options
```ts {5,8} // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", }); ``` ```shell npx drizzle-kit check ```
```shell npx drizzle-kit check --dialect=postgresql ```
### Multiple configuration files in one project You can have multiple config files in the project, it's very useful when you have multiple database stages or multiple databases on the same project: drizzle-kit migrate --config=drizzle-dev.config.ts drizzle-kit migrate --config=drizzle-prod.config.ts ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ### Extended list of configurations We recommend configuring `drizzle-kit` through [drizzle.config.ts](/docs/drizzle-config-file) file, yet you can provide all configuration options through CLI if necessary, e.g. in CI/CD pipelines, etc. | | | | | :-------- | :--------- | :---------------------------------------------------------------------- | | `dialect` | `required` | Database dialect you are using. Can be `postgresql`,`mysql` or `sqlite` | | `out` | | migrations folder, default=`./drizzle` | | `config` | | config file path, default=`drizzle.config.ts` |
drizzle-kit check --dialect=postgresql drizzle-kit check --dialect=postgresql --out=./migrations-folder Source: https://orm.drizzle.team/docs/drizzle-kit-export import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import Prerequisites from "@mdx/Prerequisites.astro" import Npx from "@mdx/Npx.astro"; import SchemaFilePaths from "@mdx/SchemaFilePaths.mdx" import Dialects from "@mdx/Dialects.mdx" # `drizzle-kit export` - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file)
`drizzle-kit export` lets you export SQL representation of Drizzle schema and print in console SQL DDL representation on it. Drizzle Kit `export` command triggers a sequence of events: 1. It will read through your Drizzle schema file(s) and compose a json snapshot of your schema 3. Based on json differences it will generate SQL DDL statements 4. Output SQL DDL statements to console It's designed to cover [codebase first](/docs/migrations) approach of managing Drizzle migrations. You can export the SQL representation of the Drizzle schema, allowing external tools like Atlas to handle all the migrations for you `drizzle-kit export` command requires you to provide both `dialect` and `schema` path options, you can set them either via [drizzle.config.ts](/docs/drizzle-config-file) config file or via CLI options
```ts // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", }); ``` ```shell npx drizzle-kit export ```
```shell npx drizzle-kit export --dialect=postgresql --schema=./src/schema.ts ```
### Schema files path You can have a single `schema.ts` file or as many schema files as you want spread out across the project. Drizzle Kit requires you to specify path(s) to them as a [glob](https://www.digitalocean.com/community/tools/glob?comments=true&glob=/**/*.js&matches=false&tests=//%20This%20will%20match%20as%20it%20ends%20with%20'.js'&tests=/hello/world.js&tests=//%20This%20won't%20match!&tests=/test/some/globs) via `schema` configuration option. ### Multiple configuration files in one project You can have multiple config files in the project, it's very useful when you have multiple database stages or multiple databases or different databases on the same project: drizzle-kit export --config=drizzle-dev.config.ts drizzle-kit export --config=drizzle-prod.config.ts ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ### Extended list of available configurations `drizzle-kit export` has a list of cli-only options | | | | :-------- | :--------------------------------------------------- | | `--sql` | generating SQL representation of Drizzle Schema | By default, Drizzle Kit outputs SQL files, but in the future, we want to support different formats drizzle-kit push --name=init drizzle-kit push --name=seed_users --custom


We recommend configuring `drizzle-kit` through [drizzle.config.ts](/docs/drizzle-config-file) file, yet you can provide all configuration options through CLI if necessary, e.g. in CI/CD pipelines, etc. | | | | | :------------ | :------- | :---------------------------------------------------------------------- | | `dialect` | `required` | Database dialect, one of | | `schema` | `required` | Path to typescript schema file(s) or folder(s) with multiple schema files | | `config` | | Configuration file path, default is `drizzle.config.ts` | ### Example Example of how to export drizzle schema to console with Drizzle schema located in `./src/schema.ts` We will also place drizzle config file in the `configs` folder. Let's create config file: ```plaintext {4} 📦 ├ 📂 configs │ └ 📜 drizzle.config.ts ├ 📂 src │ └ 📜 schema.ts └ … ``` ```ts filename='drizzle.config.ts' import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", }); ``` ```ts filename='schema.ts' import { pgTable, serial, text } from 'drizzle-orm/pg-core' export const users = pgTable('users', { id: serial('id').primaryKey(), email: text('email').notNull(), name: text('name') }); ``` Now let's run ```shell npx drizzle-kit export --config=./configs/drizzle.config.ts ``` And it will successfully output SQL representation of drizzle schema ```bash CREATE TABLE "users" ( "id" serial PRIMARY KEY NOT NULL, "email" text NOT NULL, "name" text ); ``` Source: https://orm.drizzle.team/docs/drizzle-kit-generate import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import Prerequisites from "@mdx/Prerequisites.astro" import Npx from "@mdx/Npx.astro"; import SchemaFilePaths from "@mdx/SchemaFilePaths.mdx" import Dialects from "@mdx/Dialects.mdx" # `drizzle-kit generate` - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file)
`drizzle-kit generate` lets you generate SQL migrations based on you Drizzle schema upon declaration or on subsequent schema changes. Drizzle Kit `generate` command triggers a sequence of events: 1. It will read through your Drizzle schema file(s) and compose a json snapshot of your schema 2. It will read through your previous migrations folders and compare current json snapshot to the most recent one 3. Based on json differences it will generate SQL migrations 4. Save `migration.sql` and `snapshot.json` in migration folder under current timestamp
```typescript filename="src/schema.ts" import * as p from "./drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), email: p.text().unique(), }; ``` ``` ┌────────────────────────┐ │ $ drizzle-kit generate │ └─┬──────────────────────┘ │ └ 1. read previous migration folders 2. find diff between current and previous scheama 3. prompt developer for renames if necessary ┌ 4. generate SQL migration and persist to file │ ┌─┴───────────────────────────────────────┐ │ 📂 drizzle │ ├ 📂 _meta │ └ 📜 0000_premium_mister_fear.sql v ``` ```sql -- drizzle/0000_premium_mister_fear.sql CREATE TABLE "users" ( "id" SERIAL PRIMARY KEY, "name" TEXT, "email" TEXT UNIQUE ); ```
It's designed to cover [code first](/docs/migrations) approach of managing Drizzle migrations. You can apply generated migrations using [`drizzle-kit migrate`](/docs/drizzle-kit-migrate), using drizzle-orm's `migrate()`, using external migration tools like bytebase or running migrations yourself directly on the database. `drizzle-kit generate` command requires you to provide both `dialect` and `schema` path options, you can set them either via [drizzle.config.ts](/docs/drizzle-config-file) config file or via CLI options
```ts // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", }); ``` ```shell npx drizzle-kit generate ```
```shell npx drizzle-kit generate --dialect=postgresql --schema=./src/schema.ts ```
### Schema files path You can have a single `schema.ts` file or as many schema files as you want spread out across the project. Drizzle Kit requires you to specify path(s) to them as a [glob](https://www.digitalocean.com/community/tools/glob?comments=true&glob=/**/*.js&matches=false&tests=//%20This%20will%20match%20as%20it%20ends%20with%20'.js'&tests=/hello/world.js&tests=//%20This%20won't%20match!&tests=/test/some/globs) via `schema` configuration option. ### Custom migration file name You can set custom migration file names by providing `--name` CLI option ```shell npx drizzle-kit generate --name=init ``` ```plaintext {4} 📦 ├ 📂 drizzle │ ├ 📂 _meta │ └ 📜 0000_init.sql ├ 📂 src └ … ``` ### Multiple configuration files in one project You can have multiple config files in the project, it's very useful when you have multiple database stages or multiple databases or different databases on the same project: drizzle-kit generate --config=drizzle-dev.config.ts drizzle-kit generate --config=drizzle-prod.config.ts ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ### Custom migrations You can generate empty migration files to write your own custom SQL migrations for DDL alternations currently not supported by Drizzle Kit or data seeding. Extended docs on custom migrations - [see here](/docs/kit-custom-migrations) ```shell drizzle-kit generate --custom --name=seed-users ```
```plaintext {5} 📦 ├ 📂 drizzle │ ├ 📂 _meta │ ├ 📜 0000_init.sql │ └ 📜 0001_seed-users.sql ├ 📂 src └ … ``` ```sql -- ./drizzle/0001_seed-users.sql INSERT INTO "users" ("name") VALUES('Dan'); INSERT INTO "users" ("name") VALUES('Andrew'); INSERT INTO "users" ("name") VALUES('Dandrew'); ```
### Extended list of available configurations `drizzle-kit generate` has a list of cli-only options | | | | :-------- | :--------------------------------------------------- | | `custom` | generate empty SQL for custom migration | | `name` | generate migration with custom name | drizzle-kit generate --name=init drizzle-kit generate --name=seed_users --custom


We recommend configuring `drizzle-kit` through [drizzle.config.ts](/docs/drizzle-config-file) file, yet you can provide all configuration options through CLI if necessary, e.g. in CI/CD pipelines, etc. | | | | | :------------ | :------- | :---------------------------------------------------------------------- | | `dialect` | `required` | Database dialect, one of | | `schema` | `required` | Path to typescript schema file(s) or folder(s) with multiple schema files | | `out` | | Migrations output folder, default is `./drizzle` | | `config` | | Configuration file path, default is `drizzle.config.ts` | | `breakpoints` | | SQL statements breakpoints, default is `true` | ### Extended example Example of how to create a custom postgresql migration file named `0001_seed-users.sql` with Drizzle schema located in `./src/schema.ts` and migrations folder named `./migrations` instead of default `./drizzle`. We will also place drizzle config file in the `configs` folder. Let's create config file: ```plaintext {4} 📦 ├ 📂 migrations ├ 📂 configs │ └ 📜 drizzle.config.ts ├ 📂 src └ … ``` ```ts filename='drizzle.config.ts' import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", out: "./migrations", }); ``` Now let's run ```shell npx drizzle-kit generate --config=./configs/drizzle.config.ts --name=seed-users --custom ``` And it will successfully generate
```plaintext {6} 📦 ├ … ├ 📂 migrations │ ├ 📂 _meta │ ├ 📜 0000_init.sql │ └ 📜 0001_seed-users.sql └ … ``` ```sql -- ./drizzle/0001_seed-users.sql INSERT INTO "users" ("name") VALUES('Dan'); INSERT INTO "users" ("name") VALUES('Andrew'); INSERT INTO "users" ("name") VALUES('Dandrew'); ```
Source: https://orm.drizzle.team/docs/drizzle-kit-migrate import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import Npx from "@mdx/Npx.astro"; # `drizzle-kit migrate` - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file) - `drizzle-kit generate` command - [read here](/docs/drizzle-kit-generate)
`drizzle-kit migrate` lets you apply SQL migrations generated by [`drizzle-kit generate`](/docs/drizzle-kit-generate). It's designed to cover [code first(option 3)](/docs/migrations) approach of managing Drizzle migrations. Drizzle Kit `migrate` command triggers a sequence of events: 1. Reads through migration folder and read all `.sql` migration files 2. Connects to the database and fetches entries from drizzle migrations log table 3. Based on previously applied migrations it will decide which new migrations to run 4. Runs SQL migrations and logs applied migrations to drizzle migrations table
```plaintext ├ 📂 drizzle │ ├ 📂 _meta │ ├ 📜 0000_premium_mister_fear.sql │ └ 📜 0001_delicate_professor_xavie.sql └ … ``` ```plaintext ┌───────────────────────┐ │ $ drizzle-kit migrate │ └─┬─────────────────────┘ │ ┌──────────────────────────┐ └ 1. reads migration.sql files in migrations folder │ │ 2. fetch migration history from database -------------> │ │ ┌ 3. pick previously unapplied migrations <-------------- │ DATABASE │ └ 4. apply new migration to the database ---------------> │ │ │ │ └──────────────────────────┘ [✓] done! ```
`drizzle-kit migrate` command requires you to specify both `dialect` and database connection credentials, you can provide them either via [drizzle.config.ts](/docs/drizzle-config-file) config file or via CLI options
```ts {5,8} // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", dbCredentials: { url: "postgresql://user:password@host:port/dbname" }, }); ``` ```shell npx drizzle-kit migrate ```
```shell npx drizzle-kit migrate --dialect=postgresql --url=postgresql://user:password@host:port/dbname ```
### Applied migrations log in the database Upon running migrations Drizzle Kit will persist records about successfully applied migrations in your database. It will store them in migrations log table named `__drizzle_migrations`. You can customise both **table** and **schema**(PostgreSQL only) of that table via drizzle config file: ```ts filename="drizzle.config.ts" {8-9} export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", dbCredentials: { url: "postgresql://user:password@host:port/dbname" }, migrations: { table: 'my-migrations-table', // `__drizzle_migrations` by default schema: 'public', // used in PostgreSQL only, `drizzle` by default }, }); ``` ### Multiple configuration files in one project You can have multiple config files in the project, it's very useful when you have multiple database stages or multiple databases on the same project: drizzle-kit migrate --config=drizzle-dev.config.ts drizzle-kit migrate --config=drizzle-prod.config.ts ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ### Extended example Let's generate SQL migration and apply it to our database using `drizzle-kit generate` and `drizzle-kit migrate` commands ```plaintext 📦 ├ 📂 drizzle ├ 📂 src │ ├ 📜 schema.ts │ └ 📜 index.ts ├ 📜 drizzle.config.ts └ … ``` ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", dbCredentials: { url: "postgresql://user:password@host:port/dbname" }, migrations: { table: 'journal', schema: 'drizzle', }, }); ``` ```ts import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), }) ``` Now let's run ```shell npx drizzle-kit generate --name=init ``` it will generate
```plaintext {5} 📦 ├ … ├ 📂 migrations │ ├ 📂 _meta │ └ 📜 0000_init.sql └ … ``` ```sql -- ./drizzle/0000_init.sql CREATE TABLE "users"( id serial primary key, name text, ) ```
Now let's run ```shell npx drizzle-kit migrate ``` and our SQL migration is now successfully applied to the database ✅ Source: https://orm.drizzle.team/docs/drizzle-kit-pull import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import Drivers from "@mdx/Drivers.mdx" import Dialects from "@mdx/Dialects.mdx" import Npm from "@mdx/Npm.astro" import Npx from "@mdx/Npx.astro" # `drizzle-kit pull` - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file) docs `drizzle-kit pull` lets you literally pull(introspect) your existing database schema and generate `schema.ts` drizzle schema file, it is designed to cover [database first](/docs/migrations) approach of Drizzle migrations. When you run Drizzle Kit `pull` command it will: 1. Pull database schema(DDL) from your existing database 2. Generate `schema.ts` drizzle schema file and save it to `out` folder
``` ┌────────────────────────┐ ┌─────────────────────────┐ │ │ <--- CREATE TABLE "users" ( ┌──────────────────────────┐ │ │ "id" SERIAL PRIMARY KEY, │ ~ drizzle-kit pull │ │ │ "name" TEXT, └─┬────────────────────────┘ │ DATABASE │ "email" TEXT UNIQUE │ │ │ ); └ Pull datatabase schema -----> │ │ ┌ Generate Drizzle <----- │ │ │ schema TypeScript file └────────────────────────┘ │ v ``` ```typescript import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), email: p.text().unique(), }; ```
It is a great approach if you need to manage database schema outside of your TypeScript project or you're using database, which is managed by somebody else.


`drizzle-kit pull` requires you to specify `dialect` and either database connection `url` or `user:password@host:port/db` params, you can provide them either via [drizzle.config.ts](/docs/drizzle-config-file) config file or via CLI options:
```ts // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", dbCredentials: { url: "postgresql://user:password@host:port/dbname", }, }); ``` ```shell npx drizzle-kit pull ```
```shell npx drizzle-kit pull --dialect=postgresql --url=postgresql://user:password@host:port/dbname ```
### Multiple configuration files in one project You can have multiple config files in the project, it's very useful when you have multiple database stages or multiple databases or different databases on the same project: drizzle-kit pull --config=drizzle-dev.config.ts drizzle-kit pull --config=drizzle-prod.config.ts ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ### Specifying database driver **Expo SQLite** and **OP SQLite** are on-device(per-user) databases, there's no way to `pull` database schema from there.
For embedded databases Drizzle provides **embedded migrations** - check out our [get started](/docs/get-started/expo-new) guide.
Drizzle Kit does not come with a pre-bundled database driver, it will automatically pick available database driver from your current project based on the `dialect` - [see discussion](https://github.com/drizzle-team/drizzle-orm/discussions/2203). Mostly all drivers of the same dialect share the same set of connection params, as for exceptions like `aws-data-api`, `pglight` and `d1-http` - you will have to explicitely specify `driver` param. ```ts {6} import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", driver: "aws-data-api", dbCredentials: { database: "database", resourceArn: "resourceArn", secretArn: "secretArn", }, }; ``` ```ts {6} import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", driver: "pglite", dbCredentials: { // inmemory url: ":memory:" // or database folder url: "./database/" }, }; ``` ```ts {6} import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "sqlite", driver: "d1-http", dbCredentials: { accountId: "accountId", databaseId: "databaseId", token: "token", }, }; ``` ### Including tables, schemas and extensions `drizzle-kit push` will by default manage all tables in `public` schema. You can configure list of tables, schemas and extensions via `tablesFilters`, `schemaFilter` and `extensionFilters` options. | | | | :------------------ | :-------------------------------------------------------------------------------------------- | | `tablesFilter` | `glob` based table names filter, e.g. `["users", "user_info"]` or `"user*"`. Default is `"*"` | | `schemaFilter` | Schema names filter, e.g. `["public", "drizzle"]`. Default is `["public"]` | | `extensionsFilters` | List of installed database extensions, e.g. `["postgis"]`. Default is `[]` |
Let's configure drizzle-kit to only operate with **all tables** in **public** schema and let drizzle-kit know that there's a **postgis** extension installed, which creates it's own tables in public schema, so drizzle can ignore them.
```ts filename="drizzle.config.ts" {9-11} import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", dbCredentials: { url: "postgresql://user:password@host:port/dbname", }, extensionsFilters: ["postgis"], schemaFilter: ["public"], tablesFilter: ["*"], }); ``` ```shell npx drizzle-kit push ```
### Extended list of configurations We recommend configuring `drizzle-kit` through [drizzle.config.ts](/docs/drizzle-config-file) file, yet you can provide all configuration options through CLI if necessary, e.g. in CI/CD pipelines, etc. | | | | | :------------------ | :--------- | :------------------------------------------------------------------------ | | `dialect` | `required` | Database dialect, one of | | `driver` | | Drivers exceptions | | `out` | | Migrations output folder path, default is `./drizzle` | | `url` | | Database connection string | | `user` | | Database user | | `password` | | Database password | | `host` | | Host | | `port` | | Port | | `database` | | Database name | | `config` | | Config file path, default is `drizzle.config.ts` | | `introspect-casing` | | Strategy for JS keys creation in columns, tables, etc. `preserve` `camel` | | `tablesFilter` | | Table name filter | | `schemaFilter` | | Schema name filter. Default: `["public"]` | | `extensionsFilters` | | Database extensions internal database filters | drizzle-kit pull --dialect=postgresql --schema=src/schema.ts --url=postgresql://user:password@host:port/dbname drizzle-kit pull --dialect=postgresql --schema=src/schema.ts --driver=pglite url=database/ drizzle-kit pull --dialect=postgresql --schema=src/schema.ts --tablesFilter='user*' --extensionsFilters=postgis url=postgresql://user:password@host:port/dbname ![](@/assets/gifs/introspect_mysql.gif) Source: https://orm.drizzle.team/docs/drizzle-kit-push import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import Npx from "@mdx/Npx.astro"; import SchemaFilePaths from "@mdx/SchemaFilePaths.mdx"; import Drivers from "@mdx/Drivers.mdx" import Dialects from "@mdx/Dialects.mdx" import DriversExamples from "@mdx/DriversExamples.mdx" # `drizzle-kit push` - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file) docs `drizzle-kit push` lets you literally push your schema and subsequent schema changes directly to the database while omitting SQL files generation, it's designed to cover [code first](/docs/migrations) approach of Drizzle migrations. When you run Drizzle Kit `push` command it will: 1. Read through your Drizzle schema file(s) and compose a json snapshot of your schema 2. Pull(introspect) database schema 3. Based on differences between those two it will generate SQL migrations 4. Apply SQL migrations to the database
```typescript filename="src/schema.ts" import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), }; ``` ``` ┌─────────────────────┐ │ ~ drizzle-kit push │ └─┬───────────────────┘ │ ┌──────────────────────────┐ └ Pull current datatabase schema ---------> │ │ │ │ ┌ Generate alternations based on diff <---- │ DATABASE │ │ │ │ └ Apply migrations to the database -------> │ │ │ └──────────────────────────┘ │ ┌────────────────────────────────────┴────────────────┐ create table users(id serial primary key, name text); ```
It's the best approach for rapid prototyping and we've seen dozens of teams and solo developers successfully using it as a primary migrations flow in their production applications. It pairs exceptionally well with blue/green deployment strategy and serverless databases like [Planetscale](https://planetscale.com/), [Neon](https://neon.tech/), [Turso](https://turso.tech/drizzle) and others.


`drizzle-kit push` requires you to specify `dialect`, path to the `schema` file(s) and either database connection `url` or `user:password@host:port/db` params, you can provide them either via [drizzle.config.ts](/docs/drizzle-config-file) config file or via CLI options:
```ts // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", dbCredentials: { url: "postgresql://user:password@host:port/dbname", }, }); ``` ```shell npx drizzle-kit push ```
```shell npx drizzle-kit push --dialect=postgresql --schema=./src/schema.ts --url=postgresql://user:password@host:port/dbname ```
### Schema files path You can have a single `schema.ts` file or as many schema files as you want spread out across the project. Drizzle Kit requires you to specify path(s) to them as a [glob](https://www.digitalocean.com/community/tools/glob?comments=true&glob=/**/*.js&matches=false&tests=//%20This%20will%20match%20as%20it%20ends%20with%20'.js'&tests=/hello/world.js&tests=//%20This%20won't%20match!&tests=/test/some/globs) via `schema` configuration option. ### Multiple configuration files in one project You can have multiple config files in the project, it's very useful when you have multiple database stages or multiple databases or different databases on the same project: drizzle-kit push --config=drizzle-dev.config.ts drizzle-kit push --config=drizzle-prod.config.ts ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ### Specifying database driver **Expo SQLite** and **OP SQLite** are on-device(per-user) databases, there's no way to `push` migrations there.
For embedded databases Drizzle provides **embedded migrations** - check out our [get started](/docs/get-started/expo-new) guide.
Drizzle Kit does not come with a pre-bundled database driver, it will automatically pick available database driver from your current project based on the `dialect` - [see discussion](https://github.com/drizzle-team/drizzle-orm/discussions/2203). Mostly all drivers of the same dialect share the same set of connection params, as for exceptions like `aws-data-api`, `pglight` and `d1-http` - you will have to explicitly specify `driver` param. ### Including tables, schemas and extensions `drizzle-kit push` will by default manage all tables in `public` schema. You can configure list of tables, schemas and extensions via `tablesFilters`, `schemaFilter` and `extensionFilters` options. | | | | :------------------ | :-------------------------------------------------------------------------------------------- | | `tablesFilter` | `glob` based table names filter, e.g. `["users", "user_info"]` or `"user*"`. Default is `"*"` | | `schemaFilter` | Schema names filter, e.g. `["public", "drizzle"]`. Default is `["public"]` | | `extensionsFilters` | List of installed database extensions, e.g. `["postgis"]`. Default is `[]` |
Let's configure drizzle-kit to only operate with **all tables** in **public** schema and let drizzle-kit know that there's a **postgis** extension installed, which creates it's own tables in public schema, so drizzle can ignore them.
```ts filename="drizzle.config.ts" {9-11} import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", dbCredentials: { url: "postgresql://user:password@host:port/dbname", }, extensionsFilters: ["postgis"], schemaFilter: ["public"], tablesFilter: ["*"], }); ``` ```shell npx drizzle-kit push ```
### Extended list of configurations `drizzle-kit push` has a list of cli-only options | | | | :-------- | :--------------------------------------------------- | | `verbose` | print all SQL statements prior to execution | | `strict` | always ask for approval before executing SQL statements | | `force` | auto-accept all data-loss statements |
drizzle-kit push --strict --verbose --force


We recommend configuring `drizzle-kit` through [drizzle.config.ts](/docs/drizzle-config-file) file, yet you can provide all configuration options through CLI if necessary, e.g. in CI/CD pipelines, etc. | | | | | :------------------ | :--------- | :------------------------------------------------------------------------ | | `dialect` | `required` | Database dialect, one of | | `schema` | `required` | Path to typescript schema file(s) or folder(s) with multiple schema files | | `driver` | | Drivers exceptions | | `tablesFilter` | | Table name filter | | `schemaFilter` | | Schema name filter. Default: `["public"]` | | `extensionsFilters` | | Database extensions internal database filters | | `url` | | Database connection string | | `user` | | Database user | | `password` | | Database password | | `host` | | Host | | `port` | | Port | | `database` | | Database name | | `config` | | Config file path, default=`drizzle.config.ts` | drizzle-kit push dialect=postgresql schema=src/schema.ts url=postgresql://user:password@host:port/dbname drizzle-kit push dialect=postgresql schema=src/schema.ts driver=pglite url=database/ drizzle-kit push dialect=postgresql schema=src/schema.ts --tablesFilter='user*' --extensionsFilters=postgis url=postgresql://user:password@host:port/dbname ### Extended example Let's declare drizzle schema in the project and push it to the database via `drizzle-kit push` command ```plaintext 📦 ├ 📂 src │ ├ 📜 schema.ts │ └ 📜 index.ts ├ 📜 drizzle.config.ts └ … ``` ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", dbCredentials: { url: "postgresql://user:password@host:port/dbname" }, }); ``` ```ts import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), }) ``` Now let's run ```shell npx drizzle-kit push ``` it will pull existing(empty) schema from the database and generate SQL migration and apply it under the hood ```sql CREATE TABLE "users"( id serial primary key, name text, ) ``` DONE ✅ Source: https://orm.drizzle.team/docs/drizzle-kit-studio import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from "@mdx/Npm.astro"; import Npx from "@mdx/Npx.astro"; # `drizzle-kit studio` - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file) - Drizzle Studio, our database browser - [read here](/drizzle-studio/overview) `drizzle-kit studio` command spins up a server for [Drizzle Studio](/drizzle-studio/overview) hosted on [local.drizzle.studio](https://local.drizzle.studio). It requires you to specify database connection credentials via [drizzle.config.ts](/docs/drizzle-config-file) config file. By default it will start a Drizzle Studio server on `127.0.0.1:4983`
```ts {6} // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dbCredentials: { url: "postgresql://user:password@host:port/dbname" }, }); ``` ```shell npx drizzle-kit migrate ```
### Configuring `host` and `port` By default Drizzle Studio server starts on `127.0.0.1:4983`, you can config `host` and `port` via CLI options drizzle-kit studio --port=3000 drizzle-kit studio --host=0.0.0.0 drizzle-kit studio --host=0.0.0.0 --port=3000 ### Logging You can enable logging of every SQL statement by providing `verbose` flag drizzle-kit studio --verbose ### Safari and Brave support Safari and Brave block access to localhost by default. You need to install [mkcert](https://github.com/FiloSottile/mkcert) and generate self-signed certificate: 1. Follow the mkcert [installation steps](https://github.com/FiloSottile/mkcert#installation) 2. Run `mkcert -install` 3. Restart your `drizzle-kit studio` ### Embeddable version of Drizzle Studio While hosted version of Drizzle Studio for local development is free forever and meant to just enrich Drizzle ecosystem, we have a B2B offering of an embeddable version of Drizzle Studio for businesses. **Drizzle Studio component** - is a pre-bundled framework agnostic web component of Drizzle Studio which you can embed into your UI `React` `Vue` `Svelte` `VanillaJS` etc. That is an extremely powerful UI element that can elevate your offering if you provide Database as a SaaS or a data centric SaaS solutions based on SQL or for private non-customer facing in-house usage. Database platforms using Drizzle Studio: - [Turso](https://turso.tech/), our first customers since Oct 2023! - [Neon](https://neon.tech/), [launch post](https://neon.tech/docs/changelog/2024-05-24) - [Hydra](https://www.hydra.so/) Data centric platforms using Drizzle Studio: - [Nuxt Hub](https://hub.nuxt.com/), Sébastien Chopin's [launch post](https://x.com/Atinux/status/1768663789832929520) - [Deco.cx](https://deco.cx/) You can read a detailed overview [here](https://www.npmjs.com/package/@drizzle-team/studio) and if you're interested - hit us in DMs on [Twitter](https://x.com/drizzleorm) or in [Discord #drizzle-studio](https://driz.link/discord) channel. ### Drizzle Studio chrome extension Drizzle Studio [chrome extension](https://chromewebstore.google.com/detail/drizzle-studio/mjkojjodijpaneehkgmeckeljgkimnmd) lets you browse your [PlanetScale](https://planetscale.com), [Cloudflare](https://developers.cloudflare.com/d1/) and [Vercel Postgres](https://vercel.com/docs/storage/vercel-postgres) serverless databases directly in their vendor admin panels! ### Limitations Our hosted version Drizzle Studio is meant to be used for local development and not meant to be used on remote (VPS, etc). If you want to deploy Drizzle Studio to your VPS - we have an alfa version of Drizzle Studio Gateway, hit us in DMs on [Twitter](https://x.com/drizzleorm) or in [Discord #drizzle-studio](https://driz.link/discord) channel. ### Is it open source? No. Drizzle ORM and Drizzle Kit are fully open sourced, while Studio is not. Drizzle Studio for local development is free to use forever to enrich Drizzle ecosystem, open sourcing one would've break our ability to provide B2B offerings and monetise it, unfortunately. Source: https://orm.drizzle.team/docs/drizzle-kit-up import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import Npx from "@mdx/Npx.astro"; # `drizzle-kit up` - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file) - `drizzle-kit generate` command - [read here](/docs/drizzle-kit-generate) `drizzle-kit up` command lets you upgrade drizzle schema snapshots to a newer version. It's required whenever we introduce breaking changes to the json snapshots of the schema and upgrade the internal version.


`drizzle-kit up` command requires you to specify both `dialect` and database connection credentials, you can provide them either via [drizzle.config.ts](/docs/drizzle-config-file) config file or via CLI options
```ts {5,8} // drizzle.config.ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", }); ``` ```shell npx drizzle-kit up ```
```shell npx drizzle-kit up --dialect=postgresql ```
### Multiple configuration files in one project You can have multiple config files in the project, it's very useful when you have multiple database stages or multiple databases on the same project: drizzle-kit migrate --config=drizzle-dev.config.ts drizzle-kit migrate --config=drizzle-prod.config.ts ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ### Extended list of configurations We recommend configuring `drizzle-kit` through [drizzle.config.ts](/docs/drizzle-config-file) file, yet you can provide all configuration options through CLI if necessary, e.g. in CI/CD pipelines, etc. | | | | | :-------- | :--------- | :---------------------------------------------------------------------- | | `dialect` | `required` | Database dialect you are using. Can be `postgresql`,`mysql` or `sqlite` | | `out` | | migrations folder, default=`./drizzle` | | `config` | | config file path, default=`drizzle.config.ts` |
drizzle-kit up --dialect=postgresql drizzle-kit up --dialect=postgresql --out=./migrations-folder ![](@/assets/gifs/up_mysql.gif) Source: https://orm.drizzle.team/docs/dynamic-query-building import Callout from '@mdx/Callout.astro'; # Dynamic query building By default, as all the query builders in Drizzle try to conform to SQL as much as possible, you can only invoke most of the methods once. For example, in a `SELECT` statement there might only be one `WHERE` clause, so you can only invoke `.where()` once: ```ts const query = db .select() .from(users) .where(eq(users.id, 1)) .where(eq(users.name, 'John')); // ❌ Type error - where() can only be invoked once ``` In the previous ORM versions, when such restrictions weren't implemented, this example in particular was a source of confusion for many users, as they expected the query builder to "merge" multiple `.where()` calls into a single condition. This behavior is useful for conventional query building, i.e. when you create the whole query at once. However, it becomes a problem when you want to build a query dynamically, i.e. if you have a shared function that takes a query builder and enhances it. To solve this problem, Drizzle provides a special 'dynamic' mode for query builders, which removes the restriction of invoking methods only once. To enable it, you need to call `.$dynamic()` on a query builder. Let's see how it works by implementing a simple `withPagination` function that adds `LIMIT` and `OFFSET` clauses to a query based on the provided page number and an optional page size: ```ts function withPagination( qb: T, page: number = 1, pageSize: number = 10, ) { return qb.limit(pageSize).offset((page - 1) * pageSize); } const query = db.select().from(users).where(eq(users.id, 1)); withPagination(query, 1); // ❌ Type error - the query builder is not in dynamic mode const dynamicQuery = query.$dynamic(); withPagination(dynamicQuery, 1); // ✅ OK ``` Note that the `withPagination` function is generic, which allows you to modify the result type of the query builder inside it, for example by adding a join: ```ts function withFriends(qb: T) { return qb.leftJoin(friends, eq(friends.userId, users.id)); } let query = db.select().from(users).where(eq(users.id, 1)).$dynamic(); query = withFriends(query); ``` This is possible, because `PgSelect` and other similar types are specifically designed to be used in dynamic query building. They can only be used in dynamic mode. Here is the list of all types that can be used as generic parameters in dynamic query building: {
Dialect Type
Query Select Insert Update Delete
Postgres PgSelect PgInsert PgUpdate PgDelete
PgSelectQueryBuilder
MySQL MySqlSelect MySqlInsert MySqlUpdate MySqlDelete
MySqlSelectQueryBuilder
SQLite SQLiteSelect SQLiteInsert SQLiteUpdate SQLiteDelete
SQLiteSelectQueryBuilder
} The `...QueryBuilder` types are for usage with [standalone query builder instances](/docs/goodies#standalone-query-builder). DB query builders are subclasses of them, so you can use them as well. ```ts import { QueryBuilder } from 'drizzle-orm/pg-core'; function withFriends(qb: T) { return qb.leftJoin(friends, eq(friends.userId, users.id)); } const qb = new QueryBuilder(); let query = qb.select().from(users).where(eq(users.id, 1)).$dynamic(); query = withFriends(query); ``` Source: https://orm.drizzle.team/docs/eslint-plugin import Tabs from '@mdx/Tabs.astro'; import Tab from '@mdx/Tab.astro'; import Npm from '@mdx/Npm.astro'; # ESLint Drizzle Plugin For cases where it's impossible to perform type checks for specific scenarios, or where it's possible but error messages would be challenging to understand, we've decided to create an ESLint package with recommended rules. This package aims to assist developers in handling crucial scenarios during development ## Install eslint-plugin-drizzle @typescript-eslint/eslint-plugin @typescript-eslint/parser ## Usage **`.eslintrc.yml` example** ```yml root: true parser: '@typescript-eslint/parser' parserOptions: project: './tsconfig.json' plugins: - drizzle rules: 'drizzle/enforce-delete-with-where': "error" 'drizzle/enforce-update-with-where': "error" ``` **All config** This plugin exports an `all` that makes use of all rules (except for deprecated ones). ```yml root: true extends: - "plugin:drizzle/all" parser: '@typescript-eslint/parser' parserOptions: project: './tsconfig.json' plugins: - drizzle ``` **Recommended config** At the moment, `all` is equivalent to `recommended` ```yml root: true extends: - "plugin:drizzle/recommended" parser: '@typescript-eslint/parser' parserOptions: project: './tsconfig.json' plugins: - drizzle ``` ## Rules ### **enforce-delete-with-where** Enforce using `delete` with the`.where()` clause in the `.delete()` statement. Most of the time, you don't need to delete all rows in the table and require some kind of `WHERE` statements. Optionally, you can define a `drizzleObjectName` in the plugin options that accept a `string` or `string[]`. This is useful when you have objects or classes with a delete method that's not from Drizzle. Such a `delete` method will trigger the ESLint rule. To avoid that, you can define the name of the Drizzle object that you use in your codebase (like db) so that the rule would only trigger if the delete method comes from this object: Example, config 1: ```yml rules: 'drizzle/enforce-delete-with-where': "error" ``` ```ts class MyClass { public delete() { return {} } } const myClassObj = new MyClass(); // ---> Will be triggered by ESLint Rule myClassObj.delete() const db = drizzle(...) // ---> Will be triggered by ESLint Rule db.delete() ``` Example, config 2: ```yml rules: 'drizzle/enforce-delete-with-where': - "error" - "drizzleObjectName": - "db" ``` ```ts class MyClass { public delete() { return {} } } const myClassObj = new MyClass(); // ---> Will NOT be triggered by ESLint Rule myClassObj.delete() const db = drizzle(...) // ---> Will be triggered by ESLint Rule db.delete() ``` ### **enforce-update-with-where**: Enforce using `update` with the`.where()` clause in the `.update()` statement. Most of the time, you don't need to update all rows in the table and require some kind of `WHERE` statements. Optionally, you can define a `drizzleObjectName` in the plugin options that accept a `string` or `string[]`. This is useful when you have objects or classes with a delete method that's not from Drizzle. Such as `update` method will trigger the ESLint rule. To avoid that, you can define the name of the Drizzle object that you use in your codebase (like db) so that the rule would only trigger if the delete method comes from this object: Example, config 1: ```yml rules: 'drizzle/enforce-update-with-where': "error" ``` ```ts class MyClass { public update() { return {} } } const myClassObj = new MyClass(); // ---> Will be triggered by ESLint Rule myClassObj.update() const db = drizzle(...) // ---> Will be triggered by ESLint Rule db.update() ``` Example, config 2: ```yml rules: 'drizzle/enforce-update-with-where': - "error" - "drizzleObjectName": - "db" ``` ```ts class MyClass { public update() { return {} } } const myClassObj = new MyClass(); // ---> Will NOT be triggered by ESLint Rule myClassObj.update() const db = drizzle(...) // ---> Will be triggered by ESLint Rule db.update() ``` Source: https://orm.drizzle.team/docs/extensions/mysql import Callout from '@mdx/Callout.astro'; Currently, there are no MySQL extensions natively supported by Drizzle. Once those are added, we will have them here! Source: https://orm.drizzle.team/docs/extensions/pg import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; ### `pg_vector` There is no specific code to create an extension inside the Drizzle schema. We assume that if you are using vector types, indexes, and queries, you have a PostgreSQL database with the pg_vector extension installed. [`pg_vector`](https://github.com/pgvector/pgvector) is open-source vector similarity search for Postgres Store your vectors with the rest of your data. Supports: - exact and approximate nearest neighbor search - single-precision, half-precision, binary, and sparse vectors - L2 distance, inner product, cosine distance, L1 distance, Hamming distance, and Jaccard distance #### Column Types **`vector`** Store your vectors with the rest of your data For more info please refer to the official pg_vector docs **[docs.](https://github.com/pgvector/pgvector)**
```ts const table = pgTable('table', { embedding: vector({ dimensions: 3 }) }) ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "embedding" vector(3) ); ```
#### Indexes You can now specify indexes for `pg_vector` and utilize `pg_vector` functions for querying, ordering, etc. Let's take a few examples of `pg_vector` indexes from the `pg_vector` docs and translate them to Drizzle #### L2 distance, Inner product and Cosine distance ```ts // CREATE INDEX ON items USING hnsw (embedding vector_l2_ops); // CREATE INDEX ON items USING hnsw (embedding vector_ip_ops); // CREATE INDEX ON items USING hnsw (embedding vector_cosine_ops); const table = pgTable('items', { embedding: vector({ dimensions: 3 }) }, (table) => [ index('l2_index').using('hnsw', table.embedding.op('vector_l2_ops')) index('ip_index').using('hnsw', table.embedding.op('vector_ip_ops')) index('cosine_index').using('hnsw', table.embedding.op('vector_cosine_ops')) ]) ``` #### L1 distance, Hamming distance and Jaccard distance - added in pg_vector 0.7.0 version ```ts // CREATE INDEX ON items USING hnsw (embedding vector_l1_ops); // CREATE INDEX ON items USING hnsw (embedding bit_hamming_ops); // CREATE INDEX ON items USING hnsw (embedding bit_jaccard_ops); const table = pgTable('table', { embedding: vector({ dimensions: 3 }) }, (table) => [ index('l1_index').using('hnsw', table.embedding.op('vector_l1_ops')) index('hamming_index').using('hnsw', table.embedding.op('bit_hamming_ops')) index('bit_jaccard_index').using('hnsw', table.embedding.op('bit_jaccard_ops')) ]) ``` #### Helper Functions For queries, you can use predefined functions for vectors or create custom ones using the SQL template operator. You can also use the following helpers: ```ts import { l2Distance, l1Distance, innerProduct, cosineDistance, hammingDistance, jaccardDistance } from 'drizzle-orm' l2Distance(table.column, [3, 1, 2]) // table.column <-> '[3, 1, 2]' l1Distance(table.column, [3, 1, 2]) // table.column <+> '[3, 1, 2]' innerProduct(table.column, [3, 1, 2]) // table.column <#> '[3, 1, 2]' cosineDistance(table.column, [3, 1, 2]) // table.column <=> '[3, 1, 2]' hammingDistance(table.column, '101') // table.column <~> '101' jaccardDistance(table.column, '101') // table.column <%> '101' ``` If `pg_vector` has some other functions to use, you can replicate implementation from existing one we have. Here is how it can be done ```ts export function l2Distance( column: SQLWrapper | AnyColumn, value: number[] | string[] | TypedQueryBuilder | string, ): SQL { if (is(value, TypedQueryBuilder) || typeof value === 'string') { return sql`${column} <-> ${value}`; } return sql`${column} <-> ${JSON.stringify(value)}`; } ``` Name it as you wish and change the operator. This example allows for a numbers array, strings array, string, or even a select query. Feel free to create any other type you want or even contribute and submit a PR #### Examples Let's take a few examples of `pg_vector` queries from the `pg_vector` docs and translate them to Drizzle ```ts import { l2Distance } from 'drizzle-orm'; // SELECT * FROM items ORDER BY embedding <-> '[3,1,2]' LIMIT 5; db.select().from(items).orderBy(l2Distance(items.embedding, [3,1,2])) // SELECT embedding <-> '[3,1,2]' AS distance FROM items; db.select({ distance: l2Distance(items.embedding, [3,1,2]) }) // SELECT * FROM items ORDER BY embedding <-> (SELECT embedding FROM items WHERE id = 1) LIMIT 5; const subquery = db.select({ embedding: items.embedding }).from(items).where(eq(items.id, 1)); db.select().from(items).orderBy(l2Distance(items.embedding, subquery)).limit(5) // SELECT (embedding <#> '[3,1,2]') * -1 AS inner_product FROM items; db.select({ innerProduct: sql`(${maxInnerProduct(items.embedding, [3,1,2])}) * -1` }).from(items) // and more! ``` ### `postgis` There is no specific code to create an extension inside the Drizzle schema. We assume that if you are using postgis types, indexes, and queries, you have a PostgreSQL database with the `postgis` extension installed. As [PostGIS](https://postgis.net/) website mentions: > PostGIS extends the capabilities of the PostgreSQL relational database by adding support for storing, indexing, and querying geospatial data. If you are using the `introspect` or `push` commands with the PostGIS extension and don't want PostGIS tables to be included, you can use [`extensionsFilters`](/docs/drizzle-config-file#extensionsfilters) to ignore all the PostGIS tables #### Column Types **`geometry`** Store your geometry data with the rest of your data For more info please refer to the official PostGIS docs **[docs.](https://postgis.net/workshops/postgis-intro/geometries.html)** ```ts const items = pgTable('items', { geo: geometry('geo', { type: 'point' }), geoObj: geometry('geo_obj', { type: 'point', mode: 'xy' }), geoSrid: geometry('geo_options', { type: 'point', mode: 'xy', srid: 4000 }), }); ``` **mode** Type `geometry` has 2 modes for mappings from the database: `tuple` and `xy`. - `tuple` will be accepted for insert and mapped on select to a tuple. So, the database geometry will be typed as [1,2] with drizzle. - `xy` will be accepted for insert and mapped on select to an object with x, y coordinates. So, the database geometry will be typed as `{ x: 1, y: 2 }` with drizzle **type** The current release has a predefined type: `point`, which is the `geometry(Point)` type in the PostgreSQL PostGIS extension. You can specify any string there if you want to use some other type #### Indexes With the available Drizzle indexes API, you should be able to write any indexes for PostGIS **Examples** ```ts // CREATE INDEX custom_idx ON table USING GIST (geom); const table = pgTable('table', { geo: geometry({ type: 'point' }), }, (table) => [ index('custom_idx').using('gist', table.geo) ]) ``` Source: https://orm.drizzle.team/docs/extensions/singlestore import Callout from '@mdx/Callout.astro'; Currently, there are no SingleStore extensions natively supported by Drizzle. Once those are added, we will have them here! Source: https://orm.drizzle.team/docs/extensions/sqlite import Callout from '@mdx/Callout.astro'; Currently, there are no SQLite extensions natively supported by Drizzle. Once those are added, we will have them here! Source: https://orm.drizzle.team/docs/faq import Callout from '@mdx/Callout.astro'; # FAQ & Troubleshooting ## **Should I use `generate` or `push`?** Those are logically 2 different commands. `generate` is used to create an sql file together with additional information needed for `drizzle-kit` (or any other migration tool). After generating those migrations, they won't be applied to a database. You need to do it in the next step. You can read more about it **[here](/docs/migrations)** On the other hand, `push` doesn't need any migrations to be generated. It will simply sync your schema with the database schema. Please be careful when using it; we recommend it only for local development and local databases. To read more about it, check out **[`drizzle-kit push`](/docs/drizzle-kit-push)** ## How `push` and `generate` works for PostgreSQL indexes ### Limitations 1. **You should specify a name for your index manually if you have an index on at least one expression** Example ```ts index().on(table.id, table.email) // will work well and name will be autogeneretaed index('my_name').on(table.id, table.email) // will work well // but index().on(sql`lower(${table.email})`) // error index('my_name').on(sql`lower(${table.email})`) // will work well ``` 2. **Push won't generate statements if these fields(list below) were changed in an existing index:** - expressions inside `.on()` and `.using()` - `.where()` statements - operator classes `.op()` on columns If you are using `push` workflows and want to change these fields in the index, you would need to: 1. Comment out the index 2. Push 3. Uncomment the index and change those fields 4. Push again For the `generate` command, `drizzle-kit` will be triggered by any changes in the index for any property in the new drizzle indexes API, so there are no limitations here. Source: https://orm.drizzle.team/docs/generated-columns import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Callout from '@mdx/Callout.astro'; # Generated Columns To use this feature you would need to have `drizzle-orm@0.32.0` or higher and `drizzle-kit@0.23.0` or higher Generated columns in SQL are a feature that allows you to create columns in a table whose values are automatically computed based on expressions involving other columns within the same table. This can help ensure data consistency, simplify database design, and improve query performance. There are two types of generated columns: 1. Virtual (or non-persistent) Generated Columns: These columns are computed dynamically whenever they are queried. They do not occupy storage space in the database. 2. Stored (or persistent) Generated Columns: These columns are computed when a row is inserted or updated and their values are stored in the database. This allows them to be indexed and can improve query performance since the values do not need to be recomputed for each query. Generated columns can be especially useful for: - Deriving new data from existing columns - Automating calculations to avoid manual updates - Enforcing data integrity and consistency - Simplifying application logic by keeping complex calculations within the database schema The implementation and usage of generated columns can vary significantly across different SQL databases. PostgreSQL, MySQL, and SQLite each have unique features, capabilities, and limitations when it comes to generated columns. In this section, we will explore these differences in detail to help you understand how to best utilize generated columns in each database system. #### Database side **Types**: `STORED` only **How It Works** - Automatically computes values based on other columns during insert or update. **Capabilities** - Simplifies data access by precomputing complex expressions. - Enhances query performance with index support on generated columns. **Limitations** - Cannot specify default values. - Expressions cannot reference other generated columns or include subqueries. - Schema changes required to modify generated column expressions. - Cannot directly use in primary keys, foreign keys, or unique constraints For more info, please check [PostgreSQL](https://www.postgresql.org/docs/current/ddl-generated-columns.html) docs #### Drizzle side In Drizzle you can specify `.generatedAlwaysAs()` function on any column type and add a supported sql query, that will generate this column data for you. #### Features This function can accept generated expression in 3 ways: **`string`** ```ts export const test = pgTable("test", { generatedName: text("gen_name").generatedAlwaysAs(`hello world!`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "test" ( "gen_name" text GENERATED ALWAYS AS (hello world!) STORED ); ``` **`sql`** tag - if you want drizzle to escape some values for you ```ts export const test = pgTable("test", { generatedName: text("gen_name").generatedAlwaysAs(sql`hello "world"!`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "test" ( "gen_name" text GENERATED ALWAYS AS (hello "world"!) STORED, ); ``` **`callback`** - if you need to reference columns from a table ```ts export const test = pgTable("test", { name: text("first_name"), generatedName: text("gen_name").generatedAlwaysAs( (): SQL => sql`hi, ${test.name}!` ), }); ``` ```sql CREATE TABLE IF NOT EXISTS "test" ( "first_name" text, "gen_name" text GENERATED ALWAYS AS (hi, "test"."first_name"!) STORED, ); ``` **Example** generated columns with full-text search ```typescript copy {17-19} import { SQL, sql } from "drizzle-orm"; import { customType, index, integer, pgTable, text } from "drizzle-orm/pg-core"; const tsVector = customType<{ data: string }>({ dataType() { return "tsvector"; }, }); export const test = pgTable( "test", { id: integer("id").primaryKey().generatedAlwaysAsIdentity(), content: text("content"), contentSearch: tsVector("content_search", { dimensions: 3, }).generatedAlwaysAs( (): SQL => sql`to_tsvector('english', ${test.content})` ), }, (t) => [ index("idx_content_search").using("gin", t.contentSearch) ] ); ``` ```sql {4} CREATE TABLE IF NOT EXISTS "test" ( "id" integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY (sequence name "test_id_seq" INCREMENT BY 1 MINVALUE 1 MAXVALUE 2147483647 START WITH 1 CACHE 1), "content" text, "content_search" "tsvector" GENERATED ALWAYS AS (to_tsvector('english', "test"."content")) STORED ); --> statement-breakpoint CREATE INDEX IF NOT EXISTS "idx_content_search" ON "test" USING gin ("content_search"); ``` #### Database side **Types**: `STORED`, `VIRTUAL` **How It Works** - Defined with an expression in the table schema. - Virtual columns are computed during read operations. - Stored columns are computed during write operations and stored. **Capabilities** - Used in SELECT, INSERT, UPDATE, and DELETE statements. - Can be indexed, both virtual and stored. - Can specify NOT NULL and other constraints. **Limitations** - Cannot directly insert or update values in a generated column For more info, please check [MySQL Alter Generated](https://dev.mysql.com/doc/refman/8.4/en/alter-table-generated-columns.html) docs and [MySQL create generated](https://dev.mysql.com/doc/refman/8.4/en/create-table-generated-columns.html) docs #### Drizzle side #### Features **`string`** ```ts export const test = mysqlTable("test", { generatedName: text("gen_name").generatedAlwaysAs(`hello world!`), }); ``` ```sql CREATE TABLE `test` ( `gen_name` text GENERATED ALWAYS AS (hello world!) VIRTUAL ); ``` **`sql`** tag - if you want drizzle to escape some values for you ```ts export const test = mysqlTable("test", { generatedName: text("gen_name").generatedAlwaysAs(sql`hello "world"!`), }); ``` ```sql CREATE TABLE `test` ( `gen_name` text GENERATED ALWAYS AS (hello "world"!) VIRTUAL, ); ``` **`callback`** - if you need to reference columns from a table ```ts export const test = mysqlTable("test", { name: text("first_name"), generatedName: text("gen_name").generatedAlwaysAs( (): SQL => sql`hi, ${test.name}!` ), }); ``` ```sql CREATE TABLE `test` ( `first_name` text, `gen_name` text GENERATED ALWAYS AS (hi, `test`.`first_name`!) VIRTUAL, ); ``` #### Limitations Drizzle Kit will also have limitations for `push` command: 1. You can't change the generated constraint expression and type using `push`. Drizzle-kit will ignore this change. To make it work, you would need to `drop the column`, `push`, and then `add a column with a new expression`. This was done due to the complex mapping from the database side, where the schema expression will be modified on the database side and, on introspection, we will get a different string. We can't be sure if you changed this expression or if it was changed and formatted by the database. As long as these are generated columns and `push` is mostly used for prototyping on a local database, it should be fast to `drop` and `create` generated columns. Since these columns are `generated`, all the data will be restored 2. `generate` should have no limitations ```typescript copy export const users = mysqlTable("users", { id: int("id"), id2: int("id2"), name: text("name"), storedGenerated: text("stored_gen").generatedAlwaysAs( (): SQL => sql`${users.name} || 'hello'`, { mode: "stored" } ), virtualGenerated: text("virtual_gen").generatedAlwaysAs( (): SQL => sql`${users.name} || 'hello'`, { mode: "virtual" } ), }) ``` ```sql CREATE TABLE `users` ( `id` int, `id2` int, `name` text, `stored_gen` text GENERATED ALWAYS AS (`users`.`name` || 'hello') STORED, `virtual_gen` text GENERATED ALWAYS AS (`users`.`name` || 'hello') VIRTUAL ); ``` #### Database side **Types**: `STORED`, `VIRTUAL` **How It Works** - Defined with an expression in the table schema. - Virtual columns are computed during read operations. - Stored columns are computed during write operations and stored. **Capabilities** - Used in SELECT, INSERT, UPDATE, and DELETE statements. - Can be indexed, both virtual and stored. - Can specify NOT NULL and other constraints. **Limitations** - Cannot directly insert or update values in a generated column For more info, please check [SQLite](https://www.sqlite.org/gencol.html) docs #### Drizzle side #### Features **`string`** ```ts export const test = sqliteTable("test", { generatedName: text("gen_name").generatedAlwaysAs(`hello world!`), }); ``` ```sql CREATE TABLE `test` ( `gen_name` text GENERATED ALWAYS AS (hello world!) VIRTUAL ); ``` **`sql`** tag - if you want drizzle to escape some values for you ```ts export const test = sqliteTable("test", { generatedName: text("gen_name").generatedAlwaysAs(sql`hello "world"!`), }); ``` ```sql CREATE TABLE `test` ( `gen_name` text GENERATED ALWAYS AS (hello "world"!) VIRTUAL, ); ``` **`callback`** - if you need to reference columns from a table ```ts export const test = sqliteTable("test", { name: text("first_name"), generatedName: text("gen_name").generatedAlwaysAs( (): SQL => sql`hi, ${test.name}!` ), }); ``` ```sql CREATE TABLE `test` ( `first_name` text, `gen_name` text GENERATED ALWAYS AS (hi, "first_name"!) VIRTUAL, ); ``` #### Limitations Drizzle Kit will also have limitations for `push` and `generate` command: 1. You can't change the generated constraint expression with the stored type in an existing table. You would need to delete this table and create it again. This is due to SQLite limitations for such actions. We will handle this case in future releases (it will involve the creation of a new table with data migration). 2. You can't add a `stored` generated expression to an existing column for the same reason as above. However, you can add a `virtual` expression to an existing column. 3. You can't change a `stored` generated expression in an existing column for the same reason as above. However, you can change a `virtual` expression. 4. You can't change the generated constraint type from `virtual` to `stored` for the same reason as above. However, you can change from `stored` to `virtual`. ```typescript copy export const users = sqliteTable("users", { id: int("id"), name: text("name"), storedGenerated: text("stored_gen").generatedAlwaysAs( (): SQL => sql`${users.name} || 'hello'`, { mode: "stored" } ), virtualGenerated: text("virtual_gen").generatedAlwaysAs( (): SQL => sql`${users.name} || 'hello'`, { mode: "virtual" } ), }); ``` ```sql CREATE TABLE `users` ( `id` integer, `name` text, `stored_gen` text GENERATED ALWAYS AS ("name" || 'hello') STORED, `virtual_gen` text GENERATED ALWAYS AS ("name" || 'hello') VIRTUAL ); ``` Work in Progress Source: https://orm.drizzle.team/docs/get-started-gel import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> PostgreSQL - Database [connection basics](/docs/connect-overview) with Drizzle - gel-js [basics](https://github.com/geldata/gel-js) Drizzle has native support for Gel connections with the `gel-js` client. #### Step 1 - Install packages drizzle-orm gel -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy // Make sure to install the 'gel' package import { drizzle } from 'drizzle-orm/gel'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ``` ```typescript copy // Make sure to install the 'gel' package import { drizzle } from "drizzle-orm/gel"; // You can specify any property from the gel connection options const db = drizzle({ connection: { dsn: process.env.DATABASE_URL, tlsSecurity: "default", }, }); const result = await db.execute("select 1"); ``` If you need to provide your existing driver: ```typescript copy // Make sure to install the 'gel' package import { drizzle } from "drizzle-orm/gel"; import { createClient } from "gel"; const gelClient = createClient(); const db = drizzle({ client: gelClient }); const result = await db.execute('select 1'); ``` #### What's next? Source: https://orm.drizzle.team/docs/get-started-mysql import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> MySQL To use Drizzle with a MySQL database, you should use the `mysql2` driver According to the **[official website](https://github.com/sidorares/node-mysql2)**, `mysql2` is a MySQL client for Node.js with focus on performance. Drizzle ORM natively supports `mysql2` with `drizzle-orm/mysql2` package. #### Step 1 - Install packages drizzle-orm mysql2 -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy import { drizzle } from "drizzle-orm/mysql2"; const db = drizzle(process.env.DATABASE_URL); const response = await db.select().from(...) ``` ```typescript copy import { drizzle } from "drizzle-orm/mysql2"; // You can specify any property from the mysql2 connection options const db = drizzle({ connection:{ uri: process.env.DATABASE_URL }}); const response = await db.select().from(...) ``` If you need to provide your existing driver: ```typescript copy import { drizzle } from "drizzle-orm/mysql2"; import mysql from "mysql2/promise"; const connection = await mysql.createConnection({ host: "host", user: "user", database: "database", ... }); const db = drizzle({ client: connection }); ``` ```typescript copy import { drizzle } from "drizzle-orm/mysql2"; import mysql from "mysql2/promise"; const poolConnection = mysql.createPool({ host: "host", user: "user", database: "database", ... }); const db = drizzle({ client: poolConnection }); ``` For the built in `migrate` function with DDL migrations we and drivers strongly encourage you to use single `client` connection. For querying purposes feel free to use either `client` or `pool` based on your business demands. #### What's next? Source: https://orm.drizzle.team/docs/get-started-postgresql import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> PostgreSQL - Database [connection basics](/docs/connect-overview) with Drizzle - node-postgres [basics](https://node-postgres.com/) - postgres.js [basics](https://github.com/porsager/postgres?tab=readme-ov-file#usage) Drizzle has native support for PostgreSQL connections with the `node-postgres` and `postgres.js` drivers. There are a few differences between the `node-postgres` and `postgres.js` drivers that we discovered while using both and integrating them with the Drizzle ORM. For example: - With `node-postgres`, you can install `pg-native` to boost the speed of both `node-postgres` and Drizzle by approximately 10%. - `node-postgres` supports providing type parsers on a per-query basis without globally patching things. For more details, see [Types Docs](https://node-postgres.com/features/queries#types). - `postgres.js` uses prepared statements by default, which you may need to opt out of. This could be a potential issue in AWS environments, among others, so please keep that in mind. - If there's anything else you'd like to contribute, we'd be happy to receive your PRs [here](https://github.com/drizzle-team/drizzle-orm-docs/pulls) ## node-postgres #### Step 1 - Install packages drizzle-orm pg -D drizzle-kit @types/pg #### Step 2 - Initialize the driver and make a query ```typescript copy // Make sure to install the 'pg' package import { drizzle } from 'drizzle-orm/node-postgres'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ``` ```typescript copy // Make sure to install the 'pg' package import { drizzle } from 'drizzle-orm/node-postgres'; // You can specify any property from the node-postgres connection options const db = drizzle({ connection: { connectionString: process.env.DATABASE_URL, ssl: true } }); const result = await db.execute('select 1'); ``` If you need to provide your existing driver: ```typescript copy // Make sure to install the 'pg' package import { pgTable, serial, text, varchar } from "drizzle-orm/pg-core"; import { drizzle } from "drizzle-orm/node-postgres"; import { Pool } from "pg"; const pool = new Pool({ connectionString: process.env.DATABASE_URL, }); const db = drizzle({ client: pool }); const result = await db.execute('select 1'); ``` ## postgres.js #### Step 1 - Install packages drizzle-orm postgres -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy import { drizzle } from 'drizzle-orm/postgres-js'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ``` ```typescript copy import { drizzle } from 'drizzle-orm/postgres-js'; // You can specify any property from the postgres-js connection options const db = drizzle({ connection: { url: process.env.DATABASE_URL, ssl: true } }); const result = await db.execute('select 1'); ``` If you need to provide your existing driver: ```typescript copy // Make sure to install the 'postgres' package import { drizzle } from 'drizzle-orm/postgres-js'; import postgres from 'postgres'; const queryClient = postgres(process.env.DATABASE_URL); const db = drizzle({ client: queryClient }); const result = await db.execute('select 1'); ``` #### What's next? Source: https://orm.drizzle.team/docs/get-started-singlestore import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; # Drizzle \<\> SingleStore To use Drizzle with a SingleStore database, you should use the `mysql2` driver Drizzle ORM natively supports `mysql2` with `drizzle-orm/singlestore` package. #### Step 1 - Install packages drizzle-orm mysql2 -D drizzle-kit #### Step 2 - Initialize the driver and make a query ```typescript copy import { drizzle } from "drizzle-orm/singlestore"; const db = drizzle(process.env.DATABASE_URL); const response = await db.select().from(...) ``` ```typescript copy import { drizzle } from "drizzle-orm/singlestore"; // You can specify any property from the mysql2 connection options const db = drizzle({ connection:{ uri: process.env.DATABASE_URL }}); const response = await db.select().from(...) ``` If you need to provide your existing driver: ```typescript copy import { drizzle } from "drizzle-orm/singlestore"; import mysql from "mysql2/promise"; const connection = await mysql.createConnection({ host: "host", user: "user", database: "database", ... }); const db = drizzle({ client: connection }); ``` ```typescript copy import { drizzle } from "drizzle-orm/singlestore"; import mysql from "mysql2/promise"; const poolConnection = mysql.createPool({ host: "host", user: "user", database: "database", ... }); const db = drizzle({ client: poolConnection }); ``` For the built in `migrate` function with DDL migrations we and drivers strongly encourage you to use single `client` connection. For querying purposes feel free to use either `client` or `pool` based on your business demands. #### Limitations Currently, the SingleStore dialect has a set of limitations and features that do not work on the SingleStore database side: - SingleStore's serial column type only ensures the uniqueness of column values. - `ORDER BY` and `LIMIT` cannot be chained together. - Foreign keys are not supported (check). - `INTERSECT ALL` and `EXCEPT ALL` operations are not supported by SingleStore. - Nested transactions are not supported by [SingleStore](https://docs.singlestore.com/cloud/reference/sql-reference/procedural-sql-reference/transactions-in-stored-procedures/). - SingleStore [only supports](https://docs.singlestore.com/cloud/getting-started-with-singlestore-helios/about-singlestore-helios/singlestore-helios-faqs/durability/) one `isolationLevel`. - The FSP option in `DATE`, `TIMESTAMP`, and `DATETIME` is not supported. - The relational API is not supported and will be implemented once the SingleStore team develops all the necessary APIs for it. - There may be more limitations because SingleStore is not 100% compatible with MySQL. #### What's next? Source: https://orm.drizzle.team/docs/get-started-sqlite import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Steps from '@mdx/Steps.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import LibsqlTable from '@mdx/LibsqlTable.mdx'; import LibsqlTabs from '@mdx/LibsqlTabs.mdx'; # Drizzle \<\> SQLite Drizzle has native support for SQLite connections with the `libsql` and `better-sqlite3` drivers. There are a few differences between the `libsql` and `better-sqlite3` drivers that we discovered while using both and integrating them with the Drizzle ORM. For example: At the driver level, there may not be many differences between the two, but the main one is that `libSQL` can connect to both SQLite files and `Turso` remote databases. LibSQL is a fork of SQLite that offers a bit more functionality compared to standard SQLite, such as: - More ALTER statements are available with the `libSQL` driver, allowing you to manage your schema more easily than with just `better-sqlite3`. - You can configure the encryption at rest feature natively. - A large set of extensions supported by the SQLite database is also supported by `libSQL`. ## libsql #### Step 1 - Install packages drizzle-orm @libsql/client -D drizzle-kit #### Step 2 - Initialize the driver Drizzle has native support for all @libsql/client driver variations:
#### Step 3 - make a query ```typescript copy import { drizzle } from 'drizzle-orm/libsql'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ``` ```typescript copy import { drizzle } from 'drizzle-orm/libsql'; // You can specify any property from the libsql connection options const db = drizzle({ connection: { url:'', authToken: '' }}); const result = await db.execute('select 1'); ``` If you need a synchronous connection, you can use our additional connection API, where you specify a driver connection and pass it to the Drizzle instance. ```typescript copy import { drizzle } from 'drizzle-orm/libsql'; import { createClient } from '@libsql/client'; const client = createClient({ url: process.env.DATABASE_URL, authToken: process.env.DATABASE_AUTH_TOKEN }); const db = drizzle(client); const result = await db.execute('select 1'); ``` ## better-sqlite3 #### Step 1 - Install packages drizzle-orm better-sqlite3 -D drizzle-kit @types/better-sqlite3 #### Step 2 - Initialize the driver and make a query ```typescript copy import { drizzle } from 'drizzle-orm/better-sqlite3'; const db = drizzle(process.env.DATABASE_URL); const result = await db.execute('select 1'); ``` ```typescript copy import { drizzle } from 'drizzle-orm/better-sqlite3'; // You can specify any property from the better-sqlite3 connection options const db = drizzle({ connection: { source: process.env.DATABASE_URL }}); const result = await db.execute('select 1'); ``` If you need to provide your existing driver: ```typescript copy import { drizzle } from 'drizzle-orm/better-sqlite3'; import Database from 'better-sqlite3'; const sqlite = new Database('sqlite.db'); const db = drizzle({ client: sqlite }); const result = await db.execute('select 1'); ``` #### What's next? Source: https://orm.drizzle.team/docs/get-started import Callout from '@mdx/Callout.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import YoutubeCards from '@mdx/YoutubeCards.astro'; import GetStartedLinks from '@mdx/GetStartedLinks/index.astro'; # Get started with Drizzle Source: https://orm.drizzle.team/docs/get-started/bun-sql-existing import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import IntrospectPostgreSQL from '@mdx/get-started/postgresql/IntrospectPostgreSQL.mdx'; import ConnectBun from '@mdx/get-started/postgresql/ConnectBun.mdx'; import UpdateSchema from '@mdx/get-started/postgresql/UpdateSchema.mdx'; # Get Started with Drizzle and SQLite in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **bun** - javaScript all-in-one toolkit - [read here](https://bun.sh/) - **Bun SQL** - native bindings for working with PostgreSQL databases - [read here](https://bun.sh/docs/api/sql) In version `1.2.0`, Bun has issues with executing concurrent statements, which may lead to errors if you try to run several queries simultaneously. We've created a [github issue](https://github.com/oven-sh/bun/issues/16774) that you can track. Once it's fixed, you should no longer encounter any such errors on Bun's SQL side #### Step 1 - Install required packages drizzle-orm dotenv -D drizzle-kit @types/bun #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file To run a script with `bun`, use the following command: ```bash copy bun src/index.ts ``` #### Step 9 - Update your table schema (optional) #### Step 9 - Applying changes to the database (optional) #### Step 10 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/bun-sql-new import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx'; import ConnectBun from '@mdx/get-started/postgresql/ConnectBun.mdx'; # Get Started with Drizzle and Bun:SQLite - **bun** - javaScript all-in-one toolkit - [read here](https://bun.sh/) - **Bun SQL** - native bindings for working with PostgreSQL databases - [read here](https://bun.sh/docs/api/sql) In version `1.2.0`, Bun has issues with executing concurrent statements, which may lead to errors if you try to run several queries simultaneously. We've created a [github issue](https://github.com/oven-sh/bun/issues/16774) that you can track. Once it's fixed, you should no longer encounter any such errors on Bun's SQL side #### Step 1 - Install required packages drizzle-orm -D drizzle-kit @types/bun #### Step 2 - Setup connection variables #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file To run a script with `bun`, use the following command: ```bash copy bun src/index.ts ``` Source: https://orm.drizzle.team/docs/get-started/bun-sqlite-existing import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import IntrospectSqlite from '@mdx/get-started/sqlite/IntrospectSqlite.mdx'; import ConnectBun from '@mdx/get-started/sqlite/ConnectBun.mdx'; import UpdateSchema from '@mdx/get-started/sqlite/UpdateSchema.mdx'; # Get Started with Drizzle and Bun:SQLite in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **bun** - javaScript all-in-one toolkit - [read here](https://bun.sh/) - **bun:sqlite** - native implementation of a high-performance SQLite3 driver - [read here](https://bun.sh/docs/api/sqlite) #### Step 1 - Install required packages drizzle-orm dotenv -D drizzle-kit tsx @types/bun #### Step 2 - Setup connection variables For example, if you have an SQLite database file in the root of your project, you can use this example: ```plaintext copy DB_FILE_NAME=mydb.sqlite ``` #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file To run a script with `bun`, use the following command: ```bash copy bun src/index.ts ``` #### Step 9 - Update your table schema (optional) #### Step 9 - Applying changes to the database (optional) #### Step 10 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/bun-sqlite-new import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import CreateTable from '@mdx/get-started/sqlite/CreateTable.mdx'; import ConnectBun from '@mdx/get-started/sqlite/ConnectBun.mdx'; # Get Started with Drizzle and Bun:SQLite - **bun** - javaScript all-in-one toolkit - [read here](https://bun.sh/) - **bun:sqlite** - native implementation of a high-performance SQLite3 driver - [read here](https://bun.sh/docs/api/sqlite) #### Step 1 - Install required packages drizzle-orm -D drizzle-kit @types/bun #### Step 2 - Setup connection variables For example, if you want to create an SQLite database file in the root of your project for testing purposes, you can use this example: ```plaintext copy DB_FILE_NAME=mydb.sqlite ``` #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file To run a script with `bun`, use the following command: ```bash copy bun src/index.ts ``` Source: https://orm.drizzle.team/docs/get-started/d1-existing Source: https://orm.drizzle.team/docs/get-started/d1-new import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryTurso from '@mdx/get-started/sqlite/QueryTurso.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import CreateTable from '@mdx/get-started/sqlite/CreateTable.mdx'; import ConnectLibsql from '@mdx/get-started/sqlite/ConnectLibsql.mdx'; # Get Started with Drizzle and D1 - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Cloudflare D1** - Serverless SQL database to query from your Workers and Pages projects - [read here](https://developers.cloudflare.com/d1/) - **wrangler** - Cloudflare Developer Platform command-line interface - [read here](https://developers.cloudflare.com/workers/wrangler) #### Step 1 - Install required packages #### Step 2 - Setup wrangler.toml You would need to have a `wrangler.toml` file for D1 database and will look something like this: ```toml name = "YOUR PROJECT NAME" main = "src/index.ts" compatibility_date = "2022-11-07" node_compat = true [[ d1_databases ]] binding = "DB" database_name = "YOUR DB NAME" database_id = "YOUR DB ID" migrations_dir = "drizzle" ``` #### Step 3 - Connect Drizzle ORM to the database ```typescript copy import { drizzle } from 'drizzle-orm/d1'; export interface Env { : D1Database; } export default { async fetch(request: Request, env: Env) { const db = drizzle(env.); }, }; ``` #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import 'dotenv/config'; import { defineConfig } from 'drizzle-kit'; export default defineConfig({ out: './drizzle', schema: './src/db/schema.ts', dialect: 'sqlite', driver: '', dbCredentials: { accountId: process.env.CLOUDFLARE_ACCOUNT_ID!, databaseId: process.env.CLOUDFLARE_DATABASE_ID!, token: process.env.CLOUDFLARE_D1_TOKEN!, }, }); ``` You can check [our tutorial](/docs/guides/d1-http-with-drizzle-kit) on how to get env variables from CloudFlare #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database ```typescript copy import { drizzle } from 'drizzle-orm/d1'; export interface Env { : D1Database; } export default { async fetch(request: Request, env: Env) { const db = drizzle(env.); const result = await db.select().from(users).all() return Response.json(result); }, }; ``` #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/do-existing Source: https://orm.drizzle.team/docs/get-started/do-new import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryTurso from '@mdx/get-started/sqlite/QueryTurso.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import CreateTable from '@mdx/get-started/sqlite/CreateTable.mdx'; import ConnectLibsql from '@mdx/get-started/sqlite/ConnectLibsql.mdx'; # Get Started with Drizzle and SQLite Durable Objects - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Cloudflare SQLite Durable Objects** - SQLite database embedded within a Durable Object - [read here](https://developers.cloudflare.com/durable-objects/api/sql-storage/) - **wrangler** - Cloudflare Developer Platform command-line interface - [read here](https://developers.cloudflare.com/workers/wrangler) #### Step 1 - Install required packages drizzle-orm dotenv -D drizzle-kit wrangler @cloudflare/workers-types #### Step 2 - Setup wrangler.toml You would need to have a `wrangler.toml` file for D1 database and will look something like this: ```toml #:schema node_modules/wrangler/config-schema.json name = "sqlite-durable-objects" main = "src/index.ts" compatibility_date = "2024-11-12" compatibility_flags = [ "nodejs_compat" ] # Bind a Durable Object. Durable objects are a scale-to-zero compute primitive based on the actor model. # Durable Objects can live for as long as needed. Use these when you need a long-running "server", such as in realtime apps. # Docs: https://developers.cloudflare.com/workers/wrangler/configuration/#durable-objects [[durable_objects.bindings]] name = "MY_DURABLE_OBJECT" class_name = "MyDurableObject" # Durable Object migrations. # Docs: https://developers.cloudflare.com/workers/wrangler/configuration/#migrations [[migrations]] tag = "v1" new_sqlite_classes = ["MyDurableObject"] # We need rules so we can import migrations in the next steps [[rules]] type = "Text" globs = ["**/*.sql"] fallthrough = true ``` #### Step 3 - Connect Drizzle ORM to the database ```ts /// import { drizzle, type DrizzleSqliteDODatabase } from 'drizzle-orm/durable-sqlite'; import { DurableObject } from 'cloudflare:workers' export class MyDurableObject extends DurableObject { storage: DurableObjectStorage; db: DrizzleSqliteDODatabase; constructor(ctx: DurableObjectState, env: Env) { super(ctx, env); this.storage = ctx.storage; this.db = drizzle(this.storage, { logger: false }); } } ``` #### Step 4 - Generate wrangler types wrangler types The output of this command will be a `worker-configuration.d.ts` file. #### Step 5 - Create a table #### Step 6 - Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import 'dotenv/config'; import { defineConfig } from 'drizzle-kit'; export default defineConfig({ out: './drizzle', schema: './src/db/schema.ts', dialect: 'sqlite', driver: 'durable-sqlite', }); ``` #### Step 7 - Applying changes to the database Generate migrations: ```bash copy npx drizzle-kit generate ``` You can apply migrations only from Cloudflare Workers. To achieve this, let's define the migrate functionality in MyDurableObject: ```ts copy {4-5,17-19} /// import { drizzle, type DrizzleSqliteDODatabase } from 'drizzle-orm/durable-sqlite'; import { DurableObject } from 'cloudflare:workers' import { migrate } from 'drizzle-orm/durable-sqlite/migrator'; import migrations from '../drizzle/migrations'; export class MyDurableObject extends DurableObject { storage: DurableObjectStorage; db: DrizzleSqliteDODatabase; constructor(ctx: DurableObjectState, env: Env) { super(ctx, env); this.storage = ctx.storage; this.db = drizzle(this.storage, { logger: false }); } async migrate() { migrate(this.db, migrations); } } ``` #### Step 8 - Migrate and Query the database ```typescript copy /// import { drizzle, DrizzleSqliteDODatabase } from 'drizzle-orm/durable-sqlite'; import { DurableObject } from 'cloudflare:workers' import { migrate } from 'drizzle-orm/durable-sqlite/migrator'; import migrations from '../drizzle/migrations'; import { usersTable } from './db/schema'; export class MyDurableObject extends DurableObject { storage: DurableObjectStorage; db: DrizzleSqliteDODatabase; constructor(ctx: DurableObjectState, env: Env) { super(ctx, env); this.storage = ctx.storage; this.db = drizzle(this.storage, { logger: false }); // Make sure all migrations complete before accepting queries. // Otherwise you will need to run `this.migrate()` in any function // that accesses the Drizzle database `this.db`. ctx.blockConcurrencyWhile(async () => { await this._migrate(); }); } async insertAndList(user: typeof usersTable.$inferInsert) { await this.insert(user); return this.select(); } async insert(user: typeof usersTable.$inferInsert) { await this.db.insert(usersTable).values(user); } async select() { return this.db.select().from(usersTable); } async _migrate() { migrate(this.db, migrations); } } export default { /** * This is the standard fetch handler for a Cloudflare Worker * * @param request - The request submitted to the Worker from the client * @param env - The interface to reference bindings declared in wrangler.toml * @param ctx - The execution context of the Worker * @returns The response to be sent back to the client */ async fetch(request: Request, env: Env): Promise { const id: DurableObjectId = env.MY_DURABLE_OBJECT.idFromName('durable-object'); const stub = env.MY_DURABLE_OBJECT.get(id); // Option A - Maximum performance. // Prefer to bundle all the database interaction within a single Durable Object call // for maximum performance, since database access is fast within a DO. const usersAll = await stub.insertAndList({ name: 'John', age: 30, email: 'john@example.com', }); console.log('New user created. Getting all users from the database: ', users); // Option B - Slow but maybe useful sometimes for debugging. // You can also directly call individual Drizzle queries if they are exposed // but keep in mind every query is a round-trip to the Durable Object instance. await stub.insert({ name: 'John', age: 30, email: 'john@example.com', }); console.log('New user created!'); const users = await stub.select(); console.log('Getting all users from the database: ', users); return Response.json(users); } } ``` Source: https://orm.drizzle.team/docs/get-started/expo-existing import Breadcrumbs from '@mdx/Breadcrumbs.astro'; # Get Started with Drizzle and Expo in existing project We don't have a proper guide for getting started with Expo in an existing project, and we believe that all the information from this [getting started guide](/docs/get-started/expo-new) should be sufficient Source: https://orm.drizzle.team/docs/get-started/expo-new import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import CreateTable from '@mdx/get-started/sqlite/CreateTable.mdx'; import ConnectLibsql from '@mdx/get-started/sqlite/ConnectLibsql.mdx'; # Get Started with Drizzle and Expo - **Expo SQLite** - A library that provides access to a database that can be queried through a SQLite API - [read here](https://docs.expo.dev/versions/latest/sdk/sqlite/) #### Step 1 - Setup a project from Expo Template create expo-app --template blank-typescript You can read more about this template [here](https://docs.expo.dev/more/create-expo/#create-a-new-project). #### Basic file structure After installing the template and adding the `db` folder, you'll find the following content: In the `db/schema.ts` file with drizzle table definitions. The `drizzle` folder contains SQL migration files and snapshots ```plaintext 📦 ├ 📂 assets ├ 📂 drizzle ├ 📂 db │ └ 📜 schema.ts ├ 📜 .gitignore ├ 📜 .npmrc ├ 📜 app.json ├ 📜 App.tsx ├ 📜 babel.config.ts ├ 📜 drizzle.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` #### Step 2 - Install expo-sqlite package expo install expo-sqlite #### Step 3 - Install required packages drizzle-orm -D drizzle-kit #### Step 4 - Connect Drizzle ORM to the database Create a `App.tsx` file in the root directory and initialize the connection: ```ts import * as SQLite from 'expo-sqlite'; import { drizzle } from 'drizzle-orm/expo-sqlite'; const expo = SQLite.openDatabaseSync('db.db'); const db = drizzle(expo); ``` #### Step 4 - Create a table Create a `schema.ts` file in the `db` directory and declare your table: ```typescript copy filename="src/db/schema.ts" import { int, sqliteTable, text } from "drizzle-orm/sqlite-core"; export const usersTable = sqliteTable("users_table", { id: int().primaryKey({ autoIncrement: true }), name: text().notNull(), age: int().notNull(), email: text().notNull().unique(), }); ``` #### Step 5 - Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```ts import { defineConfig } from 'drizzle-kit'; export default defineConfig({ dialect: 'sqlite', driver: 'expo', schema: './db/schema.ts', out: './drizzle', }); ``` #### Step 6 - Setup `metro` config Create a file `metro.config.js` in root folder and add this code inside: ```js copy filename="metro.config.js" const { getDefaultConfig } = require('expo/metro-config'); /** @type {import('expo/metro-config').MetroConfig} */ const config = getDefaultConfig(__dirname); config.resolver.sourceExts.push('sql'); module.exports = config; ``` #### Step 7 - Update `babel` config ```js copy filename="babel.config.js" module.exports = function(api) { api.cache(true); return { presets: ['babel-preset-expo'], plugins: [["inline-import", { "extensions": [".sql"] }]] // <-- add this }; }; ``` #### Step 8 - Applying changes to the database With Expo, you would need to generate migrations using the `drizzle-kit generate` command and then apply them at runtime using the `drizzle-orm` `migrate()` function Generate migrations: ```bash copy npx drizzle-kit generate ``` #### Step 9 - Apply migrations and query your db: Let's **App.tsx** file with migrations and queries to create, read, update, and delete users ```ts copy import { Text, View } from 'react-native'; import * as SQLite from 'expo-sqlite'; import { useEffect, useState } from 'react'; import { drizzle } from 'drizzle-orm/expo-sqlite'; import { usersTable } from './db/schema'; import { useMigrations } from 'drizzle-orm/expo-sqlite/migrator'; import migrations from './drizzle/migrations'; const expo = SQLite.openDatabaseSync('db.db'); const db = drizzle(expo); export default function App() { const { success, error } = useMigrations(db, migrations); const [items, setItems] = useState(null); useEffect(() => { if (!success) return; (async () => { await db.delete(usersTable); await db.insert(usersTable).values([ { name: 'John', age: 30, email: 'john@example.com', }, ]); const users = await db.select().from(usersTable); setItems(users); })(); }, [success]); if (error) { return ( Migration error: {error.message} ); } if (!success) { return ( Migration is in progress... ); } if (items === null || items.length === 0) { return ( Empty ); } return ( {items.map((item) => ( {item.email} ))} ); } ``` #### Step 10 - Prebuild and run expo app ```bash copy npx expo run:ios ``` ```bash copy yarn expo run:ios ``` ```bash copy pnpm expo run:ios ``` ```bash copy bun expo run:ios ``` Source: https://orm.drizzle.team/docs/get-started/gel-existing import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Npx from "@mdx/Npx.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectPostgreSQL from '@mdx/get-started/postgresql/ConnectPostgreSQL.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and Gel in existing project - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **gel-js** - package for querying your Gel database - [read here](https://github.com/geldata/gel-js) - **gel** - cli tool to manage your Gel database - [read here](https://docs.geldata.com/reference/cli) Drizzle has native support for Gel connections with the `gel` client. This is the basic file structure of the project. In the `src` directory, we have table definition in `index.ts`. In `drizzle` folder there are generated Gel to Drizzle schema ```plaintext 📦 ├ 📂 drizzle ├ 📂 dbschema │ ├ 📂 migrations │ ├ 📜 default.esdl │ └ 📜 scoping.esdl ├ 📂 src │ └ 📜 index.ts ├ 📜 drizzle.config.ts ├ 📜 edgedb.toml ├ 📜 package.json └ 📜 tsconfig.json ``` #### Step 4 - Install **gel** package drizzle-orm gel -D drizzle-kit tsx #### Step 5 - Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { defineConfig } from 'drizzle-kit'; export default defineConfig({ dialect: 'gel', }); ``` #### Step 6 - Pull Gel types to Drizzle schema Pull your database schema: drizzle-kit pull Here is an example of the generated schema.ts file: ```ts // drizzle/schema.ts import { gelTable, uniqueIndex, uuid, smallint, text } from "drizzle-orm/gel-core" import { sql } from "drizzle-orm" export const users = gelTable("users", { id: uuid().default(sql`uuid_generate_v4()`).primaryKey().notNull(), age: smallint(), email: text().notNull(), name: text(), }, (table) => [ uniqueIndex("a8c6061c-f37f-11ef-9249-0d78f6c1807b;schemaconstr").using("btree", table.id.asc().nullsLast().op("uuid_ops")), ]); ``` #### Step 6 - Connect Drizzle ORM to the database Create a `index.ts` file in the `src` directory and initialize the connection: ```typescript copy import { drizzle } from "drizzle-orm/gel"; import { createClient } from "gel"; const gelClient = createClient(); const db = drizzle({ client: gelClient }); ``` #### Step 7 - Query the database ```typescript copy filename="src/index.ts" import { eq } from "drizzle-orm"; import { drizzle } from "drizzle-orm/gel"; import { createClient } from "gel"; import { users } from "../drizzle/schema"; const gelClient = createClient(); const db = drizzle({ client: gelClient }); async function main() { const user: typeof users.$inferInsert = { name: "John", age: 30, email: "john@example.com", }; await db.insert(users).values(user); console.log("New user created!"); const usersResponse = await db.select().from(users); console.log("Getting all users from the database: ", usersResponse); /* const users: { id: number; name: string; age: number; email: string; }[] */ await db .update(users) .set({ age: 31, }) .where(eq(users.email, user.email)); console.log("User info updated!"); await db.delete(users).where(eq(users.email, user.email)); console.log("User deleted!"); } main(); ``` #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/gel-new import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Npx from "@mdx/Npx.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectPostgreSQL from '@mdx/get-started/postgresql/ConnectPostgreSQL.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and Gel - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **gel-js** - package for querying your Gel database - [read here](https://github.com/geldata/gel-js) Drizzle has native support for Gel connections with the `gel` client. This is the basic file structure of the project. In the `src` directory, we have table definition in `index.ts`. In `drizzle` folder there are generated Gel to Drizzle schema ```plaintext 📦 ├ 📂 drizzle ├ 📂 src │ └ 📜 index.ts ├ 📜 drizzle.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` #### Step 1 - Install and init **Gel** project Linux or macOS ```bash curl --proto '=https' --tlsv1.2 -sSf https://sh.edgedb.com | sh ``` For more options, check [gel docs](https://docs.geldata.com/reference/cli) Once installed: ```bash gel project init ``` #### Step 2 - Define basic Gel schema In `dbschema/default.esdl` file add a basic Gel schema ```esdl module default { TYPE test { name: str; required email: str; age: int16; } } ``` #### Step 3 - Push Gel schema to the database Generate Gel migration file: ```bash gel migration create ``` Apply Gel migrations to the database ```bash gel migration apply ``` Now you should have this file structure ```plaintext 📦 ├ 📂 dbschema │ ├ 📂 migrations │ ├ 📜 default.esdl │ └ 📜 scoping.esdl ├ 📂 src │ └ 📜 index.ts ├ 📜 drizzle.config.ts ├ 📜 edgedb.toml ├ 📜 package.json └ 📜 tsconfig.json ``` #### Step 4 - Install **gel** package drizzle-orm gel -D drizzle-kit tsx #### Step 5 - Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { defineConfig } from 'drizzle-kit'; export default defineConfig({ dialect: 'gel', }); ``` #### Step 6 - Pull Gel types to Drizzle schema Pull your database schema: drizzle-kit pull Here is an example of the generated schema.ts file: ```ts // drizzle/schema.ts import { gelTable, uniqueIndex, uuid, smallint, text } from "drizzle-orm/gel-core" import { sql } from "drizzle-orm" export const users = gelTable("users", { id: uuid().default(sql`uuid_generate_v4()`).primaryKey().notNull(), age: smallint(), email: text().notNull(), name: text(), }, (table) => [ uniqueIndex("a8c6061c-f37f-11ef-9249-0d78f6c1807b;schemaconstr").using("btree", table.id.asc().nullsLast().op("uuid_ops")), ]); ``` #### Step 6 - Connect Drizzle ORM to the database Create a `index.ts` file in the `src` directory and initialize the connection: ```typescript copy import { drizzle } from "drizzle-orm/gel"; import { createClient } from "gel"; const gelClient = createClient(); const db = drizzle({ client: gelClient }); ``` #### Step 7 - Query the database ```typescript copy filename="src/index.ts" import { eq } from "drizzle-orm"; import { drizzle } from "drizzle-orm/gel"; import { createClient } from "gel"; import { users } from "../drizzle/schema"; const gelClient = createClient(); const db = drizzle({ client: gelClient }); async function main() { const user: typeof users.$inferInsert = { name: "John", age: 30, email: "john@example.com", }; await db.insert(users).values(user); console.log("New user created!"); const usersResponse = await db.select().from(users); console.log("Getting all users from the database: ", usersResponse); /* const users: { id: number; name: string; age: number; email: string; }[] */ await db .update(users) .set({ age: 31, }) .where(eq(users.email, user.email)); console.log("User info updated!"); await db.delete(users).where(eq(users.email, user.email)); console.log("User deleted!"); } main(); ``` #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/mysql-existing import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import ConnectMySQL from '@mdx/get-started/mysql/ConnectMySQL.mdx'; import CreateTable from '@mdx/get-started/mysql/CreateTable.mdx'; import UpdateSchema from '@mdx/get-started/mysql/UpdateSchema.mdx'; import IntrospectMySQL from '@mdx/get-started/mysql/IntrospectMySQL.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; # Get Started with Drizzle and MySQL in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **mysql2** - package for querying your MySQL database - [read here](https://github.com/sidorares/node-mysql2) #### Step 1 - Install the `mysql2` package #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/mysql-new import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import ConnectMySQL from '@mdx/get-started/mysql/ConnectMySQL.mdx'; import CreateTable from '@mdx/get-started/mysql/CreateTable.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; # Get Started with Drizzle and MySQL - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **mysql2** - package for querying your MySQL database - [read here](https://github.com/sidorares/node-mysql2) To use Drizzle with a MySQL database, you should use the `mysql2` driver According to the **[official website](https://github.com/sidorares/node-mysql2)**, `mysql2` is a MySQL client for Node.js with focus on performance. Drizzle ORM natively supports `mysql2` with `drizzle-orm/mysql2` package. #### Step 1 - Install **mysql2** package #### Step 2 - Setup connection variables If you don't have a MySQL database yet and want to create one for testing, you can use our guide on how to set up MySQL in Docker. The MySQL in Docker guide is available [here](/docs/guides/mysql-local-setup). Go set it up, generate a database URL (explained in the guide), and come back for the next steps #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/neon-existing import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IntrospectPostgreSQL from '@mdx/get-started/postgresql/IntrospectPostgreSQL.mdx'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ConnectNeon from '@mdx/get-started/postgresql/ConnectNeon.mdx' import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import UpdateSchema from '@mdx/get-started/postgresql/UpdateSchema.mdx'; # Get Started with Drizzle and Neon in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Neon** - serverless Postgres platform - [read here](https://neon.tech/docs/introduction) #### Step 1 - Install **@neondatabase/serverless** package #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/neon-new import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectNeon from '@mdx/get-started/postgresql/ConnectNeon.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and Neon - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Neon** - serverless Postgres platform - [read here](https://neon.tech/docs/introduction) Drizzle has native support for Neon connections with the `neon-http` and `neon-websockets` drivers. These use the **neon-serverless** driver under the hood. With the `neon-http` and `neon-websockets` drivers, you can access a Neon database from serverless environments over HTTP or WebSockets instead of TCP. Querying over HTTP is faster for single, non-interactive transactions. If you need session or interactive transaction support, or a fully compatible drop-in replacement for the `pg` driver, you can use the WebSocket-based `neon-serverless` driver. You can connect to a Neon database directly using [Postgres](/docs/get-started/postgresql-new) #### Step 1 - Install **@neondatabase/serverless** package #### Step 2 - Setup connection variables #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/nile-existing import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IntrospectPostgreSQL from '@mdx/get-started/postgresql/IntrospectPostgreSQL.mdx'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ConnectNile from '@mdx/get-started/postgresql/ConnectNile.mdx' import QueryNile from '@mdx/get-started/postgresql/QueryNile.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import UpdateSchema from '@mdx/get-started/postgresql/UpdateSchema.mdx'; # Get Started with Drizzle and Nile in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Nile** - PostgreSQL re-engineered for multi-tenant apps - [read here](https://thenile.dev/) #### Step 1 - Install **postgres** package #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database Drizzle Kit provides a CLI command to introspect your database and generate a schema file with migrations. The schema file contains all the information about your database tables, columns, relations, and indices. For example, you have such table in your database: ```sql copy CREATE TABLE IF NOT EXISTS "todos" ( "id" uuid DEFAULT gen_random_uuid(), "tenant_id" uuid, "title" varchar(256), "estimate" varchar(256), "embedding" vector(3), "complete" boolean ); ``` Pull your database schema: ```bash copy npx drizzle-kit pull ``` The result of introspection will be a `schema.ts` file, `meta` folder with snapshots of your database schema, sql file with the migration and `relations.ts` file for [relational queries](/docs/rqb). Nile has several built-in tables that are part of every database. When you introspect a Nile database, the built-in tables will be included. For example, the `tenants` table that you see in the example below. This will allow you to easily create new tenants, list tenants and other operations. Here is an example of the generated `schema.ts` file: ```typescript copy filename="src/db/schema.ts" // table schema generated by introspection import { pgTable, uuid, text, timestamp, varchar, vector, boolean } from "drizzle-orm/pg-core" import { sql } from "drizzle-orm" export const tenants = pgTable("tenants", { id: uuid().default(sql`public.uuid_generate_v7()`).primaryKey().notNull(), name: text(), created: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), updated: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), deleted: timestamp({ mode: 'string' }), }); export const todos = pgTable("todos", { id: uuid().defaultRandom(), tenantId: uuid("tenant_id"), title: varchar({ length: 256 }), estimate: varchar({ length: 256 }), embedding: vector({ dimensions: 3 }), complete: boolean(), }); ``` Learn more about introspection in the [documentation](/docs/drizzle-kit-pull). #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) If you want to update your table schema, you can do it in the `schema.ts` file. For example, let's add a new column `deadline` to the `todos` table`: ```typescript copy filename="src/db/schema.ts" {19} import { pgTable, uuid, text, timestamp, varchar, vector, boolean } from "drizzle-orm/pg-core" import { sql } from "drizzle-orm" export const tenants = pgTable("tenants", { id: uuid().default(sql`public.uuid_generate_v7()`).primaryKey().notNull(), name: text(), created: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), updated: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), deleted: timestamp({ mode: 'string' }), }); export const todos = pgTable("todos", { id: uuid().defaultRandom(), tenantId: uuid("tenant_id"), title: varchar({ length: 256 }), estimate: varchar({ length: 256 }), embedding: vector({ dimensions: 3 }), complete: boolean(), deadline: timestamp({ mode: 'string' }) }); ``` #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) If you run the `index.ts` file again, you'll be able to see the new field that you've just added. The field will be `null` since we did not populate deadlines when inserting todos previously. Source: https://orm.drizzle.team/docs/get-started/nile-new import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectNile from '@mdx/get-started/postgresql/ConnectNile.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryNile from '@mdx/get-started/postgresql/QueryNile.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and Nile - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Nile** - PostgreSQL re-engineered for multi-tenant apps - [read here](https://thenile.dev/) #### Step 1 - Install **postgres** package #### Step 2 - Setup connection variables #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table Create a `schema.ts` file in the `src/db` directory and declare your tables. Since Nile is Postgres for multi-tenant apps, our schema includes a table for tenants and a todos table with a `tenant_id` column (we refer to those as tenant-aware tables): ```typescript copy filename="src/db/schema.ts" import { pgTable, uuid, text, timestamp, varchar, vector, boolean } from "drizzle-orm/pg-core" import { sql } from "drizzle-orm" export const tenantsTable = pgTable("tenants", { id: uuid().default(sql`public.uuid_generate_v7()`).primaryKey().notNull(), name: text(), created: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), updated: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), deleted: timestamp({ mode: 'string' }), }); export const todos = pgTable("todos", { id: uuid().defaultRandom(), tenantId: uuid("tenant_id"), title: varchar({ length: 256 }), estimate: varchar({ length: 256 }), embedding: vector({ dimensions: 3 }), complete: boolean(), }); ``` #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/op-sqlite-existing import Breadcrumbs from '@mdx/Breadcrumbs.astro'; # Get Started with Drizzle and OP-SQLite in existing project We don't have a proper guide for getting started with OP-SQLite in an existing project, and we believe that all the information from this [getting started guide](/docs/get-started/op-sqlite-new) should be sufficient Source: https://orm.drizzle.team/docs/get-started/op-sqlite-new import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import CreateTable from '@mdx/get-started/sqlite/CreateTable.mdx'; import ConnectLibsql from '@mdx/get-started/sqlite/ConnectLibsql.mdx'; # Get Started with Drizzle and OP-SQLite - **OP-SQLite** - SQLite library for react-native - [read here](https://github.com/OP-Engineering/op-sqlite) #### Step 1 - Setup a project from Expo Template create expo-app --template blank-typescript You can read more about this template [here](https://docs.expo.dev/more/create-expo/#create-a-new-project). #### Basic file structure After installing the template and adding the `db` folder, you'll find the following content: In the `db/schema.ts` file with drizzle table definitions. The `drizzle` folder contains SQL migration files and snapshots ```plaintext 📦 ├ 📂 assets ├ 📂 drizzle ├ 📂 db │ └ 📜 schema.ts ├ 📜 .gitignore ├ 📜 .npmrc ├ 📜 app.json ├ 📜 App.tsx ├ 📜 babel.config.ts ├ 📜 drizzle.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` #### Step 2 - Install required packages drizzle-orm @op-engineering/op-sqlite -D drizzle-kit #### Step 3 - Connect Drizzle ORM to the database Create a `App.tsx` file in the root directory and initialize the connection: ```ts import { open } from '@op-engineering/op-sqlite'; import { drizzle } from 'drizzle-orm/expo-sqlite'; const opsqliteDb = open({ name: 'db', }); const db = drizzle(opsqliteDb); ``` #### Step 4 - Create a table Create a `schema.ts` file in the `db` directory and declare your table: ```typescript copy filename="src/db/schema.ts" import { int, sqliteTable, text } from "drizzle-orm/sqlite-core"; export const usersTable = sqliteTable("users_table", { id: int().primaryKey({ autoIncrement: true }), name: text().notNull(), age: int().notNull(), email: text().notNull().unique(), }); ``` #### Step 5 - Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```ts import { defineConfig } from 'drizzle-kit'; export default defineConfig({ dialect: 'sqlite', driver: 'expo', schema: './db/schema.ts', out: './drizzle', }); ``` #### Step 6 - Setup `metro` config Create a file `metro.config.js` in root folder and add this code inside: ```js copy filename="metro.config.js" const { getDefaultConfig } = require('expo/metro-config'); /** @type {import('expo/metro-config').MetroConfig} */ const config = getDefaultConfig(__dirname); config.resolver.sourceExts.push('sql'); module.exports = config; ``` #### Step 7 - Update `babel` config ```js copy filename="metro.config.js" module.exports = function(api) { api.cache(true); return { presets: ['babel-preset-expo'], plugins: [["inline-import", { "extensions": [".sql"] }]] // <-- add this }; }; ``` #### Step 8 - Applying changes to the database With Expo, you would need to generate migrations using the `drizzle-kit generate` command and then apply them at runtime using the `drizzle-orm` `migrate()` function Generate migrations: ```bash copy npx drizzle-kit generate ``` #### Step 9 - Apply migrations and query your db: Let's **App.tsx** file with migrations and queries to create, read, update, and delete users ```ts copy import { Text, View } from 'react-native'; import { open } from '@op-engineering/op-sqlite'; import { useEffect, useState } from 'react'; import { drizzle } from 'drizzle-orm/op-sqlite'; import { usersTable } from './db/schema'; import { useMigrations } from 'drizzle-orm/op-sqlite/migrator'; import migrations from './drizzle/migrations'; const opsqliteDb = open({ name: 'db', }); const db = drizzle(opsqliteDb); export default function App() { const { success, error } = useMigrations(db, migrations); const [items, setItems] = useState(null); useEffect(() => { if (!success) return; (async () => { await db.delete(usersTable); await db.insert(usersTable).values([ { name: 'John', age: 30, email: 'john@example.com', }, ]); const users = await db.select().from(usersTable); setItems(users); })(); }, [success]); if (error) { return ( Migration error: {error.message} ); } if (!success) { return ( Migration is in progress... ); } if (items === null || items.length === 0) { return ( Empty ); } return ( {items.map((item) => ( {item.email} ))} ); } ``` #### Step 10 - Prebuild and run expo app ```bash copy npx expo run:ios ``` ```bash copy yarn expo run:ios ``` ```bash copy pnpm expo run:ios ``` ```bash copy bun expo run:ios ``` Source: https://orm.drizzle.team/docs/get-started/pglite-existing import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IntrospectPostgreSQL from '@mdx/get-started/postgresql/IntrospectPostgreSQL.mdx'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ConnectPgLite from '@mdx/get-started/postgresql/ConnectPgLite.mdx' import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import UpdateSchema from '@mdx/get-started/postgresql/UpdateSchema.mdx'; # Get Started with Drizzle and PGLite in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **ElectricSQL** - [website](https://electric-sql.com/) - **pglite driver** - [docs](https://pglite.dev/) & [GitHub](https://github.com/electric-sql/pglite) #### Step 1 - Install all needed packages #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/pglite-new import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectPgLite from '@mdx/get-started/postgresql/ConnectPgLite.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and PGlite - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **ElectricSQL** - [website](https://electric-sql.com/) - **pglite driver** - [docs](https://pglite.dev/) & [GitHub](https://github.com/electric-sql/pglite) #### Step 1 - Install all needed packages #### Step 2 - Setup connection variables #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/planetscale-existing import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import ConnectPlanetScale from '@mdx/get-started/mysql/ConnectPlanetScale.mdx'; import CreateTable from '@mdx/get-started/mysql/CreateTable.mdx'; import UpdateSchema from '@mdx/get-started/mysql/UpdateSchema.mdx'; import IntrospectMySQL from '@mdx/get-started/mysql/IntrospectMySQL.mdx'; import QueryPlanetScale from '@mdx/get-started/mysql/QueryPlanetScale.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; # Get Started with Drizzle and PlanetScale in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **PlanetScale** - MySQL database platform - [read here](https://planetscale.com/) - **database-js** - PlanetScale serverless driver - [read here](https://github.com/planetscale/database-js) For this tutorial, we will use the `database-js` driver to make **HTTP** calls to the PlanetScale database. If you need to connect to PlanetScale through TCP, you can refer to our [MySQL Get Started](/docs/get-started/mysql-new) page #### Step 1 - Install **@planetscale/database** package #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) ```typescript copy filename="src/index.ts" import 'dotenv/config'; import { eq } from 'drizzle-orm'; import { drizzle } from 'drizzle-orm/planetscale-serverless'; import { usersTable } from './db/schema'; async function main() { const db = drizzle({ connection: { host: process.env.DATABASE_HOST!, username: process.env.DATABASE_USERNAME!, password: process.env.DATABASE_PASSWORD!, }}); const user: typeof usersTable.$inferInsert = { name: 'John', age: 30, email: 'john@example.com', phone: '123-456-7890', }; await db.insert(usersTable).values(user); console.log('New user created!') const users = await db.select().from(usersTable); console.log('Getting all users from the database: ', users) /* const users: { id: number; name: string; age: number; email: string; phone: string | null; }[] */ await db .update(usersTable) .set({ age: 31, }) .where(eq(usersTable.email, user.email)); console.log('User info updated!') await db.delete(usersTable).where(eq(usersTable.email, user.email)); console.log('User deleted!') } main(); ``` Source: https://orm.drizzle.team/docs/get-started/planetscale-new import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import ConnectPlanetScale from '@mdx/get-started/mysql/ConnectPlanetScale.mdx'; import CreateTable from '@mdx/get-started/mysql/CreateTable.mdx'; import QueryPlanetScale from '@mdx/get-started/mysql/QueryPlanetScale.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; # Get Started with Drizzle and PlanetScale - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **PlanetScale** - MySQL database platform - [read here](https://planetscale.com/) - **database-js** - PlanetScale serverless driver - [read here](https://github.com/planetscale/database-js) For this tutorial, we will use the `database-js` driver to make **HTTP** calls to the PlanetScale database. If you need to connect to PlanetScale through TCP, you can refer to our [MySQL Get Started](/docs/get-started/mysql-new) page #### Step 1 - Install **@planetscale/database** package #### Step 2 - Setup connection variables Create a `.env` file in the root of your project and add your database connection variable: ```plaintext copy DATABASE_HOST= DATABASE_USERNAME= DATABASE_PASSWORD= ``` To get all the necessary environment variables to connect through the `database-js` driver, you can check the [PlanetScale docs](https://planetscale.com/docs/tutorials/planetscale-serverless-driver-node-example#use-the-sample-repository) #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/postgresql-existing import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IntrospectPostgreSQL from '@mdx/get-started/postgresql/IntrospectPostgreSQL.mdx'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ConnectPostgreSQL from '@mdx/get-started/postgresql/ConnectPostgreSQL.mdx' import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import UpdateSchema from '@mdx/get-started/postgresql/UpdateSchema.mdx'; # Get Started with Drizzle and PostgreSQL in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **node-postgres** - package for querying your PostgreSQL database - [read here](https://node-postgres.com/) #### Step 1 - Install **node-postgres** package #### Step 2 - Setup connection variables If you don't have a PostgreSQL database yet and want to create one for testing, you can use our guide on how to set up PostgreSQL in Docker. The PostgreSQL in Docker guide is available [here](/docs/guides/postgresql-local-setup). Go set it up, generate a database URL (explained in the guide), and come back for the next steps #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/postgresql-new import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectPostgreSQL from '@mdx/get-started/postgresql/ConnectPostgreSQL.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and PostgreSQL - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **node-postgres** - package for querying your PostgreSQL database - [read here](https://node-postgres.com/) Drizzle has native support for PostgreSQL connections with the `node-postgres` and `postgres.js` drivers. We will use `node-postgres` for this get started example. But if you want to find more ways to connect to postgresql check our [PostgreSQL Connection](/docs/get-started-postgresql) page #### Step 1 - Install **node-postgres** package #### Step 2 - Setup connection variables If you don't have a PostgreSQL database yet and want to create one for testing, you can use our guide on how to set up PostgreSQL in Docker. The PostgreSQL in Docker guide is available [here](/docs/guides/postgresql-local-setup). Go set it up, generate a database URL (explained in the guide), and come back for the next steps #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/singlestore-existing import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import ConnectSingleStore from '@mdx/get-started/singlestore/ConnectSingleStore.mdx'; import UpdateSchema from '@mdx/get-started/singlestore/UpdateSchema.mdx'; import IntrospectSingleStore from '@mdx/get-started/singlestore/IntrospectSingleStore.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; # Get Started with Drizzle and SingleStore in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **mysql2** - package for querying your SingleStore database - [read here](https://github.com/sidorares/node-mysql2) #### Step 1 - Install the `mysql2` package #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/singlestore-new import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import ConnectSingleStore from '@mdx/get-started/singlestore/ConnectSingleStore.mdx'; import CreateSingleStoreTable from '@mdx/get-started/singlestore/CreateSingleStoreTable.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; # Get Started with Drizzle and SingleStore - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **mysql2** - package for querying your MySQL database - [read here](https://github.com/sidorares/node-mysql2) To use Drizzle with a SingleStore database, you should use the `singlestore` driver According to the **[official website](https://github.com/sidorares/node-mysql2)**, `mysql2` is a MySQL client for Node.js with focus on performance. Drizzle ORM natively supports `mysql2` with `drizzle-orm/singlestore` package for SingleStore database. #### Step 1 - Install **mysql2** package #### Step 2 - Setup connection variables #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/sqlite-existing import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import IntrospectSqlite from '@mdx/get-started/sqlite/IntrospectSqlite.mdx'; import ConnectLibsql from '@mdx/get-started/sqlite/ConnectLibsql.mdx'; import UpdateSchema from '@mdx/get-started/sqlite/UpdateSchema.mdx'; # Get Started with Drizzle and SQLite in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **libsql** - a fork of SQLite optimized for low query latency, making it suitable for global applications - [read here](https://docs.turso.tech/libsql) #### Step 1 - Install required packages #### Step 2 - Setup connection variables For example, if you want to create an SQLite database file in the root of your project for testing purposes, you need to use `file:` before the actual filename, as this is the format required by `LibSQL`, like this: ```plaintext copy DB_FILE_NAME=file:local.db ``` You can check the **[LibSQL docs](https://docs.turso.tech/sdk/ts/reference#local-development)** for more info. #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 9 - Applying changes to the database (optional) #### Step 10 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/sqlite-new import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import CreateTable from '@mdx/get-started/sqlite/CreateTable.mdx'; import ConnectLibsql from '@mdx/get-started/sqlite/ConnectLibsql.mdx'; # Get Started with Drizzle and SQLite - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **libsql** - a fork of SQLite optimized for low query latency, making it suitable for global applications - [read here](https://docs.turso.tech/libsql) Drizzle has native support for SQLite connections with the `libsql` and `better-sqlite3` drivers. We will use `libsql` for this get started example. But if you want to find more ways to connect to SQLite check our [SQLite Connection](/docs/get-started-sqlite) page #### Step 1 - Install required packages #### Step 2 - Setup connection variables For example, if you want to create an SQLite database file in the root of your project for testing purposes, you need to use `file:` before the actual filename, as this is the format required by `LibSQL`, like this: ```plaintext copy DB_FILE_NAME=file:local.db ``` You can check the **[LibSQL docs](https://docs.turso.tech/sdk/ts/reference#local-development)** for more info. #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/supabase-existing import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IntrospectPostgreSQL from '@mdx/get-started/postgresql/IntrospectPostgreSQL.mdx'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ConnectSupabase from '@mdx/get-started/postgresql/ConnectSupabase.mdx' import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import UpdateSchema from '@mdx/get-started/postgresql/UpdateSchema.mdx'; # Get Started with Drizzle and Supabase in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Supabase** - open source Firebase alternative - [read here](https://supabase.com/) #### Step 1 - Install **postgres** package #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/supabase-new import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectSupabase from '@mdx/get-started/postgresql/ConnectSupabase.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and Supabase - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Supabase** - open source Firebase alternative - [read here](https://supabase.com/) #### Step 1 - Install **postgres** package #### Step 2 - Setup connection variables #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/tidb-existing import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import ConnectTiDB from '@mdx/get-started/mysql/ConnectTiDB.mdx'; import CreateTable from '@mdx/get-started/mysql/CreateTable.mdx'; import UpdateSchema from '@mdx/get-started/mysql/UpdateSchema.mdx'; import IntrospectMySQL from '@mdx/get-started/mysql/IntrospectMySQL.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; # Get Started with Drizzle and TiDB in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **TiDB** - The Distributed SQL Database by PingCAP - [read here](https://www.pingcap.com/) - **serverless-js** - package for serverless and edge compute platforms that require HTTP external connections - [read here](https://github.com/tidbcloud/serverless-js) #### Step 1 - Install **@tidbcloud/serverless** package #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/tidb-new import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import ConnectTiDB from '@mdx/get-started/mysql/ConnectTiDB.mdx'; import CreateTable from '@mdx/get-started/mysql/CreateTable.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; # Get Started with Drizzle and TiDB - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **TiDB** - The Distributed SQL Database by PingCAP - [read here](https://www.pingcap.com/) - **serverless-js** - package for serverless and edge compute platforms that require HTTP external connections - [read here](https://github.com/tidbcloud/serverless-js) For this tutorial, we will use the `@tidbcloud/serverless` driver to make **HTTP** calls. If you need to connect to TiDB through TCP, you can refer to our [MySQL Get Started](/docs/get-started/mysql-new) page #### Step 1 - Install **@tidbcloud/serverless** package #### Step 2 - Setup connection variables #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/turso-existing import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import IntrospectSqlite from '@mdx/get-started/sqlite/IntrospectSqlite.mdx'; import ConnectLibsql from '@mdx/get-started/sqlite/ConnectLibsql.mdx'; import UpdateSchema from '@mdx/get-started/sqlite/UpdateSchema.mdx'; import QueryTurso from '@mdx/get-started/sqlite/QueryTurso.mdx'; import QueryTursoUpdated from '@mdx/get-started/sqlite/QueryTursoUpdated.mdx'; import LibsqlTable from '@mdx/LibsqlTable.mdx'; import LibsqlTabs from '@mdx/LibsqlTabs.mdx'; # Get Started with Drizzle and Turso in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **turso** - SQLite for Production - [read here](https://turso.tech/) - **libsql** - a fork of SQLite optimized for low query latency, making it suitable for global applications - [read here](https://docs.turso.tech/libsql) #### Step 1 - Install required packages #### Step 2 - Setup connection variables Create a `.env` file in the root of your project and add you Turso database url and auth token: ```plaintext copy TURSO_DATABASE_URL= TURSO_AUTH_TOKEN= ``` If you don't know your `TURSO_DATABASE_URL` and `TURSO_AUTH_TOKEN` values, you can refer to the LibSQL Driver SDK tutorial. Check it out [here](https://docs.turso.tech/sdk/ts/quickstart), then return with all the values generated and added to the `.env` file #### Step 3 - Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import 'dotenv/config'; import { defineConfig } from 'drizzle-kit'; export default defineConfig({ out: './drizzle', schema: './src/db/schema.ts', dialect: 'turso', dbCredentials: { url: process.env.TURSO_DATABASE_URL, authToken: process.env.TURSO_AUTH_TOKEN, }, }); ``` #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database Drizzle has native support for all @libsql/client driver variations:
Create a `index.ts` file in the `src` directory and initialize the connection: ```typescript copy import 'dotenv/config'; import { drizzle } from 'drizzle-orm/libsql'; // You can specify any property from the libsql connection options const db = drizzle({ connection: { url: process.env.TURSO_DATABASE_URL!, authToken: process.env.TURSO_AUTH_TOKEN! } }); ``` If you need to provide your existing driver: ```typescript copy import 'dotenv/config'; import { drizzle } from 'drizzle-orm/libsql'; import { createClient } from '@libsql/client'; const client = createClient({ url: process.env.TURSO_DATABASE_URL!, authToken: process.env.TURSO_AUTH_TOKEN! }); const db = drizzle({ client }); ``` #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 9 - Applying changes to the database (optional) #### Step 10 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/turso-new import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Callout from '@mdx/Callout.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import WhatsNextPostgres from "@mdx/WhatsNextPostgres.astro"; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import QueryTurso from '@mdx/get-started/sqlite/QueryTurso.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import CreateTable from '@mdx/get-started/sqlite/CreateTable.mdx'; import ConnectLibsql from '@mdx/get-started/sqlite/ConnectLibsql.mdx'; import LibsqlTable from '@mdx/LibsqlTable.mdx'; import LibsqlTabs from '@mdx/LibsqlTabs.mdx'; # Get Started with Drizzle and Turso - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **turso** - SQLite for Production - [read here](https://turso.tech/) - **libsql** - a fork of SQLite optimized for low query latency, making it suitable for global applications - [read here](https://docs.turso.tech/libsql) #### Step 1 - Install required packages #### Step 2 - Setup connection variables Create a `.env` file in the root of your project and add you Turso database url and auth token: ```plaintext copy TURSO_DATABASE_URL= TURSO_AUTH_TOKEN= ``` If you don't know your `TURSO_DATABASE_URL` and `TURSO_AUTH_TOKEN` values, you can refer to the LibSQL Driver SDK tutorial. Check it out [here](https://docs.turso.tech/sdk/ts/quickstart), then return with all the values generated and added to the `.env` file #### Step 3 - Connect Drizzle ORM to the database Drizzle has native support for all @libsql/client driver variations:
Create a `index.ts` file in the `src` directory and initialize the connection: ```typescript copy import 'dotenv/config'; import { drizzle } from 'drizzle-orm/libsql'; // You can specify any property from the libsql connection options const db = drizzle({ connection: { url: process.env.TURSO_DATABASE_URL!, authToken: process.env.TURSO_AUTH_TOKEN! } }); ``` If you need to provide your existing driver: ```typescript copy import 'dotenv/config'; import { drizzle } from 'drizzle-orm/libsql'; import { createClient } from '@libsql/client'; const client = createClient({ url: process.env.TURSO_DATABASE_URL!, authToken: process.env.TURSO_AUTH_TOKEN! }); const db = drizzle({ client }); ``` #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import 'dotenv/config'; import { defineConfig } from 'drizzle-kit'; export default defineConfig({ out: './drizzle', schema: './src/db/schema.ts', dialect: 'turso', dbCredentials: { url: process.env.TURSO_DATABASE_URL, authToken: process.env.TURSO_AUTH_TOKEN, }, }); ``` #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/vercel-existing import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IntrospectPostgreSQL from '@mdx/get-started/postgresql/IntrospectPostgreSQL.mdx'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ConnectVercel from '@mdx/get-started/postgresql/ConnectVercel.mdx' import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import QueryDatabaseUpdated from '@mdx/get-started/QueryDatabaseUpdated.mdx'; import UpdateSchema from '@mdx/get-started/postgresql/UpdateSchema.mdx'; # Get Started with Drizzle and Vercel Postgres in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Vercel Postgres database** - [read here](https://vercel.com/docs/storage/vercel-postgres) - **Vercel Postgres driver** - [read here](https://vercel.com/docs/storage/vercel-postgres/sdk) & [GitHub](https://github.com/vercel/storage/tree/main/packages/postgres) #### Step 1 - Install required package #### Step 2 - Setup connection variables It's important to name the variable `POSTGRES_URL` for Vercel Postgres. In the Vercel Postgres storage tab, you can find the `.env.local` tab and copy the `POSTGRES_URL` variable #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database ```typescript copy filename="src/index.ts" import 'dotenv/config'; import { eq } from 'drizzle-orm'; import { drizzle } from 'drizzle-orm/vercel-postgres'; import { usersTable } from './db/schema'; async function main() { const db = drizzle(); const user: typeof usersTable.$inferInsert = { name: 'John', age: 30, email: 'john@example.com', }; await db.insert(usersTable).values(user); console.log('New user created!') const users = await db.select().from(usersTable); console.log('Getting all users from the database: ', users) /* const users: { id: number; name: string; age: number; email: string; }[] */ await db .update(usersTable) .set({ age: 31, }) .where(eq(usersTable.email, user.email)); console.log('User info updated!') await db.delete(usersTable).where(eq(usersTable.email, user.email)); console.log('User deleted!') } main(); ``` #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) ```typescript copy filename="src/index.ts" import 'dotenv/config'; import { eq } from 'drizzle-orm'; import { drizzle } from 'drizzle-orm/vercel-postgres'; import { usersTable } from './db/schema'; async function main() { const db = drizzle(); const user: typeof usersTable.$inferInsert = { name: 'John', age: 30, email: 'john@example.com', phone: '123-456-7890', }; await db.insert(usersTable).values(user); console.log('New user created!') const users = await db.select().from(usersTable); console.log('Getting all users from the database: ', users) /* const users: { id: number; name: string; age: number; email: string; phone: string | null; }[] */ await db .update(usersTable) .set({ age: 31, }) .where(eq(usersTable.email, user.email)); console.log('User info updated!') await db.delete(usersTable).where(eq(usersTable.email, user.email)); console.log('User deleted!') } main(); ``` Source: https://orm.drizzle.team/docs/get-started/vercel-new import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectVercel from '@mdx/get-started/postgresql/ConnectVercel.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryDatabase from '@mdx/get-started/QueryDatabase.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and Vercel Postgres - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Vercel Postgres database** - [read here](https://vercel.com/docs/storage/vercel-postgres) - **Vercel Postgres driver** - [read here](https://vercel.com/docs/storage/vercel-postgres/sdk) & [GitHub](https://github.com/vercel/storage/tree/main/packages/postgres) #### Step 1 - Install required package #### Step 2 - Setup connection variables It's important to name the variable `POSTGRES_URL` for Vercel Postgres. In the Vercel Postgres storage tab, you can find the `.env.local` tab and copy the `POSTGRES_URL` variable #### Step 3 - Connect Drizzle ORM to the database #### Step 4 - Create a table #### Step 5 - Setup Drizzle config file #### Step 6 - Applying changes to the database #### Step 7 - Seed and Query the database ```typescript copy filename="src/index.ts" import 'dotenv/config'; import { eq } from 'drizzle-orm'; import { drizzle } from 'drizzle-orm/vercel-postgres'; import { usersTable } from './db/schema'; async function main() { const db = drizzle(); const user: typeof usersTable.$inferInsert = { name: 'John', age: 30, email: 'john@example.com', }; await db.insert(usersTable).values(user); console.log('New user created!') const users = await db.select().from(usersTable); console.log('Getting all users from the database: ', users) /* const users: { id: number; name: string; age: number; email: string; }[] */ await db .update(usersTable) .set({ age: 31, }) .where(eq(usersTable.email, user.email)); console.log('User info updated!') await db.delete(usersTable).where(eq(usersTable.email, user.email)); console.log('User deleted!') } main(); ``` #### Step 8 - Run index.ts file Source: https://orm.drizzle.team/docs/get-started/xata-existing import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IntrospectPostgreSQL from '@mdx/get-started/postgresql/IntrospectPostgreSQL.mdx'; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import ConnectXata from '@mdx/get-started/postgresql/ConnectXata.mdx' import QueryXata from '@mdx/get-started/postgresql/QueryXata.mdx'; import QueryXataUpdated from '@mdx/get-started/postgresql/QueryXataUpdated.mdx'; import UpdateSchema from '@mdx/get-started/postgresql/UpdateSchema.mdx'; # Get Started with Drizzle and Xata in existing project - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Xata database** - [read here](https://xata.io/docs) - **Xata driver** - [read here](https://xata.io/docs/sdk/typescript/overview) & [GitHub](https://github.com/xataio/client-ts) #### Step 1 - Install **@xata.io/client** package #### Step 2 - Setup connection variables #### Step 3 - Setup Drizzle config file #### Step 4 - Introspect your database #### Step 5 - Transfer code to your actual schema file #### Step 6 - Connect Drizzle ORM to the database #### Step 7 - Query the database #### Step 8 - Run index.ts file #### Step 9 - Update your table schema (optional) #### Step 10 - Applying changes to the database (optional) #### Step 11 - Query the database with a new field (optional) Source: https://orm.drizzle.team/docs/get-started/xata-new import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from "@mdx/Npm.astro"; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import AnchorCards from '@mdx/AnchorCards.astro'; import Breadcrumbs from '@mdx/Breadcrumbs.astro'; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import FileStructure from '@mdx/get-started/FileStructure.mdx'; import InstallPackages from '@mdx/get-started/InstallPackages.mdx'; import ConnectXata from '@mdx/get-started/postgresql/ConnectXata.mdx' import CreateTable from '@mdx/get-started/postgresql/CreateTable.mdx' import SetupConfig from '@mdx/get-started/SetupConfig.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; import QueryXata from '@mdx/get-started/postgresql/QueryXata.mdx'; import SetupEnv from '@mdx/get-started/SetupEnv.mdx'; # Get Started with Drizzle and Xata - **dotenv** - package for managing environment variables - [read here](https://www.npmjs.com/package/dotenv) - **tsx** - package for running TypeScript files - [read here](https://tsx.is/) - **Xata database** - [read here](https://xata.io/docs) - **Xata driver** - [read here](https://xata.io/docs/sdk/typescript/overview) & [GitHub](https://github.com/xataio/client-ts) #### Step 1 - Install **@xata.io/client** package #### Step 2 - Setup connection variables #### Step 3 - Generate Xata client To generate the Xata client, please refer to the [Xata docs](https://xata.io/docs/getting-started/installation) #### Step 4 - Connect Drizzle ORM to the database #### Step 5 - Create a table #### Step 6 - Setup Drizzle config file #### Step 7 - Applying changes to the database #### Step 8 - Seed and Query the database #### Step 9 - Run index.ts file Source: https://orm.drizzle.team/docs/goodies import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; ## Type API To retrieve a type from your table schema for `select` and `insert` queries, you can make use of our type helpers. ```ts import { serial, text, pgTable } from 'drizzle-orm/pg-core'; import { type InferSelectModel, type InferInsertModel } from 'drizzle-orm' const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), }); type SelectUser = typeof users.$inferSelect; type InsertUser = typeof users.$inferInsert; // or type SelectUser = typeof users._.$inferSelect; type InsertUser = typeof users._.$inferInsert; // or type SelectUser = InferSelectModel; type InsertUser = InferInsertModel; ``` ```ts import { int, text, mysqlTable } from 'drizzle-orm/mysql-core'; import { type InferSelectModel, type InferInsertModel } from 'drizzle-orm' const users = mysqlTable('users', { id: int('id').primaryKey(), name: text('name').notNull(), }); type SelectUser = typeof users.$inferSelect; type InsertUser = typeof users.$inferInsert; // or type SelectUser = typeof users._.$inferSelect; type InsertUser = typeof users._.$inferInsert; // or type SelectUser = InferSelectModel; type InsertUser = InferInsertModel; ``` ```ts import { int, text, sqliteTable } from 'drizzle-orm/sqlite-core'; import { type InferSelectModel, type InferInsertModel } from 'drizzle-orm' const users = sqliteTable('users', { id: int('id').primaryKey(), name: text('name').notNull(), }); type SelectUser = typeof users.$inferSelect; type InsertUser = typeof users.$inferInsert; // or type SelectUser = typeof users._.$inferSelect; type InsertUser = typeof users._.$inferInsert; // or type SelectUser = InferSelectModel; type InsertUser = InferInsertModel; ``` ```ts import { int, text, singlestoreTable } from 'drizzle-orm/singlestore-core'; import { type InferSelectModel, type InferInsertModel } from 'drizzle-orm' const users = singlestoreTable('users', { id: int('id').primaryKey(), name: text('name').notNull(), }); type SelectUser = typeof users.$inferSelect; type InsertUser = typeof users.$inferInsert; // or type SelectUser = typeof users._.$inferSelect; type InsertUser = typeof users._.$inferInsert; // or type SelectUser = InferSelectModel; type InsertUser = InferInsertModel; ``` ## Logging To enable default query logging, just pass `{ logger: true }` to the `drizzle` initialization function: ```typescript copy import { drizzle } from 'drizzle-orm/...'; // driver specific const db = drizzle({ logger: true }); ``` You can change the logs destination by creating a `DefaultLogger` instance and providing a custom `writer` to it: ```typescript copy import { DefaultLogger, LogWriter } from 'drizzle-orm/logger'; import { drizzle } from 'drizzle-orm/...'; // driver specific class MyLogWriter implements LogWriter { write(message: string) { // Write to file, stdout, etc. } } const logger = new DefaultLogger({ writer: new MyLogWriter() }); const db = drizzle({ logger }); ``` You can also create a custom logger: ```typescript copy import { Logger } from 'drizzle-orm/logger'; import { drizzle } from 'drizzle-orm/...'; // driver specific class MyLogger implements Logger { logQuery(query: string, params: unknown[]): void { console.log({ query, params }); } } const db = drizzle({ logger: new MyLogger() }); ``` ## Multi-project schema **Table creator** API lets you define customise table names. It's very useful when you need to keep schemas of different projects in one database. ```ts {3} import { serial, text, pgTableCreator } from 'drizzle-orm/pg-core'; const pgTable = pgTableCreator((name) => `project1_${name}`); const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), }); ``` ```ts {3} import { int, text, mysqlTableCreator } from 'drizzle-orm/mysql-core'; const mysqlTable = mysqlTableCreator((name) => `project1_${name}`); const users = mysqlTable('users', { id: int('id').primaryKey(), name: text('name').notNull(), }); ``` ```ts {3} import { int, text, sqliteTableCreator } from 'drizzle-orm/sqlite-core'; const sqliteTable = sqliteTableCreator((name) => `project1_${name}`); const users = sqliteTable('users', { id: int('id').primaryKey(), name: text('name').notNull(), }); ``` ```ts {3} import { int, text, singlestoreTableCreator } from 'drizzle-orm/singlestore-core'; const mysqlTable = singlestoreTableCreator((name) => `project1_${name}`); const users = singlestoreTable('users', { id: int('id').primaryKey(), name: text('name').notNull(), }); ``` ```ts {10} import { defineConfig } from "drizzle-kit"; export default defineConfig({ schema: "./src/schema/*", out: "./drizzle", dialect: "mysql", dbCredentials: { url: process.env.DATABASE_URL, } tablesFilter: ["project1_*"], }); ``` You can apply multiple `or` filters: ```ts tablesFilter: ["project1_*", "project2_*"] ``` ## Printing SQL query You can print SQL queries with `db` instance or by using **[`standalone query builder`](#standalone-query-builder)**. ```typescript copy const query = db .select({ id: users.id, name: users.name }) .from(users) .groupBy(users.id) .toSQL(); // query: { sql: 'select 'id', 'name' from 'users' group by 'users'.'id'', params: [], } ``` ## Raw SQL queries execution If you have some complex queries to execute and `drizzle-orm` can't handle them yet, you can use the `db.execute` method to execute raw `parametrized` queries. ```ts const statement = sql`select * from ${users} where ${users.id} = ${userId}`; const res: postgres.RowList[]> = await db.execute(statement) ``` ```typescript copy import { ..., MySqlQueryResult } from "drizzle-orm/mysql2"; const statement = sql`select * from ${users} where ${users.id} = ${userId}`; const res: MySqlRawQueryResult = await db.execute(statement); ``` ```ts const statement = sql`select * from ${users} where ${users.id} = ${userId}`; const res: unknown[] = db.all(statement) const res: unknown = db.get(statement) const res: unknown[][] = db.values(statement) const res: Database.RunResult = db.run(statement) ``` ```typescript copy import { ..., SingleStoreQueryResult } from "drizzle-orm/singlestore"; const statement = sql`select * from ${users} where ${users.id} = ${userId}`; const res: SingleStoreRawQueryResult = await db.execute(statement); ``` ## Standalone query builder Drizzle ORM provides a standalone query builder that allows you to build queries without creating a database instance and get generated SQL. ```typescript copy import { QueryBuilder } from 'drizzle-orm/pg-core'; const qb = new QueryBuilder(); const query = qb.select().from(users).where(eq(users.name, 'Dan')); const { sql, params } = query.toSQL(); ``` ```typescript copy import { QueryBuilder } from 'drizzle-orm/mysql-core'; const qb = new QueryBuilder(); const query = qb.select().from(users).where(eq(users.name, 'Dan')); const { sql, params } = query.toSQL(); ``` ```typescript copy import { QueryBuilder } from 'drizzle-orm/sqlite-core'; const qb = new QueryBuilder(); const query = qb.select().from(users).where(eq(users.name, 'Dan')); const { sql, params } = query.toSQL(); ``` ```typescript copy import { QueryBuilder } from 'drizzle-orm/singlestore-core'; const qb = new QueryBuilder(); const query = qb.select().from(users).where(eq(users.name, 'Dan')); const { sql, params } = query.toSQL(); ``` ## Get typed table columns You can get a typed table columns map, very useful when you need to omit certain columns upon selection. ```ts import { getTableColumns } from "drizzle-orm"; import { user } from "./schema"; const { password, role, ...rest } = getTableColumns(user); await db.select({ ...rest }).from(users); ``` ```ts import { serial, text, pgTable } from "drizzle-orm/pg-core"; export const user = pgTable("user", { id: serial("id").primaryKey(), name: text("name"), email: text("email"), password: text("password"), role: text("role").$type<"admin" | "customer">(), }); ``` ```ts import { getTableColumns } from "drizzle-orm"; import { user } from "./schema"; const { password, role, ...rest } = getTableColumns(user); await db.select({ ...rest }).from(users); ``` ```ts import { int, text, mysqlTable } from "drizzle-orm/mysql-core"; export const user = mysqlTable("user", { id: int("id").primaryKey().autoincrement(), name: text("name"), email: text("email"), password: text("password"), role: text("role").$type<"admin" | "customer">(), }); ``` ```ts import { getTableColumns } from "drizzle-orm"; import { user } from "./schema"; const { password, role, ...rest } = getTableColumns(user); await db.select({ ...rest }).from(users); ``` ```ts import { integer, text, sqliteView } from "drizzle-orm/sqlite-core"; export const user = pgTable("user", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name"), email: text("email"), password: text("password"), role: text("role").$type<"admin" | "customer">(), }); ``` ```ts import { getTableColumns } from "drizzle-orm"; import { user } from "./schema"; const { password, role, ...rest } = getTableColumns(user); await db.select({ ...rest }).from(users); ``` ```ts import { int, text, mysqlTable } from "drizzle-orm/singlestore-core"; export const user = singlestoreTable("user", { id: int("id").primaryKey().autoincrement(), name: text("name"), email: text("email"), password: text("password"), role: text("role").$type<"admin" | "customer">(), }); ``` ## Get table information ```ts copy import { getTableConfig, pgTable } from 'drizzle-orm/pg-core'; export const table = pgTable(...); const { columns, indexes, foreignKeys, checks, primaryKeys, name, schema, } = getTableConfig(table); ``` ```ts copy import { getTableConfig, mysqlTable } from 'drizzle-orm/mysql-core'; export const table = mysqlTable(...); const { columns, indexes, foreignKeys, checks, primaryKeys, name, schema, } = getTableConfig(table); ``` ```ts copy import { getTableConfig, sqliteTable } from 'drizzle-orm/sqlite-core'; export const table = sqliteTable(...); const { columns, indexes, foreignKeys, checks, primaryKeys, name, schema, } = getTableConfig(table); ``` ```ts copy import { getTableConfig, mysqlTable } from 'drizzle-orm/singlestore-core'; export const table = singlestoreTable(...); const { columns, indexes, checks, primaryKeys, name, schema, } = getTableConfig(table); ``` ## Compare objects types (instanceof alternative) You can check if an object is of a specific Drizzle type using the `is()` function. You can use it with any available type in Drizzle. You should always use `is()` instead of `instanceof` **Few examples** ```ts import { Column, is } from 'drizzle-orm'; if (is(value, Column)) { // value's type is narrowed to Column } ``` ### Mock Driver This API is a successor to an undefined `drizzle({} as any)` API which we've used internally in Drizzle tests and rarely recommended to external developers. We decided to build and expose a proper API, every `drizzle` driver now has `drizzle.mock()`: ```ts import { drizzle } from "drizzle-orm/node-postgres"; const db = drizzle.mock(); ``` you can provide schema if necessary for types ```ts import { drizzle } from "drizzle-orm/node-postgres"; import * as schema from "./schema" const db = drizzle.mock({ schema }); ``` Source: https://orm.drizzle.team/docs/gotchas import CodeTab from "@mdx/CodeTab.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; # Drizzle gotchas This will be a library of `gotchas` with Drizzle use cases Source: https://orm.drizzle.team/docs/graphql import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import CodeTab from '@mdx/CodeTab.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import Npm from '@mdx/Npm.astro'; # drizzle-graphql Create a GraphQL server from a Drizzle schema in one line, and easily enhance it with custom queries and mutations. ## Quick start Make sure your `drizzle-orm` version is at least `0.30.9`, and update if needed: drizzle-orm@latest ### Apollo Server drizzle-graphql @apollo/server graphql ```ts copy {1, 10} import { buildSchema } from 'drizzle-graphql'; import { drizzle } from 'drizzle-orm/...'; import client from './db'; import { ApolloServer } from '@apollo/server'; import { startStandaloneServer } from '@apollo/server/standalone'; import * as dbSchema from './schema'; const db = drizzle({ client, schema: dbSchema }); const { schema } = buildSchema(db); const server = new ApolloServer({ schema }); const { url } = await startStandaloneServer(server); console.log(`🚀 Server ready at ${url}`); ``` ```typescript copy import { integer, serial, text, pgTable } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), }); export const usersRelations = relations(users, ({ many }) => ({ posts: many(posts), })); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content').notNull(), authorId: integer('author_id').notNull(), }); export const postsRelations = relations(posts, ({ one }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id] }), })); ``` ### GraphQL Yoga drizzle-graphql graphql-yoga graphql ```ts copy {1, 10} import { buildSchema } from 'drizzle-graphql'; import { drizzle } from 'drizzle-orm/...'; import { createYoga } from 'graphql-yoga'; import { createServer } from 'node:http'; import * as dbSchema from './schema'; const db = drizzle({ schema: dbSchema }); const { schema } = buildSchema(db); const yoga = createYoga({ schema }); const server = createServer(yoga); server.listen(4000, () => { console.info('Server is running on http://localhost:4000/graphql'); }); ``` ```typescript copy import { integer, serial, text, pgTable } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), }); export const usersRelations = relations(users, ({ many }) => ({ posts: many(posts), })); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content').notNull(), authorId: integer('author_id').notNull(), }); export const postsRelations = relations(posts, ({ one }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id] }), })); ``` ## Customizing schema `buildSchema()` produces schema and types using standard `graphql` SDK, so its output is compatible with any library that supports it. If you want to customize your schema, you can use `entities` object to build your own new schema: ```ts {1, 11} import { buildSchema } from 'drizzle-graphql'; import { drizzle } from 'drizzle-orm/...'; import { GraphQLList, GraphQLNonNull, GraphQLObjectType, GraphQLSchema } from 'graphql'; import { createYoga } from 'graphql-yoga'; import { createServer } from 'node:http'; import * as dbSchema from './schema'; const db = drizzle({ schema: dbSchema }); const { entities } = buildSchema(db); // You can customize which parts of queries or mutations you want const schema = new GraphQLSchema({ query: new GraphQLObjectType({ name: 'Query', fields: { // Select only wanted queries out of all generated users: entities.queries.users, customer: entities.queries.customersSingle, // Create a custom one customUsers: { // You can reuse and customize types from original schema type: new GraphQLList(new GraphQLNonNull(entities.types.UsersItem)), args: { // You can reuse inputs as well where: { type: entities.inputs.UsersFilters }, }, resolve: async (source, args, context, info) => { // Your custom logic goes here... const result = await db.select(schema.users).where()... return result; }, }, }, }), // Same rules apply to mutations mutation: new GraphQLObjectType({ name: 'Mutation', fields: entities.mutations, }), // In case you need types inside your schema types: [...Object.values(entities.types), ...Object.values(entities.inputs)], }); const yoga = createYoga({ schema, }); const server = createServer(yoga); server.listen(4000, () => { console.info('Server is running on http://localhost:4000/graphql'); }) ``` ```typescript copy import { integer, serial, text, pgTable } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), }); export const usersRelations = relations(users, ({ many }) => ({ posts: many(posts), })); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content').notNull(), authorId: integer('author_id').notNull(), }); export const postsRelations = relations(posts, ({ one }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id] }), })); ``` Source: https://orm.drizzle.team/docs/guides import Guides from "@components/Guides.astro"; Source: https://orm.drizzle.team/docs/conditional-filters-in-query import Section from "@mdx/Section.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite); - [Select statement](/docs/select); - [Filtering](/docs/select#filtering) and [Filter operators](/docs/operators); To pass a conditional filter in query you can use `.where()` method and logical operator like below:
```ts copy {9} import { ilike } from 'drizzle-orm'; const db = drizzle(...) const searchPosts = async (term?: string) => { await db .select() .from(posts) .where(term ? ilike(posts.title, term) : undefined); }; await searchPosts(); await searchPosts('AI'); ``` ```sql select * from posts; select * from posts where title ilike 'AI'; ```
To combine conditional filters you can use `and()` or `or()` operators like below:
```ts copy {7,8,9,10,11,12,13} import { and, gt, ilike, inArray } from 'drizzle-orm'; const searchPosts = async (term?: string, categories: string[] = [], views = 0) => { await db .select() .from(posts) .where( and( term ? ilike(posts.title, term) : undefined, categories.length > 0 ? inArray(posts.category, categories) : undefined, views > 100 ? gt(posts.views, views) : undefined, ), ); }; await searchPosts(); await searchPosts('AI', ['Tech', 'Art', 'Science'], 200); ``` ```sql select * from posts; select * from posts where ( title ilike 'AI' and category in ('Tech', 'Science', 'Art') and views > 200 ); ```
If you need to combine conditional filters in different part of the project you can create a variable, push filters and then use it in `.where()` method with `and()` or `or()` operators like below: ```ts copy {7,10} import { SQL, ... } from 'drizzle-orm'; const searchPosts = async (filters: SQL[]) => { await db .select() .from(posts) .where(and(...filters)); }; const filters: SQL[] = []; filters.push(ilike(posts.title, 'AI')); filters.push(inArray(posts.category, ['Tech', 'Art', 'Science'])); filters.push(gt(posts.views, 200)); await searchPosts(filters); ``` Drizzle has useful and flexible API, which lets you create your custom solutions. This is how you can create a custom filter operator:
```ts copy {5,14} import { AnyColumn, ... } from 'drizzle-orm'; // length less than const lenlt = (column: AnyColumn, value: number) => { return sql`length(${column}) < ${value}`; }; const searchPosts = async (maxLen = 0, views = 0) => { await db .select() .from(posts) .where( and( maxLen ? lenlt(posts.title, maxLen) : undefined, views > 100 ? gt(posts.views, views) : undefined, ), ); }; await searchPosts(8); await searchPosts(8, 200); ``` ```sql select * from posts where length(title) < 8; select * from posts where (length(title) < 8 and views > 200); ```
Drizzle filter operators are just SQL expressions under the hood. This is example of how `lt` operator is implemented in Drizzle: ```js const lt = (left, right) => { return sql`${left} < ${bindIfParam(right, left)}`; // bindIfParam is internal magic function }; ``` Source: https://orm.drizzle.team/docs/count-rows import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Callout from '@mdx/Callout.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Select statement](/docs/select) - [Filters](/docs/operators) and [sql operator](/docs/sql) - [Aggregations](/docs/select#aggregations) and [Aggregation helpers](/docs/select#aggregations-helpers) - [Joins](/docs/joins) To count all rows in table you can use `count()` function or `sql` operator like below: ```ts copy {6,9} import { count, sql } from 'drizzle-orm'; import { products } from './schema'; const db = drizzle(...); await db.select({ count: count() }).from(products); // Under the hood, the count() function casts its result to a number at runtime. await db.select({ count: sql`count(*)`.mapWith(Number) }).from(products); ``` ```ts // result type type Result = { count: number; }[]; ``` ```sql select count(*) from products; ``` ```ts import { integer, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const products = pgTable('products', { id: serial('id').primaryKey(), name: text('name').notNull(), discount: integer('discount'), price: integer('price').notNull(), }); ``` To count rows where the specified column contains non-NULL values you can use `count()` function with a column:
```ts copy {1} await db.select({ count: count(products.discount) }).from(products); ``` ```ts // result type type Result = { count: number; }[]; ``` ```sql select count("discount") from products; ```
Drizzle has simple and flexible API, which lets you create your custom solutions. In PostgreSQL and MySQL `count()` function returns bigint, which is interpreted as string by their drivers, so it should be casted to integer:
```ts copy {5,7,11,12} import { AnyColumn, sql } from 'drizzle-orm'; const customCount = (column?: AnyColumn) => { if (column) { return sql`cast(count(${column}) as integer)`; // In MySQL cast to unsigned integer } else { return sql`cast(count(*) as integer)`; // In MySQL cast to unsigned integer } }; await db.select({ count: customCount() }).from(products); await db.select({ count: customCount(products.discount) }).from(products); ``` ```sql select cast(count(*) as integer) from products; select cast(count("discount") as integer) from products; ```
In SQLite, `count()` result returns as integer.
```ts copy {3,4} import { sql } from 'drizzle-orm'; await db.select({ count: sql`count(*)` }).from(products); await db.select({ count: sql`count(${products.discount})` }).from(products); ``` ```sql select count(*) from products; select count("discount") from products; ```
By specifying `sql`, you are telling Drizzle that the **expected** type of the field is `number`.
If you specify it incorrectly (e.g. use `sql` for a field that will be returned as a number), the runtime value won't match the expected type. Drizzle cannot perform any type casts based on the provided type generic, because that information is not available at runtime. If you need to apply runtime transformations to the returned value, you can use the [`.mapWith()`](/docs/sql#sqlmapwith) method.
To count rows that match a condition you can use `.where()` method:
```ts copy {4,6} import { count, gt } from 'drizzle-orm'; await db .select({ count: count() }) .from(products) .where(gt(products.price, 100)); ``` ```sql select count(*) from products where price > 100 ```
This is how you can use `count()` function with joins and aggregations: ```ts copy {8,11,12,13} import { count, eq } from 'drizzle-orm'; import { countries, cities } from './schema'; // Count cities in each country await db .select({ country: countries.name, citiesCount: count(cities.id), }) .from(countries) .leftJoin(cities, eq(countries.id, cities.countryId)) .groupBy(countries.id) .orderBy(countries.name); ``` ```sql select countries.name, count("cities"."id") from countries left join cities on countries.id = cities.country_id group by countries.id order by countries.name; ``` ```ts import { integer, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const countries = pgTable('countries', { id: serial('id').primaryKey(), name: text('name').notNull(), }); export const cities = pgTable('cities', { id: serial('id').primaryKey(), name: text('name').notNull(), countryId: integer('country_id').notNull().references(() => countries.id), }); ``` Source: https://orm.drizzle.team/docs/cursor-based-pagination import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Select statement](/docs/select) with [order by clause](/docs/select#order-by) - [Relational queries](/docs/rqb) with [order by clause](/docs/rqb#order-by) - [Indices](/docs/indexes-constraints) This guide demonstrates how to implement `cursor-based` pagination in Drizzle: ```ts copy {10,11,12} import { asc, gt } from 'drizzle-orm'; import { users } from './schema'; const db = drizzle(...); const nextUserPage = async (cursor?: number, pageSize = 3) => { await db .select() .from(users) .where(cursor ? gt(users.id, cursor) : undefined) // if cursor is provided, get rows after it .limit(pageSize) // the number of rows to return .orderBy(asc(users.id)); // ordering }; // pass the cursor of the last row of the previous page (id) await nextUserPage(3); ``` ```sql select * from users order by id asc limit 3; ``` ```ts // next page, 4-6 rows returned [ { id: 4, firstName: 'Brian', lastName: 'Brown', createdAt: 2024-03-08T12:34:55.182Z }, { id: 5, firstName: 'Beth', lastName: 'Davis', createdAt: 2024-03-08T12:40:55.182Z }, { id: 6, firstName: 'Charlie', lastName: 'Miller', createdAt: 2024-03-08T13:04:55.182Z } ] ``` ```ts copy import { pgTable, serial, text, timestamp } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), firstName: text('first_name').notNull(), lastName: text('last_name').notNull(), createdAt: timestamp('created_at').notNull().defaultNow(), }); ``` ```plaintext +----+------------+------------+----------------------------+ | id | first_name | last_name | created_at | +----+------------+------------+----------------------------+ | 1 | Alice | Johnson | 2024-03-08 12:23:55.251797 | +----+------------+------------+----------------------------+ | 2 | Alex | Smith | 2024-03-08 12:25:55.182 | +----+------------+------------+----------------------------+ | 3 | Aaron | Williams | 2024-03-08 12:28:55.182 | +----+------------+------------+----------------------------+ | 4 | Brian | Brown | 2024-03-08 12:34:55.182 | +----+------------+------------+----------------------------+ | 5 | Beth | Davis | 2024-03-08 12:40:55.182 | +----+------------+------------+----------------------------+ | 6 | Charlie | Miller | 2024-03-08 13:04:55.182 | +----+------------+------------+----------------------------+ | 7 | Clara | Wilson | 2024-03-08 13:22:55.182 | +----+------------+------------+----------------------------+ | 8 | David | Moore | 2024-03-08 13:34:55.182 | +----+------------+------------+----------------------------+ | 9 | Aaron | Anderson | 2024-03-08 12:40:33.677235 | +----+------------+------------+----------------------------+ ``` If you need dynamic order by you can do like below: ```ts copy {6,8} const nextUserPage = async (order: 'asc' | 'desc' = 'asc', cursor?: number, pageSize = 3) => { await db .select() .from(users) // cursor comparison .where(cursor ? (order === 'asc' ? gt(users.id, cursor) : lt(users.id, cursor)) : undefined) .limit(pageSize) .orderBy(order === 'asc' ? asc(users.id) : desc(users.id)); }; await nextUserPage(); await nextUserPage('asc', 3); // descending order await nextUserPage('desc'); await nextUserPage('desc', 7); ``` The main idea of this pagination is to use cursor as a pointer to a specific row in a dataset, indicating the end of the previous page. For correct ordering and cursor comparison, cursor should be unique and sequential. If you need to order by a non-unique and non-sequential column, you can use multiple columns for cursor. This is how you can do it:
```ts copy {14,15,16,17,18,19,22} import { and, asc, eq, gt, or } from 'drizzle-orm'; const nextUserPage = async ( cursor?: { id: number; firstName: string; }, pageSize = 3, ) => { await db .select() .from(users) .where( cursor ? or( gt(users.firstName, cursor.firstName), and(eq(users.firstName, cursor.firstName), gt(users.id, cursor.id)), ) : undefined, ) .limit(pageSize) .orderBy(asc(users.firstName), asc(users.id)); }; // pass the cursor from previous page (id & firstName) await nextUserPage({ id: 2, firstName: 'Alex', }); ``` ```sql select * from users where (first_name > 'Alex' or (first_name = 'Alex' and id > 2)) order by first_name asc, id asc limit 3; ``` ```ts // next page, 4-6 rows returned [ { id: 1, firstName: 'Alice', lastName: 'Johnson', createdAt: 2024-03-08T12:23:55.251Z }, { id: 5, firstName: 'Beth', lastName: 'Davis', createdAt: 2024-03-08T12:40:55.182Z }, { id: 4, firstName: 'Brian', lastName: 'Brown', createdAt: 2024-03-08T12:34:55.182Z } ] ```
Make sure to create indices for the columns that you use for cursor to make query efficient.
```ts copy {7,8} import { index, ...imports } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { // columns declaration }, (t) => [ index('first_name_index').on(t.firstName).asc(), index('first_name_and_id_index').on(t.firstName, t.id).asc(), ]); ``` ```sql -- As of now drizzle-kit only supports index name and on() param, so you have to add order manually CREATE INDEX IF NOT EXISTS "first_name_index" ON "users" ("first_name" ASC); CREATE INDEX IF NOT EXISTS "first_name_and_id_index" ON "users" ("first_name" ASC,"id" ASC); ```
If you are using primary key which is not sequential (e.g. `UUIDv4`), you should add sequential column (e.g. `created_at` column) and use multiple cursor. This is how you can do it:
```ts copy {12,13,14,15,16,17,18,21} const nextUserPage = async ( cursor?: { id: string; createdAt: Date; }, pageSize = 3, ) => { await db .select() .from(users) .where( // make sure to add indices for the columns that you use for cursor cursor ? or( gt(users.createdAt, cursor.createdAt), and(eq(users.createdAt, cursor.createdAt), gt(users.id, cursor.id)), ) : undefined, ) .limit(pageSize) .orderBy(asc(users.createdAt), asc(users.id)); }; // pass the cursor from previous page (id & createdAt) await nextUserPage({ id: '66ed00a4-c020-4dfd-a1ca-5d2e4e54d174', createdAt: new Date('2024-03-09T17:59:36.406Z'), }); ```
Drizzle has useful relational queries API, that lets you easily implement `cursor-based` pagination: ```ts copy {7,8,9} import * as schema from './db/schema'; const db = drizzle(..., { schema }); const nextUserPage = async (cursor?: number, pageSize = 3) => { await db.query.users.findMany({ where: (users, { gt }) => (cursor ? gt(users.id, cursor) : undefined), orderBy: (users, { asc }) => asc(users.id), limit: pageSize, }); }; // next page, cursor of last row of the first page (id = 3) await nextUserPage(3); ``` **Benefits** of `cursor-based` pagination: consistent query results, with no skipped or duplicated rows due to insert or delete operations, and greater efficiency compared to `limit/offset` pagination because it does not need to scan and skip previous rows to access the next page. **Drawbacks** of `cursor-based` pagination: the inability to directly navigate to a specific page and complexity of implementation. Since you add more columns to the sort order, you'll need to add more filters to the `where` clause for the cursor comparison to ensure consistent pagination. So, if you need to directly navigate to a specific page or you need simpler implementation of pagination, you should consider using [offset/limit](/docs/guides/limit-offset-pagination) pagination instead. Source: https://orm.drizzle.team/docs/d1-http-with-drizzle-kit import Prerequisites from "@mdx/Prerequisites.astro"; - [Drizzle Kit](/docs/kit-overview) - [Drizzle Studio](/docs/kit-overview#drizzle-studio) - [Drizzle Chrome Extension](https://chromewebstore.google.com/detail/drizzle-studio/mjkojjodijpaneehkgmeckeljgkimnmd) - You should have installed `drizzle-kit@0.21.3` or higher - You should have [Cloudflare account](https://dash.cloudflare.com/login), deployed [D1 database](https://developers.cloudflare.com/d1/) and token with D1 edit permissions To use Drizzle kit with Cloudflare D1 HTTP API, you need to configure the `drizzle.config.ts` file like this: ```ts copy filename="drizzle.config.ts" {7, 9-11} import { defineConfig } from 'drizzle-kit'; export default defineConfig({ schema: './src/schema.ts', out: './migrations', dialect: 'sqlite', driver: 'd1-http', dbCredentials: { accountId: process.env.CLOUDFLARE_ACCOUNT_ID!, databaseId: process.env.CLOUDFLARE_DATABASE_ID!, token: process.env.CLOUDFLARE_D1_TOKEN!, }, }); ``` You can find `accountId`, `databaseId` and `token` in [Cloudflare dashboard](https://dash.cloudflare.com/login?). 1. To get `accountId` go to **Workers & Pages** -> **Overview** -> copy **Account ID** from the right sidebar. 2. To get `databaseId` open D1 database you want to connect to and copy **Database ID**. 3. To get `token` go to **My profile** -> **API Tokens** and create token with D1 edit permissions. After you have configured `drizzle.config.ts` file, Drizzle Kit lets you run `migrate`, `push`, `introspect` and `studio` commands using Cloudflare D1 HTTP API. You can also use [Drizzle Chrome Extension](https://chromewebstore.google.com/detail/drizzle-studio/mjkojjodijpaneehkgmeckeljgkimnmd) to browse Cloudflare D1 database directly in their admin panel. Source: https://orm.drizzle.team/docs/decrementing-a-value import Section from "@mdx/Section.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Update statement](/docs/update) - [Filters](/docs/operators) and [sql operator](/docs/sql) To decrement a column value you can use `update().set()` method like below:
```ts copy {8} import { eq, sql } from 'drizzle-orm'; const db = drizzle(...) await db .update(table) .set({ counter: sql`${table.counter} - 1`, }) .where(eq(table.id, 1)); ``` ```sql update "table" set "counter" = "counter" - 1 where "id" = 1; ```
Drizzle has simple and flexible API, which lets you easily create custom solutions. This is how you do custom decrement function: ```ts copy {4,10,11} import { AnyColumn } from 'drizzle-orm'; const decrement = (column: AnyColumn, value = 1) => { return sql`${column} - ${value}`; }; await db .update(table) .set({ counter1: decrement(table.counter1), counter2: decrement(table.counter2, 10), }) .where(eq(table.id, 1)); ``` Source: https://orm.drizzle.team/docs/empty-array-default-value import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - Learn about column data types for [PostgreSQL](/docs/column-types/pg), [MySQL](/docs/column-types/mysql) and [SQLite](/docs/column-types/sqlite) - [sql operator](/docs/sql) ### PostgreSQL To set an empty array as a default value in PostgreSQL, you can use `sql` operator with `'{}'` or `ARRAY[]` syntax:
```ts copy {10,14} import { sql } from 'drizzle-orm'; import { pgTable, serial, text } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), tags1: text('tags1') .array() .notNull() .default(sql`'{}'::text[]`), tags2: text('tags2') .array() .notNull() .default(sql`ARRAY[]::text[]`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "users" ( "id" serial PRIMARY KEY NOT NULL, "name" text NOT NULL, "tags1" text[] DEFAULT '{}'::text[] NOT NULL, "tags2" text[] DEFAULT ARRAY[]::text[] NOT NULL ); ```
### MySQL MySQL doesn't have an array data type, but you can use `json` data type for the same purpose. To set an empty array as a default value in MySQL, you can use `JSON_ARRAY()` function or `sql` operator with `('[]')` syntax:
```ts copy {7,11,15} import { sql } from 'drizzle-orm'; import { json, mysqlTable, serial, varchar } from 'drizzle-orm/mysql-core'; export const users = mysqlTable('users', { id: serial('id').primaryKey(), name: varchar('name', { length: 255 }).notNull(), tags1: json('tags1').$type().notNull().default([]), tags2: json('tags2') .$type() .notNull() .default(sql`('[]')`), // the same as default([]) tags3: json('tags3') .$type() .notNull() .default(sql`(JSON_ARRAY())`), }); ``` ```sql CREATE TABLE `users` ( `id` serial AUTO_INCREMENT NOT NULL, `name` varchar(255) NOT NULL, `tags1` json NOT NULL DEFAULT ('[]'), `tags2` json NOT NULL DEFAULT ('[]'), `tags3` json NOT NULL DEFAULT (JSON_ARRAY()), CONSTRAINT `users_id` PRIMARY KEY(`id`) ); ```
The `mode` option defines how values are handled in the application. With `json` mode, values are treated as JSON object literal. You can specify `.$type<..>()` for json object inference, it will not check runtime values. It provides compile time protection for default values, insert and select schemas. ### SQLite SQLite doesn't have an array data type, but you can use `text` data type for the same purpose. To set an empty array as a default value in SQLite, you can use `json_array()` function or `sql` operator with `'[]'` syntax:
```ts copy {9,13} import { sql } from 'drizzle-orm'; import { integer, sqliteTable, text } from 'drizzle-orm/sqlite-core'; export const users = sqliteTable('users', { id: integer('id').primaryKey(), tags1: text('tags1', { mode: 'json' }) .notNull() .$type() .default(sql`(json_array())`), tags2: text('tags2', { mode: 'json' }) .notNull() .$type() .default(sql`'[]'`), }); ``` ```sql CREATE TABLE `users` ( `id` integer PRIMARY KEY NOT NULL, `tags1` text DEFAULT (json_array()) NOT NULL, `tags2` text DEFAULT '[]' NOT NULL ); ```
The `mode` option defines how values are handled in the application. With `json` mode, values are treated as JSON object literal. You can specify `.$type<..>()` for json object inference, it will not check runtime values. It provides compile time protection for default values, insert and select schemas. Source: https://orm.drizzle.team/docs/full-text-search-with-generated-columns import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql) - [Select statement](/docs/select) - [Indexes](/docs/indexes-constraints#indexes) - [sql operator](/docs/sql) - [Full-text search](/learn/guides/postgresql-full-text-search) - [Generated columns](/docs/generated-columns) This guide demonstrates how to implement full-text search in PostgreSQL with Drizzle and generated columns. A generated column is a special column that is always computed from other columns. It is useful because you don't have to compute the value of the column every time you query the table: ```ts copy {18,19,20,23} import { SQL, sql } from 'drizzle-orm'; import { index, pgTable, serial, text, customType } from 'drizzle-orm/pg-core'; export const tsvector = customType<{ data: string; }>({ dataType() { return `tsvector`; }, }); export const posts = pgTable( 'posts', { id: serial('id').primaryKey(), title: text('title').notNull(), body: text('body').notNull(), bodySearch: tsvector('body_search') .notNull() .generatedAlwaysAs((): SQL => sql`to_tsvector('english', ${posts.body})`), }, (t) => [ index('idx_body_search').using('gin', t.bodySearch), ] ); ``` ```sql CREATE TABLE "posts" ( "id" serial PRIMARY KEY NOT NULL, "title" text NOT NULL, "body" text NOT NULL, "body_search" "tsvector" GENERATED ALWAYS AS (to_tsvector('english', "posts"."body")) STORED NOT NULL ); --> statement-breakpoint CREATE INDEX "idx_body_search" ON "posts" USING gin ("body_search"); ``` When you insert a row into a table, the value of a generated column is computed from an expression that you provide when you create the column:
```ts import { posts } from './schema'; const db = drizzle(...); const body = "Golden leaves cover the quiet streets as a crisp breeze fills the air, bringing the scent of rain and the promise of change" await db.insert(posts).values({ body, title: "The Beauty of Autumn", } ).returning(); ``` ```json [ { id: 1, title: 'The Beauty of Autumn', body: 'Golden leaves cover the quiet streets as a crisp breeze fills the air, bringing the scent of rain and the promise of change', bodySearch: "'air':13 'breez':10 'bring':14 'chang':23 'cover':3 'crisp':9 'fill':11 'golden':1 'leav':2 'promis':21 'quiet':5 'rain':18 'scent':16 'street':6" } ] ```
This is how you can implement full-text search with generated columns in PostgreSQL with Drizzle ORM. The `@@` operator is used for direct matches:
```ts copy {6} const searchParam = "bring"; await db .select() .from(posts) .where(sql`${posts.bodySearch} @@ to_tsquery('english', ${searchParam})`); ``` ```sql select * from posts where body_search @@ to_tsquery('english', 'bring'); ```
This is more advanced schema with a generated column. The `search` column is generated from the `title` and `body` columns and `setweight()` function is used to assign different weights to the columns for full-text search. This is typically used to mark entries coming from different parts of a document, such as title versus body. ```ts copy {18,19,20,21,22,23,24,28} import { SQL, sql } from 'drizzle-orm'; import { index, pgTable, serial, text, customType } from 'drizzle-orm/pg-core'; export const tsvector = customType<{ data: string; }>({ dataType() { return `tsvector`; }, }); export const posts = pgTable( 'posts', { id: serial('id').primaryKey(), title: text('title').notNull(), body: text('body').notNull(), search: tsvector('search') .notNull() .generatedAlwaysAs( (): SQL => sql`setweight(to_tsvector('english', ${posts.title}), 'A') || setweight(to_tsvector('english', ${posts.body}), 'B')`, ), }, (t) => [ index('idx_search').using('gin', t.search), ], ); ``` ```sql CREATE TABLE "posts" ( "id" serial PRIMARY KEY NOT NULL, "title" text NOT NULL, "body" text NOT NULL, "search" "tsvector" GENERATED ALWAYS AS (setweight(to_tsvector('english', "posts"."title"), 'A') || setweight(to_tsvector('english', "posts"."body"), 'B')) STORED NOT NULL ); --> statement-breakpoint CREATE INDEX "idx_search" ON "posts" USING gin ("search"); ``` This is how you can query the table with full-text search:
```ts copy {6} const search = 'travel'; await db .select() .from(posts) .where(sql`${posts.search} @@ to_tsquery('english', ${search})`); ``` ```sql select * from posts where search @@ to_tsquery('english', 'travel'); ```
Source: https://orm.drizzle.team/docs/include-or-exclude-columns import Section from "@mdx/Section.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Select statement](/docs/select) - [Get typed table columns](/docs/goodies#get-typed-table-columns) - [Joins](/docs/joins) - [Relational queries](/docs/rqb) - [Partial select with relational queries](/docs/rqb#partial-fields-select) Drizzle has flexible API for including or excluding columns in queries. To include all columns you can use `.select()` method like this: ```ts copy {5} import { posts } from './schema'; const db = drizzle(...); await db.select().from(posts); ``` ```ts // result type type Result = { id: number; title: string; content: string; views: number; }[]; ``` ```ts copy import { integer, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const posts = pgTable('posts', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), views: integer('views').notNull().default(0), }); ``` To include specific columns you can use `.select()` method like this:
```ts copy {1} await db.select({ title: posts.title }).from(posts); ``` ```ts // result type type Result = { title: string; }[]; ```
To include all columns with extra columns you can use `getTableColumns()` utility function like this:
```ts copy {5,6} import { getTableColumns, sql } from 'drizzle-orm'; await db .select({ ...getTableColumns(posts), titleLength: sql`length(${posts.title})`, }) .from(posts); ``` ```ts // result type type Result = { id: number; title: string; content: string; views: number; titleLength: number; }[]; ```
To exclude columns you can use `getTableColumns()` utility function like this:
```ts copy {3,5} import { getTableColumns } from 'drizzle-orm'; const { content, ...rest } = getTableColumns(posts); // exclude "content" column await db.select({ ...rest }).from(posts); // select all other columns ``` ```ts // result type type Result = { id: number; title: string; views: number; }[]; ```
This is how you can include or exclude columns with joins: ```ts copy {5,9,10,11} import { eq, getTableColumns } from 'drizzle-orm'; import { comments, posts, users } from './db/schema'; // exclude "userId" and "postId" columns from "comments" const { userId, postId, ...rest } = getTableColumns(comments); await db .select({ postId: posts.id, // include "id" column from "posts" comment: { ...rest }, // include all other columns user: users, // equivalent to getTableColumns(users) }) .from(posts) .leftJoin(comments, eq(posts.id, comments.postId)) .leftJoin(users, eq(users.id, posts.userId)); ``` ```ts // result type type Result = { postId: number; comment: { id: number; content: string; createdAt: Date; } | null; user: { id: number; name: string; email: string; } | null; }[]; ``` ```ts copy import { integer, pgTable, serial, text, timestamp } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), email: text('email').notNull(), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), views: integer('views').notNull().default(0), userId: integer('user_id').notNull().references(() => users.id), }); export const comments = pgTable('comments', { id: serial('id').primaryKey(), postId: integer('post_id').notNull().references(() => posts.id), userId: integer('user_id').notNull().references(() => users.id), content: text('content').notNull(), createdAt: timestamp('created_at').notNull().defaultNow(), }); ``` Drizzle has useful relational queries API, that lets you easily include or exclude columns in queries. This is how you can include all columns: ```ts copy {5,7,8,9,12,13,14,17,18,19,20,21,22} import * as schema from './schema'; const db = drizzle(..., { schema }); await db.query.posts.findMany(); ``` ```ts // result type type Result = { id: number; title: string; content: string; views: number; }[] ``` ```ts copy import { integer, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const posts = pgTable('posts', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), views: integer('views').notNull().default(0), }); ``` This is how you can include specific columns using relational queries:
```ts copy {2,3,4} await db.query.posts.findMany({ columns: { title: true, }, }); ``` ```ts // result type type Result = { title: string; }[] ```
This is how you can include all columns with extra columns using relational queries:
```ts copy {4,5,6} import { sql } from 'drizzle-orm'; await db.query.posts.findMany({ extras: { titleLength: sql`length(${posts.title})`.as('title_length'), }, }); ``` ```ts // result type type Result = { id: number; title: string; content: string; views: number; titleLength: number; }[]; ```
This is how you can exclude columns using relational queries:
```ts copy {2,3,4} await db.query.posts.findMany({ columns: { content: false, }, }); ``` ```ts // result type type Result = { id: number; title: string; views: number; }[] ```
This is how you can include or exclude columns with relations using relational queries: ```ts copy {7,12,13,16} import * as schema from './schema'; const db = drizzle(..., { schema }); await db.query.posts.findMany({ columns: { id: true, // include "id" column }, with: { comments: { columns: { userId: false, // exclude "userId" column postId: false, // exclude "postId" column }, }, user: true, // include all columns from "users" table }, }); ``` ```ts // result type type Result = { id: number; user: { id: number; name: string; email: string; }; comments: { id: number; content: string; createdAt: Date; }[]; }[] ``` ```ts copy import { relations } from 'drizzle-orm'; import { integer, pgTable, serial, text, timestamp } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), email: text('email').notNull(), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), views: integer('views').notNull().default(0), userId: integer('user_id').notNull().references(() => users.id), }); export const comments = pgTable('comments', { id: serial('id').primaryKey(), postId: integer('post_id').notNull().references(() => posts.id), userId: integer('user_id').notNull().references(() => users.id), content: text('content').notNull(), createdAt: timestamp('created_at').notNull().defaultNow(), }); export const usersRelations = relations(users, ({ many }) => ({ posts: many(posts), comments: many(comments), })); export const postsRelations = relations(posts, ({ many, one }) => ({ comments: many(comments), user: one(users, { fields: [posts.userId], references: [users.id] }), })); export const commentsRelations = relations(comments, ({ one }) => ({ post: one(posts, { fields: [comments.postId], references: [posts.id] }), user: one(users, { fields: [comments.userId], references: [users.id] }), })); ``` This is how you can create custom solution for conditional select: ```ts copy {7} import { posts } from './schema'; const searchPosts = async (withTitle = false) => { await db .select({ id: posts.id, ...(withTitle && { title: posts.title }), }) .from(posts); }; await searchPosts(); await searchPosts(true); ``` ```ts // result type type Result = { id: number; title?: string | undefined; }[]; ``` ```ts copy import { integer, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const posts = pgTable('posts', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), views: integer('views').notNull().default(0), }); ``` Source: https://orm.drizzle.team/docs/incrementing-a-value import Section from "@mdx/Section.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Update statement](/docs/update) - [Filters](/docs/operators) and [sql operator](/docs/sql) To increment a column value you can use `update().set()` method like below:
```ts copy {8} import { eq, sql } from 'drizzle-orm'; const db = drizzle(...) await db .update(table) .set({ counter: sql`${table.counter} + 1`, }) .where(eq(table.id, 1)); ``` ```sql update "table" set "counter" = "counter" + 1 where "id" = 1; ```
Drizzle has simple and flexible API, which lets you easily create custom solutions. This is how you do custom increment function: ```ts copy {4,10,11} import { AnyColumn } from 'drizzle-orm'; const increment = (column: AnyColumn, value = 1) => { return sql`${column} + ${value}`; }; await db .update(table) .set({ counter1: increment(table.counter1), counter2: increment(table.counter2, 10), }) .where(eq(table.id, 1)); ``` Source: https://orm.drizzle.team/docs/limit-offset-pagination import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Select statement](/docs/select) with [order by clause](/docs/select#order-by) and [limit & offset clauses](/docs/select#limit--offset) - [Relational queries](/docs/rqb) with [order by clause](/docs/rqb#order-by) and [limit & offset clauses](/docs/rqb#limit--offset) - [Dynamic query building](/docs/dynamic-query-building) This guide demonstrates how to implement `limit/offset` pagination in Drizzle: ```ts copy {9,10,11} import { asc } from 'drizzle-orm'; import { users } from './schema'; const db = drizzle(...); await db .select() .from(users) .orderBy(asc(users.id)) // order by is mandatory .limit(4) // the number of rows to return .offset(4); // the number of rows to skip ``` ```sql select * from users order by id asc limit 4 offset 4; ``` ```ts // 5-8 rows returned [ { id: 5, firstName: 'Beth', lastName: 'Davis', createdAt: 2024-03-11T20:51:46.787Z }, { id: 6, firstName: 'Charlie', lastName: 'Miller', createdAt: 2024-03-11T21:15:46.787Z }, { id: 7, firstName: 'Clara', lastName: 'Wilson', createdAt: 2024-03-11T21:33:46.787Z }, { id: 8, firstName: 'David', lastName: 'Moore', createdAt: 2024-03-11T21:45:46.787Z } ] ``` ```ts copy import { pgTable, serial, text, timestamp } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), firstName: text('first_name').notNull(), lastName: text('last_name').notNull(), createdAt: timestamp('created_at').notNull().defaultNow(), }); ``` ```plaintext +----+------------+-----------+----------------------------+ | id | first_name | last_name | created_at | +----+------------+-----------+----------------------------+ | 1 | Alice | Johnson | 2024-03-08 12:23:55.251797 | +----+------------+-----------+----------------------------+ | 2 | Alex | Smith | 2024-03-08 12:25:55.182 | +----+------------+-----------+----------------------------+ | 3 | Aaron | Williams | 2024-03-08 12:28:55.182 | +----+------------+-----------+----------------------------+ | 4 | Brian | Brown | 2024-03-08 12:34:55.182 | +----+------------+-----------+----------------------------+ | 5 | Beth | Davis | 2024-03-08 12:40:55.182 | +----+------------+-----------+----------------------------+ | 6 | Charlie | Miller | 2024-03-08 13:04:55.182 | +----+------------+-----------+----------------------------+ | 7 | Clara | Wilson | 2024-03-08 13:22:55.182 | +----+------------+-----------+----------------------------+ | 8 | David | Moore | 2024-03-08 13:34:55.182 | +----+------------+-----------+----------------------------+ ``` Limit is the number of rows to return `(page size)` and offset is the number of rows to skip `((page number - 1) * page size)`. For consistent pagination, ensure ordering by a unique column. Otherwise, the results can be inconsistent. If you need to order by a non-unique column, you should also append a unique column to the ordering. This is how you can implement `limit/offset` pagination with 2 columns:
```ts copy {5} const getUsers = async (page = 1, pageSize = 3) => { await db .select() .from(users) .orderBy(asc(users.firstName), asc(users.id)) // order by first_name (non-unique), id (pk) .limit(pageSize) .offset((page - 1) * pageSize); } await getUsers(); ```
Drizzle has useful relational queries API, that lets you easily implement `limit/offset` pagination:
```ts copy {7,8,9} import * as schema from './db/schema'; const db = drizzle({ schema }); const getUsers = async (page = 1, pageSize = 3) => { await db.query.users.findMany({ orderBy: (users, { asc }) => asc(users.id), limit: pageSize, offset: (page - 1) * pageSize, }); }; await getUsers(); ```
Drizzle has simple and flexible API, which lets you easily create custom solutions. This is how you can create custom function for pagination using `.$dynamic()` function:
```ts copy {11,12,13,16} import { SQL, asc } from 'drizzle-orm'; import { PgColumn, PgSelect } from 'drizzle-orm/pg-core'; function withPagination( qb: T, orderByColumn: PgColumn | SQL | SQL.Aliased, page = 1, pageSize = 3, ) { return qb .orderBy(orderByColumn) .limit(pageSize) .offset((page - 1) * pageSize); } const query = db.select().from(users); // query that you want to execute with pagination await withPagination(query.$dynamic(), asc(users.id)); ```
You can improve performance of `limit/offset` pagination by using `deferred join` technique. This method performs the pagination on a subset of the data instead of the entire table. To implement it you can do like this: ```ts copy {10} const getUsers = async (page = 1, pageSize = 10) => { const sq = db .select({ id: users.id }) .from(users) .orderBy(users.id) .limit(pageSize) .offset((page - 1) * pageSize) .as('subquery'); await db.select().from(users).innerJoin(sq, eq(users.id, sq.id)).orderBy(users.id); }; ``` **Benefits** of `limit/offset` pagination: it's simple to implement and pages are easily reachable, which means that you can navigate to any page without having to save the state of the previous pages. **Drawbacks** of `limit/offset` pagination: degradation in query performance with increasing offset because database has to scan all rows before the offset to skip them, and inconsistency due to data shifts, which can lead to the same row being returned on different pages or rows being skipped. This is how it works:
```ts copy const getUsers = async (page = 1, pageSize = 3) => { await db .select() .from(users) .orderBy(asc(users.id)) .limit(pageSize) .offset((page - 1) * pageSize); }; // user is browsing the first page await getUsers(); ``` ```ts // results for the first page [ { id: 1, firstName: 'Alice', lastName: 'Johnson', createdAt: 2024-03-10T17:17:06.148Z }, { id: 2, firstName: 'Alex', lastName: 'Smith', createdAt: 2024-03-10T17:19:06.147Z }, { id: 3, firstName: 'Aaron', lastName: 'Williams', createdAt: 2024-03-10T17:22:06.147Z } ] ``` ```ts // while user is browsing the first page, a row with id 2 is deleted await db.delete(users).where(eq(users.id, 2)); // user navigates to the second page await getUsers(2); ``` ```ts // second page, row with id 3 was skipped [ { id: 5, firstName: 'Beth', lastName: 'Davis', createdAt: 2024-03-10T17:34:06.147Z }, { id: 6, firstName: 'Charlie', lastName: 'Miller', createdAt: 2024-03-10T17:58:06.147Z }, { id: 7, firstName: 'Clara', lastName: 'Wilson', createdAt: 2024-03-10T18:16:06.147Z } ] ```
So, if your database experiences frequently insert and delete operations in real time or you need high performance to paginate large tables, you should consider using [cursor-based](/docs/guides/cursor-based-pagination) pagination instead. To learn more about `deferred join` technique you should follow these guides: [Planetscale Pagination Guide](https://planetscale.com/blog/mysql-pagination) and [Efficient Pagination Guide by Aaron Francis](https://aaronfrancis.com/2022/efficient-pagination-using-deferred-joins). Source: https://orm.drizzle.team/docs/mysql-local-setup import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Steps from '@mdx/Steps.astro'; - Install latest [Docker Desktop](https://www.docker.com/products/docker-desktop/). Follow the instructions for your operating system. #### Pull the MySQL image Pull the latest MySQL image from Docker Hub. In your terminal, run `docker pull mysql` to pull the latest MySQL version from Docker Hub: ```bash copy docker pull mysql ``` Alternatively, you can pull preferred version with a specific tag: ```bash copy docker pull mysql:8.2 ``` When MySQL image is downloaded, you can check it in `Images` tab in Docker Desktop or by running `docker images`:
```bash copy docker images ``` ```plaintext REPOSITORY TAG IMAGE ID CREATED SIZE mysql latest 4e8a34aea708 2 months ago 609MB ```
#### Start a MySQL instance To start a new MySQL container, run the following command: ```bash copy docker run --name drizzle-mysql -e MYSQL_ROOT_PASSWORD=mypassword -d -p 3306:3306 mysql ``` 1. The `--name` option assigns the container the name `drizzle-mysql`. 2. The `-e MYSQL_ROOT_PASSWORD=` option sets the `MYSQL_ROOT_PASSWORD` environment variable with the specified value. This is password for the root user. 3. The `-d` flag runs the container in detached mode (in the background). 4. The `-p` option maps port `3306` on the container to port `3306` on your host machine, allowing MySQL to be accessed from your host system through this port. 5. The `mysql` argument specifies the image to use for the container. You can also specify other versions like `mysql:8.2`. You can also specify other parameters like: 1. `-e MYSQL_DATABASE=` to create a new database when the container is created. Default is `mysql`. 2. `-e MYSQL_USER=` and `-e MYSQL_PASSWORD=` to create a new user with a password when the container is created. But you still need to specify `MYSQL_ROOT_PASSWORD` for `root` user. To check if the container is running, check `Containers` tab in Docker Desktop or use the `docker ps` command: ```plaintext CONTAINER ID IMAGE COMMAND CREATED STATUS PORTS NAMES 19506a8dc12b mysql "docker-entrypoint.s…" 4 seconds ago Up 3 seconds 33060/tcp, 0.0.0.0:3306->3306/tcp drizzle-mysql ``` #### Configure database url To connect to the MySQL database, you need to provide the database URL. The URL format is: ```plaintext mysql://:@:/ ``` You should replace placeholders with your actual values. For example, for created container the url will be: ```plaintext mysql://root:mypassword@localhost:3306/mysql ``` Now you can connect to the database using the URL in your application.
Source: https://orm.drizzle.team/docs/point-datatype-psql import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql) - [Point datatype](/docs/column-types/pg#point) - [Filtering in select statement](/docs/select#filtering) - [sql operator](/docs/sql) PostgreSQL has a special datatype to store geometric data called `point`. It is used to represent a point in a two-dimensional space. The point datatype is represented as a pair of `(x, y)` coordinates. The point expects to receive longitude first, followed by latitude.
```ts copy {6} import { sql } from 'drizzle-orm'; const db = drizzle(...); await db.execute( sql`select point(-90.9, 18.7)`, ); ``` ```json [ { point: '(-90.9,18.7)' } ] ```
This is how you can create table with `point` datatype in Drizzle: ```ts {6} import { pgTable, point, serial, text } from 'drizzle-orm/pg-core'; export const stores = pgTable('stores', { id: serial('id').primaryKey(), name: text('name').notNull(), location: point('location', { mode: 'xy' }).notNull(), }); ``` This is how you can insert point data into the table in Drizzle: ```ts {4, 10, 16} // mode: 'xy' await db.insert(stores).values({ name: 'Test', location: { x: -90.9, y: 18.7 }, }); // mode: 'tuple' await db.insert(stores).values({ name: 'Test', location: [-90.9, 18.7], }); // sql raw await db.insert(stores).values({ name: 'Test', location: sql`point(-90.9, 18.7)`, }); ``` To compute the distance between the objects you can use `<->` operator. This is how you can query for the nearest location by coordinates in Drizzle:
```ts {9, 14, 17} import { getTableColumns, sql } from 'drizzle-orm'; import { stores } from './schema'; const point = { x: -73.935_242, y: 40.730_61, }; const sqlDistance = sql`location <-> point(${point.x}, ${point.y})`; await db .select({ ...getTableColumns(stores), distance: sql`round((${sqlDistance})::numeric, 2)`, }) .from(stores) .orderBy(sqlDistance) .limit(1); ``` ```sql select *, round((location <-> point(-73.935242, 40.73061))::numeric, 2) from stores order by location <-> point(-73.935242, 40.73061) limit 1; ```
To filter rows to include only those where a `point` type `location` falls within a specified rectangular boundary defined by two diagonal points you can user `<@` operator. It checks if the first object is contained in or on the second object:
```ts {12} const point = { x1: -88, x2: -73, y1: 40, y2: 43, }; await db .select() .from(stores) .where( sql`${stores.location} <@ box(point(${point.x1}, ${point.y1}), point(${point.x2}, ${point.y2}))` ); ``` ```sql select * from stores where location <@ box(point(-88, 40), point(-73, 43)); ```
Source: https://orm.drizzle.team/docs/postgis-geometry-point import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql) - [Postgis extension](/docs/extensions/pg#postgis) - [Indexes](/docs/indexes-constraints#indexes) - [Filtering in select statement](/docs/select#filtering) - [sql operator](/docs/sql) `PostGIS` extends the capabilities of the PostgreSQL relational database by adding support for storing, indexing, and querying geospatial data. As for now, Drizzle doesn't create extension automatically, so you need to create it manually. Create an empty migration file and add SQL query:
```bash npx drizzle-kit generate --custom ``` ```sql CREATE EXTENSION postgis; ```
This is how you can create table with `geometry` datatype and spatial index in Drizzle: ```ts copy {8, 11} import { geometry, index, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const stores = pgTable( 'stores', { id: serial('id').primaryKey(), name: text('name').notNull(), location: geometry('location', { type: 'point', mode: 'xy', srid: 4326 }).notNull(), }, (t) => [ index('spatial_index').using('gist', t.location), ] ); ``` ```sql CREATE TABLE IF NOT EXISTS "stores" ( "id" serial PRIMARY KEY NOT NULL, "name" text NOT NULL, "location" geometry(point) NOT NULL ); --> statement-breakpoint CREATE INDEX IF NOT EXISTS "spatial_index" ON "stores" USING gist ("location"); ``` This is how you can insert `geometry` data into the table in Drizzle. `ST_MakePoint()` in PostGIS creates a geometric object of type `point` using the specified coordinates. `ST_SetSRID()` sets the `SRID` (unique identifier associated with a specific coordinate system, tolerance, and resolution) on a geometry to a particular integer value: ```ts {4, 10, 16} // mode: 'xy' await db.insert(stores).values({ name: 'Test', location: { x: -90.9, y: 18.7 }, }); // mode: 'tuple' await db.insert(stores).values({ name: 'Test', location: [-90.9, 18.7], }); // sql raw await db.insert(stores).values({ name: 'Test', location: sql`ST_SetSRID(ST_MakePoint(-90.9, 18.7), 4326)`, }); ``` To compute the distance between the objects you can use `<->` operator and `ST_Distance()` function, which for `geometry types` returns the minimum planar distance between two geometries. This is how you can query for the nearest location by coordinates in Drizzle with PostGIS:
```ts copy {9, 14, 17} import { getTableColumns, sql } from 'drizzle-orm'; import { stores } from './schema'; const point = { x: -73.935_242, y: 40.730_61, }; const sqlPoint = sql`ST_SetSRID(ST_MakePoint(${point.x}, ${point.y}), 4326)`; await db .select({ ...getTableColumns(stores), distance: sql`ST_Distance(${stores.location}, ${sqlPoint})`, }) .from(stores) .orderBy(sql`${stores.location} <-> ${sqlPoint}`) .limit(1); ``` ```sql select *, ST_Distance(location, ST_SetSRID(ST_MakePoint(-73.935_242, 40.730_61), 4326)) from stores order by location <-> ST_SetSRID(ST_MakePoint(-73.935_242, 40.730_61), 4326) limit 1; ```
To filter stores located within a specified rectangular area, you can use `ST_MakeEnvelope()` and `ST_Within()` functions. `ST_MakeEnvelope()` creates a rectangular Polygon from the minimum and maximum values for X and Y. `ST_Within()` Returns TRUE if geometry A is within geometry B.
```ts copy {13} const point = { x1: -88, x2: -73, y1: 40, y2: 43, }; await db .select() .from(stores) .where( sql`ST_Within( ${stores.location}, ST_MakeEnvelope(${point.x1}, ${point.y1}, ${point.x2}, ${point.y2}, 4326) )`, ); ``` ```sql select * from stores where ST_Within(location, ST_MakeEnvelope(-88, 40, -73, 43, 4326)); ```
Source: https://orm.drizzle.team/docs/postgresql-full-text-search import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql) - [Select statement](/docs/select) - [Indexes](/docs/indexes-constraints#indexes) - [sql operator](/docs/sql) - You should have `drizzle-orm@0.31.0` and `drizzle-kit@0.22.0` or higher. This guide demonstrates how to implement full-text search in PostgreSQL with Drizzle ORM. Full-text search is a technique used to search for text within a document or a set of documents. A document is the unit of searching in a full text search system. PostgreSQL provides a set of functions to work with full-text search, such as `to_tsvector` and `to_tsquery`: The `to_tsvector` function parses a textual document into tokens, reduces the tokens to lexemes, and returns a `tsvector` which lists the lexemes together with their positions in the document:
```ts copy {6} import { sql } from 'drizzle-orm'; const db = drizzle(...); await db.execute( sql`select to_tsvector('english', 'Guide to PostgreSQL full-text search with Drizzle ORM')`, ); ``` ```json [ { to_tsvector: "'drizzl':9 'full':5 'full-text':4 'guid':1 'orm':10 'postgresql':3 'search':7 'text':6" } ] ```
The `to_tsquery` function converts a keyword to normalized tokens and returns a `tsquery` that matches the lexemes in a `tsvector`. The `@@` operator is used for direct matches:
```ts copy {2, 3} await db.execute( sql`select to_tsvector('english', 'Guide to PostgreSQL full-text search with Drizzle ORM') @@ to_tsquery('english', 'Drizzle') as match`, ); ``` ```json [ { match: true } ] ```
As for now, Drizzle doesn't support `tsvector` type natively, so you need to convert your data in the `text` column on the fly. To enhance the performance, you can create a `GIN` index on your column like this: ```ts copy {10, 11} import { index, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const posts = pgTable( 'posts', { id: serial('id').primaryKey(), title: text('title').notNull(), }, (table) => [ index('title_search_index').using('gin', sql`to_tsvector('english', ${table.title})`), ] ); ``` ```sql CREATE TABLE IF NOT EXISTS "posts" ( "id" serial PRIMARY KEY NOT NULL, "title" text NOT NULL ); CREATE INDEX IF NOT EXISTS "title_search_index" ON "posts" USING gin (to_tsvector('english', "title")); ``` ```json [ { id: 1, title: 'Planning Your First Trip to Europe' }, { id: 2, title: "Cultural Insights: Exploring Asia's Heritage" }, { id: 3, title: 'Top 5 Destinations for a Family Trip' }, { id: 4, title: 'Essential Hiking Gear for Mountain Enthusiasts' }, { id: 5, title: 'Trip Planning: Choosing Your Next Destination' }, { id: 6, title: 'Discovering Hidden Culinary Gems in Italy' }, { id: 7, title: 'The Ultimate Road Trip Guide for Explorers' }, ]; ``` To implement full-text search in PostgreSQL with Drizzle ORM, you can use the `to_tsvector` and `to_tsquery` functions with `sql` operator:
```ts copy {9} import { sql } from 'drizzle-orm'; import { posts } from './schema'; const title = 'trip'; await db .select() .from(posts) .where(sql`to_tsvector('english', ${posts.title}) @@ to_tsquery('english', ${title})`); ``` ```json [ { id: 1, title: 'Planning Your First Trip to Europe' }, { id: 3, title: 'Top 5 Destinations for a Family Trip' }, { id: 5, title: 'Trip Planning: Choosing Your Next Destination' }, { id: 7, title: 'The Ultimate Road Trip Guide for Explorers' } ] ```
To match by any of the keywords, you can use the `|` operator:
```ts copy {6} const title = 'Europe | Asia'; await db .select() .from(posts) .where(sql`to_tsvector('english', ${posts.title}) @@ to_tsquery('english', ${title})`); ``` ```json [ { id: 1, title: 'Planning Your First Trip to Europe' }, { id: 2, title: "Cultural Insights: Exploring Asia's Heritage" } ] ```
To match multiple keywords, you can use the `plainto_tsquery` function:
```ts copy {7} // 'discover & Italy' const title = 'discover Italy'; await db .select() .from(posts) .where(sql`to_tsvector('english', ${posts.title}) @@ plainto_tsquery('english', ${title})`); ``` ```sql select * from posts where to_tsvector('english', title) @@ plainto_tsquery('english', 'discover Italy'); ``` ```json [ { id: 6, title: 'Discovering Hidden Culinary Gems in Italy' } ] ```
To match a phrase, you can use the `phraseto_tsquery` function:
```ts copy {8} // if you query by "trip family", it will not return any result // 'family <-> trip' const title = 'family trip'; await db .select() .from(posts) .where(sql`to_tsvector('english', ${posts.title}) @@ phraseto_tsquery('english', ${title})`); ``` ```sql select * from posts where to_tsvector('english', title) @@ phraseto_tsquery('english', 'family trip'); ``` ```json [ { id: 3, title: 'Top 5 Destinations for a Family Trip' } ] ```
You can also use `websearch_to_tsquery` function which is a simplified version of `to_tsquery` with an alternative syntax, similar to the one used by web search engines:
```ts copy {7} // 'family | first & trip & europ | asia' const title = 'family or first trip Europe or Asia'; await db .select() .from(posts) .where(sql`to_tsvector('english', ${posts.title}) @@ websearch_to_tsquery('english', ${title})`); ``` ```sql select * from posts where to_tsvector('english', title) @@ websearch_to_tsquery('english', 'family or first trip Europe or Asia'); ``` ```json [ { id: 1, title: 'Planning Your First Trip to Europe' }, { id: 2, title: "Cultural Insights: Exploring Asia's Heritage" }, { id: 3, title: 'Top 5 Destinations for a Family Trip' } ] ```
To implement full-text search on multiple columns, you can create index on multiple columns and concatenate the columns with `to_tsvector` function: ```ts copy {12-17} import { sql } from 'drizzle-orm'; import { index, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const posts = pgTable( 'posts', { id: serial('id').primaryKey(), title: text('title').notNull(), description: text('description').notNull(), }, (table) => [ index('search_index').using( 'gin', sql`( setweight(to_tsvector('english', ${table.title}), 'A') || setweight(to_tsvector('english', ${table.description}), 'B') )`, ), ], ); ``` ```sql CREATE TABLE IF NOT EXISTS "posts" ( "id" serial PRIMARY KEY NOT NULL, "title" text NOT NULL, "description" text NOT NULL ); CREATE INDEX IF NOT EXISTS "search_index" ON "posts" USING gin ((setweight(to_tsvector('english', "title"), 'A') || setweight(to_tsvector('english', "description"), 'B'))); ``` ```json [ { id: 1, title: 'Planning Your First Trip to Europe', description: 'Get essential tips on budgeting, sightseeing, and cultural etiquette for your inaugural European adventure.', }, { id: 2, title: "Cultural Insights: Exploring Asia's Heritage", description: 'Dive deep into the rich history and traditions of Asia through immersive experiences and local interactions.', }, { id: 3, title: 'Top 5 Destinations for a Family Trip', description: 'Discover family-friendly destinations that offer fun, education, and relaxation for all ages.', }, { id: 4, title: 'Essential Hiking Gear for Mountain Enthusiasts', description: 'Equip yourself with the latest and most reliable gear for your next mountain hiking expedition.', }, { id: 5, title: 'Trip Planning: Choosing Your Next Destination', description: 'Learn how to select destinations that align with your travel goals, whether for leisure, adventure, or cultural exploration.', }, { id: 6, title: 'Discovering Hidden Culinary Gems in Italy', description: "Unearth Italy's lesser-known eateries and food markets that offer authentic and traditional flavors.", }, { id: 7, title: 'The Ultimate Road Trip Guide for Explorers', description: 'Plan your next great road trip with tips on route planning, packing, and discovering off-the-beaten-path attractions.', }, ]; ``` The `setweight` function is used to label the entries of a tsvector with a given weight, where a weight is one of the letters A, B, C, or D. This is typically used to mark entries coming from different parts of a document, such as title versus body. This is how you can query on multiple columns:
```ts copy {5-7} const title = 'plan'; await db.select().from(posts) .where(sql`( setweight(to_tsvector('english', ${posts.title}), 'A') || setweight(to_tsvector('english', ${posts.description}), 'B')) @@ to_tsquery('english', ${title} )` ); ``` ```json [ { id: 1, title: 'Planning Your First Trip to Europe', description: 'Get essential tips on budgeting, sightseeing, and cultural etiquette for your inaugural European adventure.' }, { id: 5, title: 'Trip Planning: Choosing Your Next Destination', description: 'Learn how to select destinations that align with your travel goals, whether for leisure, adventure, or cultural exploration.' }, { id: 7, title: 'The Ultimate Road Trip Guide for Explorers', description: 'Plan your next great road trip with tips on route planning, packing, and discovering off-the-beaten-path attractions.' } ] ```
To rank the search results, you can use the `ts_rank` or `ts_rank_cd` functions and `orderBy` method:
```ts copy {6,7,12,13,18-20} import { desc, getTableColumns, sql } from 'drizzle-orm'; const search = 'culture | Europe | Italy | adventure'; const matchQuery = sql`( setweight(to_tsvector('english', ${posts.title}), 'A') || setweight(to_tsvector('english', ${posts.description}), 'B')), to_tsquery('english', ${search})`; await db .select({ ...getTableColumns(posts), rank: sql`ts_rank(${matchQuery})`, rankCd: sql`ts_rank_cd(${matchQuery})`, }) .from(posts) .where( sql`( setweight(to_tsvector('english', ${posts.title}), 'A') || setweight(to_tsvector('english', ${posts.description}), 'B') ) @@ to_tsquery('english', ${search})`, ) .orderBy((t) => desc(t.rank)); ``` ```json [ { id: 1, title: 'Planning Your First Trip to Europe', description: 'Get essential tips on budgeting, sightseeing, and cultural etiquette for your inaugural European adventure.', rank: 0.2735672, rankCd: 1.8 }, { id: 6, title: 'Discovering Hidden Culinary Gems in Italy', description: "Unearth Italy's lesser-known eateries and food markets that offer authentic and traditional flavors.", rank: 0.16717994, rankCd: 1.4 }, { id: 2, title: "Cultural Insights: Exploring Asia's Heritage", description: 'Dive deep into the rich history and traditions of Asia through immersive experiences and local interactions.', rank: 0.15198177, rankCd: 1 }, { id: 5, title: 'Trip Planning: Choosing Your Next Destination', description: 'Learn how to select destinations that align with your travel goals, whether for leisure, adventure, or cultural exploration.', rank: 0.12158542, rankCd: 0.8 } ] ```
The `ts_rank` function focuses on the frequency of query terms throughout the document. The `ts_rank_cd` function focuses on the proximity of query terms within the document. Source: https://orm.drizzle.team/docs/postgresql-local-setup import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Steps from '@mdx/Steps.astro'; - Install latest [Docker Desktop](https://www.docker.com/products/docker-desktop/). Follow the instructions for your operating system. #### Pull the PostgreSQL image Pull the latest PostgreSQL image from Docker Hub. In your terminal, run `docker pull postgres` to pull the latest Postgres version from Docker Hub: ```bash copy docker pull postgres ``` Alternatively, you can pull preferred version with a specific tag: ```bash copy docker pull postgres:15 ``` When postgres image is downloaded, you can check it in `Images` tab in Docker Desktop or by running `docker images`:
```bash copy docker images ``` ```plaintext REPOSITORY TAG IMAGE ID CREATED SIZE postgres latest 75282fa229a1 6 weeks ago 453MB ```
#### Start a Postgres instance To start a new PostgreSQL container, run the following command: ```bash copy docker run --name drizzle-postgres -e POSTGRES_PASSWORD=mypassword -d -p 5432:5432 postgres ``` 1. The `--name` option assigns the container the name `drizzle-postgres`. 2. The `-e POSTGRES_PASSWORD=` option sets the `POSTGRES_PASSWORD` environment variable with the specified value. 3. The `-d` flag runs the container in detached mode (in the background). 4. The `-p` option maps port `5432` on the container to port `5432` on your host machine, allowing PostgreSQL to be accessed from your host system through this port. 5. The `postgres` argument specifies the image to use for the container. You can also specify other versions like `postgres:15`. You can also specify other parameters like: 1. The `-e POSTGRES_USER=` option sets the `POSTGRES_USER` environment variable with the specified value. Postgres uses the default user when this is empty. Most of the time, it is `postgres` and you can check it in the container logs in Docker Desktop or by running `docker logs `. 2. The `-e POSTGRES_DB=` option sets the `POSTGRES_DB` environment variable with the specified value. Defaults to the `POSTGRES_USER` value when is empty. To check if the container is running, check `Containers` tab in Docker Desktop or use the `docker ps` command: ```plaintext CONTAINER ID IMAGE COMMAND CREATED STATUS PORTS NAMES df957c58a6a3 postgres "docker-entrypoint.s…" 4 seconds ago Up 3 seconds 0.0.0.0:5432->5432/tcp drizzle-postgres ``` #### Configure database url To connect to the PostgreSQL database, you need to provide the database URL. The URL format is: ```plaintext postgres://:@:/ ``` You should replace placeholders with your actual values. For example, for created container the url will be: ```plaintext postgres://postgres:mypassword@localhost:5432/postgres ``` Now you can connect to the database using the URL in your application.
Source: https://orm.drizzle.team/docs/seeding-using-with-option import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Callout from '@mdx/Callout.astro'; import Section from "@mdx/Section.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) or [SQLite](/docs/get-started-sqlite) - Get familiar with [One-to-many Relation](/docs/relations#one-to-many) - Get familiar with [Drizzle Seed](/docs/seed-overview) Using `with` implies tables to have a one-to-many relationship. Therefore, if `one` user has `many` posts, you can use `with` as follows: ```ts users: { count: 2, with: { posts: 3, }, }, ``` ## Example 1 ```ts import { users, posts } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { users, posts }).refine(() => ({ users: { count: 2, with: { posts: 3, }, }, })); } main(); ``` ```ts import { serial, pgTable, integer, text } from "drizzle-orm/pg-core"; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content'), authorId: integer('author_id').notNull(), }); ``` Running the seeding script above will cause an error. ``` Error: "posts" table doesn't have a reference to "users" table or you didn't include your one-to-many relation in the seed function schema. You can't specify "posts" as parameter in users.with object. ``` You will have several options to resolve an error: - You can add reference to the `authorId` column in `posts` table in your schema
```ts import { users, posts } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { users, posts }).refine(() => ({ users: { count: 2, with: { posts: 3, }, }, })); } main(); // Running the seeding script above will fill you database with values shown below ``` ```mdx `users` | id | name | | -- | -------- | | 1 | 'Melanny' | | 2 | 'Elvera' | `posts` | id | content | author_id | | -- | --------------------- | --------- | | 1 | 'tf02gUXb0LZIdEg6SL' | 2 | | 2 | 'j15YdT7Sma' | 2 | | 3 | 'LwwvWtLLAZzIpk' | 1 | | 4 | 'mgyUnBKSrQw' | 1 | | 5 | 'CjAJByKIqilHcPjkvEw' | 2 | | 6 | 'S5g0NzXs' | 1 | ```
```ts copy{11} import { serial, pgTable, integer, text } from "drizzle-orm/pg-core"; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content'), authorId: integer('author_id').notNull().references(() => users.id), }); ```
- You can add one-to-many relation to your schema and include it in the seed function schema
```ts copy{1,5} import { users, posts, postsRelations } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { users, posts, postsRelations }).refine(() => ({ users: { count: 2, with: { posts: 3, }, }, })); } main(); // Running the seeding script above will fill you database with values shown below ``` ```mdx `users` | id | name | | -- | -------- | | 1 | 'Melanny' | | 2 | 'Elvera' | `posts` | id | content | author_id | | -- | --------------------- | --------- | | 1 | 'tf02gUXb0LZIdEg6SL' | 2 | | 2 | 'j15YdT7Sma' | 2 | | 3 | 'LwwvWtLLAZzIpk' | 1 | | 4 | 'mgyUnBKSrQw' | 1 | | 5 | 'CjAJByKIqilHcPjkvEw' | 2 | | 6 | 'S5g0NzXs' | 1 | ```
```ts copy{2,15-20} import { serial, pgTable, integer, text } from "drizzle-orm/pg-core"; import { relations } from "drizzle-orm"; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content'), authorId: integer('author_id').notNull(), }); export const postsRelations = relations(posts, ({ one }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id], }), })); ```
## Example 2 ```ts import { users, posts } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { users, posts }).refine(() => ({ posts: { count: 2, with: { users: 3, }, }, })); } main(); ``` ```ts import { serial, pgTable, integer, text } from "drizzle-orm/pg-core"; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content'), authorId: integer('author_id').notNull().references(() => users.id), }); ``` Running the seeding script above will cause an error. ``` Error: "posts" table doesn't have a reference to "users" table or you didn't include your one-to-many relation in the seed function schema. You can't specify "posts" as parameter in users.with object. ``` You have a `posts` table referencing a `users` table in your schema, ```ts copy{7} . . . export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content'), authorId: integer('author_id').notNull().references(() => users.id), }); ``` or in other words, you have one-to-many relation where `one` user can have `many` posts. However, in your seeding script, you're attempting to generate 3 (`many`) users for `one` post. ```ts posts: { count: 2, with: { users: 3, }, }, ``` To resolve the error, you can modify your seeding script as follows:
```ts copy{6-9} import { users, posts, postsRelations } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { users, posts, postsRelations }).refine(() => ({ users: { count: 2, with: { posts: 3, }, }, })); } main(); // Running the seeding script above will fill you database with values shown below ``` ```mdx `users` | id | name | | -- | -------- | | 1 | 'Melanny' | | 2 | 'Elvera' | `posts` | id | content | author_id | | -- | --------------------- | --------- | | 1 | 'tf02gUXb0LZIdEg6SL' | 2 | | 2 | 'j15YdT7Sma' | 2 | | 3 | 'LwwvWtLLAZzIpk' | 1 | | 4 | 'mgyUnBKSrQw' | 1 | | 5 | 'CjAJByKIqilHcPjkvEw' | 2 | | 6 | 'S5g0NzXs' | 1 | ```
## Example 3 ```ts copy{6-9} import { users } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { users }).refine(() => ({ users: { count: 2, with: { users: 3, }, }, })); } main(); ``` ```ts import { serial, pgTable, integer, text } from "drizzle-orm/pg-core"; import type { AnyPgColumn } from "drizzle-orm/pg-core"; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), reportsTo: integer('reports_to').references((): AnyPgColumn => users.id), }); ``` Running the seeding script above will cause an error. ``` Error: "users" table has self reference. You can't specify "users" as parameter in users.with object. ``` You have a `users` table referencing a `users` table in your schema, ```ts copy{7} . . . export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), reportsTo: integer('reports_to').references((): AnyPgColumn => users.id), }); ``` or in other words, you have one-to-one relation where `one` user can have only `one` user. However, in your seeding script, you're attempting to generate 3 (`many`) users for `one` user, which is impossible. ```ts users: { count: 2, with: { users: 3, }, }, ``` Source: https://orm.drizzle.team/docs/seeding-with-partially-exposed-tables import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Callout from '@mdx/Callout.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) or [SQLite](/docs/get-started-sqlite) - Get familiar with [Drizzle Seed](/docs/seed-overview) ## Example 1 Let's assume you are trying to seed your database using the seeding script and schema shown below. ```ts import { bloodPressure } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { bloodPressure }); } main(); ``` ```ts copy {10} import { serial, pgTable, integer, doublePrecision } from "drizzle-orm/pg-core"; export const users = pgTable("users", { id: serial("id").primaryKey(), }); export const bloodPressure = pgTable("bloodPressure", { bloodPressureId: serial().primaryKey(), pressure: doublePrecision(), userId: integer().references(() => users.id).notNull(), }) ``` If the `bloodPressure` table has a not-null constraint on the `userId` column, running the seeding script will cause an error. ``` Error: Column 'userId' has not null constraint, and you didn't specify a table for foreign key on column 'userId' in 'bloodPressure' table. ``` This means we can't fill the `userId` column with Null values due to the not-null constraint on that column. Additionally, you didn't expose the `users` table to the `seed` function schema, so we can't generate `users.id` to populate the `userId` column with these values. At this point, you have several options to resolve the error: - You can remove the not-null constraint from the `userId` column; - You can expose `users` table to `seed` function schema ```ts await seed(db, { bloodPressure, users }); ``` - You can [refine](/docs/guides/seeding-with-partially-exposed-tables#refining-the-userid-column-generator) the `userId` column generator; ## Example 2 ```ts import { bloodPressure } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { bloodPressure }); } main(); ``` ```ts copy {10} import { serial, pgTable, integer, doublePrecision } from "drizzle-orm/pg-core"; export const users = pgTable("users", { id: serial("id").primaryKey(), }); export const bloodPressure = pgTable("bloodPressure", { bloodPressureId: serial().primaryKey(), pressure: doublePrecision(), userId: integer().references(() => users.id), }) ``` By running the seeding script above you will see a warning ``` Column 'userId' in 'bloodPressure' table will be filled with Null values because you specified neither a table for foreign key on column 'userId' nor a function for 'userId' column in refinements. ``` This means you neither provided the `users` table to the `seed` function schema nor refined the `userId` column generator. As a result, the `userId` column will be filled with Null values. Then you will have two choices: - If you're okay with filling the `userId` column with Null values, you can ignore the warning; - Otherwise, you can [refine](/docs/guides/seeding-with-partially-exposed-tables#refining-the-userid-column-generator) the `userId` column generator. ## Refining the `userId` column generator Doing so requires the `users` table to already have IDs such as 1 and 2 in the database. ```ts copy {8} import { bloodPressure } from './schema.ts'; async function main() { const db = drizzle(...); await seed(db, { bloodPressure }).refine((funcs) => ({ bloodPressure: { columns: { userId: funcs.valuesFromArray({ values: [1, 2] }) } } })); } main(); ``` Source: https://orm.drizzle.team/docs/select-parent-rows-with-at-least-one-related-child-row import Prerequisites from "@mdx/Prerequisites.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Section from "@mdx/Section.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Select statement](/docs/select) and [select from subquery](/docs/select#select-from-subquery) - [Inner join](/docs/joins#inner-join) - [Filter operators](/docs/operators) and [exists function](/docs/operators#exists) This guide demonstrates how to select parent rows with the condition of having at least one related child row. Below, there are examples of schema definitions and the corresponding database data: ```ts copy import { integer, pgTable, serial, text } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), email: text('email').notNull(), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), userId: integer('user_id').notNull().references(() => users.id), }); ``` ```plaintext +----+------------+----------------------+ | id | name | email | +----+------------+----------------------+ | 1 | John Doe | john_doe@email.com | +----+------------+----------------------+ | 2 | Tom Brown | tom_brown@email.com | +----+------------+----------------------+ | 3 | Nick Smith | nick_smith@email.com | +----+------------+----------------------+ ``` ```plaintext +----+--------+-----------------------------+---------+ | id | title | content | user_id | +----+--------+-----------------------------+---------+ | 1 | Post 1 | This is the text of post 1 | 1 | +----+--------+-----------------------------+---------+ | 2 | Post 2 | This is the text of post 2 | 1 | +----+--------+-----------------------------+---------+ | 3 | Post 3 | This is the text of post 3 | 3 | +----+--------+-----------------------------+---------+ ``` To select parent rows with at least one related child row and retrieve child data you can use `.innerJoin()` method:
```ts copy {12} import { eq } from 'drizzle-orm'; import { users, posts } from './schema'; const db = drizzle(...); await db .select({ user: users, post: posts, }) .from(users) .innerJoin(posts, eq(users.id, posts.userId)); .orderBy(users.id); ``` ```sql select users.*, posts.* from users inner join posts on users.id = posts.user_id order by users.id; ``` ```ts // result data, there is no user with id 2 because he has no posts [ { user: { id: 1, name: 'John Doe', email: 'john_doe@email.com' }, post: { id: 1, title: 'Post 1', content: 'This is the text of post 1', userId: 1 } }, { user: { id: 1, name: 'John Doe', email: 'john_doe@email.com' }, post: { id: 2, title: 'Post 2', content: 'This is the text of post 2', userId: 1 } }, { user: { id: 3, name: 'Nick Smith', email: 'nick_smith@email.com' }, post: { id: 3, title: 'Post 3', content: 'This is the text of post 3', userId: 3 } } ] ```
To only select parent rows with at least one related child row you can use subquery with `exists()` function like this:
```ts copy {8} import { eq, exists, sql } from 'drizzle-orm'; const sq = db .select({ id: sql`1` }) .from(posts) .where(eq(posts.userId, users.id)); await db.select().from(users).where(exists(sq)); ``` ```sql select * from users where exists (select 1 from posts where posts.user_id = users.id); ``` ```ts // result data, there is no user with id 2 because he has no posts [ { id: 1, name: 'John Doe', email: 'john_doe@email.com' }, { id: 3, name: 'Nick Smith', email: 'nick_smith@email.com' } ] ```
Source: https://orm.drizzle.team/docs/timestamp-default-value import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - Learn about column data types for [PostgreSQL](/docs/column-types/pg), [MySQL](/docs/column-types/mysql) and [SQLite](/docs/column-types/sqlite) - [sql operator](/docs/sql) ### PostgreSQL To set current timestamp as a default value in PostgreSQL, you can use the `defaultNow()` method or `sql` operator with `now()` function which returns the current date and time with the time zone:
```ts copy {6,9} import { sql } from 'drizzle-orm'; import { timestamp, pgTable, serial } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), timestamp1: timestamp('timestamp1').notNull().defaultNow(), timestamp2: timestamp('timestamp2', { mode: 'string' }) .notNull() .default(sql`now()`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "users" ( "id" serial PRIMARY KEY NOT NULL, "timestamp1" timestamp DEFAULT now() NOT NULL, "timestamp2" timestamp DEFAULT now() NOT NULL ); ```
The `mode` option defines how values are handled in the application. Values with `string` mode are treated as `string` in the application, but stored as timestamps in the database.
```plaintext // Data stored in the database +----+----------------------------+----------------------------+ | id | timestamp1 | timestamp2 | +----+----------------------------+----------------------------+ | 1 | 2024-04-11 14:14:28.038697 | 2024-04-11 14:14:28.038697 | +----+----------------------------+----------------------------+ ``` ```ts // Data returned by the application [ { id: 1, timestamp1: 2024-04-11T14:14:28.038Z, // Date object timestamp2: '2024-04-11 14:14:28.038697' // string } ] ```
To set unix timestamp as a default value in PostgreSQL, you can use the `sql` operator and `extract(epoch from now())` function which returns the number of seconds since `1970-01-01 00:00:00 UTC`:
```ts copy {8} import { sql } from 'drizzle-orm'; import { integer, pgTable, serial } from 'drizzle-orm/pg-core' export const users = pgTable('users', { id: serial('id').primaryKey(), timestamp: integer('timestamp') .notNull() .default(sql`extract(epoch from now())`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "users" ( "id" serial PRIMARY KEY NOT NULL, "timestamp" integer DEFAULT extract(epoch from now()) NOT NULL ); ``` ```plaintext // Data stored in the database +----+------------+ | id | timestamp | +----+------------+ | 1 | 1712846784 | +----+------------+ ``` ```ts // Data returned by the application [ { id: 1, timestamp: 1712846784 // number } ] ```
### MySQL To set current timestamp as a default value in MySQL, you can use the `defaultNow()` method or `sql` operator with `now()` function which returns the current date and time `(YYYY-MM-DD HH-MM-SS)`:
```ts copy {6,9,12} import { sql } from 'drizzle-orm'; import { mysqlTable, serial, timestamp } from 'drizzle-orm/mysql-core'; export const users = mysqlTable('users', { id: serial('id').primaryKey(), timestamp1: timestamp('timestamp1').notNull().defaultNow(), timestamp2: timestamp('timestamp2', { mode: 'string' }) .notNull() .default(sql`now()`), timestamp3: timestamp('timestamp3', { fsp: 3 }) // fractional seconds part .notNull() .default(sql`now(3)`), }); ``` ```sql CREATE TABLE `users` ( `id` serial AUTO_INCREMENT NOT NULL, `timestamp1` timestamp NOT NULL DEFAULT now(), `timestamp2` timestamp NOT NULL DEFAULT now(), `timestamp3` timestamp(3) NOT NULL DEFAULT now(3), CONSTRAINT `users_id` PRIMARY KEY(`id`) ); ```
`fsp` option defines the number of fractional seconds to include in the timestamp. The default value is `0`. The `mode` option defines how values are handled in the application. Values with `string` mode are treated as `string` in the application, but stored as timestamps in the database.
```plaintext // Data stored in the database +----+---------------------+---------------------+-------------------------+ | id | timestamp1 | timestamp2 | timestamp3 | +----+---------------------+---------------------+-------------------------+ | 1 | 2024-04-11 15:24:53 | 2024-04-11 15:24:53 | 2024-04-11 15:24:53.236 | +----+---------------------+---------------------+-------------------------+ ``` ```ts // Data returned by the application [ { id: 1, timestamp1: 2024-04-11T15:24:53.000Z, // Date object timestamp2: '2024-04-11 15:24:53', // string timestamp3: 2024-04-11T15:24:53.236Z // Date object } ] ```
To set unix timestamp as a default value in MySQL, you can use the `sql` operator and `unix_timestamp()` function which returns the number of seconds since `1970-01-01 00:00:00 UTC`:
```ts copy {8} import { sql } from 'drizzle-orm'; import { mysqlTable, serial, int } from 'drizzle-orm/mysql-core'; export const users = mysqlTable('users', { id: serial('id').primaryKey(), timestamp: int('timestamp') .notNull() .default(sql`(unix_timestamp())`), }); ``` ```sql CREATE TABLE `users` ( `id` serial AUTO_INCREMENT NOT NULL, `timestamp` int NOT NULL DEFAULT (unix_timestamp()), CONSTRAINT `users_id` PRIMARY KEY(`id`) ); ``` ```plaintext // Data stored in the database +----+------------+ | id | timestamp | +----+------------+ | 1 | 1712847986 | +----+------------+ ``` ```ts // Data returned by the application [ { id: 1, timestamp: 1712847986 // number } ] ```
### SQLite To set current timestamp as a default value in SQLite, you can use `sql` operator with `current_timestamp` constant which returns text representation of the current UTC date and time `(YYYY-MM-DD HH:MM:SS)`:
```ts copy {8} import { sql } from 'drizzle-orm'; import { integer, sqliteTable, text } from 'drizzle-orm/sqlite-core'; export const users = sqliteTable('users', { id: integer('id').primaryKey(), timestamp: text('timestamp') .notNull() .default(sql`(current_timestamp)`), }); ``` ```sql CREATE TABLE `users` ( `id` integer PRIMARY KEY NOT NULL, `timestamp` text DEFAULT (current_timestamp) NOT NULL ); ``` ```plaintext // Data stored in the database +----+---------------------+ | id | timestamp | +----+---------------------+ | 1 | 2024-04-11 15:40:43 | +----+---------------------+ ``` ```ts // Data returned by the application [ { id: 1, timestamp: '2024-04-11 15:40:43' // string } ] ```
To set unix timestamp as a default value in SQLite, you can use the `sql` operator and `unixepoch()` function which returns the number of seconds since `1970-01-01 00:00:00 UTC`:
```ts copy {8,11,14} import { sql } from 'drizzle-orm'; import { integer, sqliteTable } from 'drizzle-orm/sqlite-core'; export const users = sqliteTable('users', { id: integer('id').primaryKey(), timestamp1: integer('timestamp1', { mode: 'timestamp' }) .notNull() .default(sql`(unixepoch())`), timestamp2: integer('timestamp2', { mode: 'timestamp_ms' }) .notNull() .default(sql`(unixepoch() * 1000)`), timestamp3: integer('timestamp3', { mode: 'number' }) .notNull() .default(sql`(unixepoch())`), }); ``` ```sql CREATE TABLE `users` ( `id` integer PRIMARY KEY NOT NULL, `timestamp1` integer DEFAULT (unixepoch()) NOT NULL, `timestamp2` integer DEFAULT (unixepoch() * 1000) NOT NULL, `timestamp3` integer DEFAULT (unixepoch()) NOT NULL ); ```
The `mode` option defines how values are handled in the application. In the application, values with `timestamp` and `timestamp_ms` modes are treated as `Date` objects, but stored as integers in the database. The difference is that `timestamp` handles seconds, while `timestamp_ms` handles milliseconds.
```plaintext // Data stored in the database +------------+------------+---------------+------------+ | id | timestamp1 | timestamp2 | timestamp3 | +------------+------------+---------------+------------+ | 1 | 1712835640 | 1712835640000 | 1712835640 | +------------+------------+---------------+------------+ ``` ```ts // Data returned by the application [ { id: 1, timestamp1: 2024-04-11T11:40:40.000Z, // Date object timestamp2: 2024-04-11T11:40:40.000Z, // Date object timestamp3: 1712835640 // number } ] ```
Source: https://orm.drizzle.team/docs/toggling-a-boolean-field import Section from "@mdx/Section.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Update statement](/docs/update) - [Filters](/docs/operators) and [not operator](/docs/operators#not) - Boolean data type in [MySQL](/docs/column-types/mysql#boolean) and [SQLite](/docs/column-types/sqlite#boolean) To toggle a column value you can use `update().set()` method like below:
```tsx copy {8} import { eq, not } from 'drizzle-orm'; const db = drizzle(...); await db .update(table) .set({ isActive: not(table.isActive), }) .where(eq(table.id, 1)); ``` ```sql update "table" set "is_active" = not "is_active" where "id" = 1; ```
Please note that there is no boolean type in MySQL and SQLite. MySQL uses tinyint(1). SQLite uses integers 0 (false) and 1 (true). Source: https://orm.drizzle.team/docs/unique-case-insensitive-email import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Callout from '@mdx/Callout.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Indexes](/docs/indexes-constraints#indexes) - [Insert statement](/docs/insert) and [Select method](/docs/select) - [sql operator](/docs/sql) - You should have `drizzle-orm@0.31.0` and `drizzle-kit@0.22.0` or higher. ### PostgreSQL To implement a unique and case-insensitive `email` handling in PostgreSQL with Drizzle, you can create a unique index on the lowercased `email` column. This way, you can ensure that the `email` is unique regardless of the case. Drizzle has simple and flexible API, which lets you easily create such an index using SQL-like syntax: ```ts copy {12,13} import { SQL, sql } from 'drizzle-orm'; import { pgTable, serial, text, uniqueIndex } from 'drizzle-orm/pg-core'; export const users = pgTable( 'users', { id: serial('id').primaryKey(), name: text('name').notNull(), email: text('email').notNull(), }, (table) => [ // uniqueIndex('emailUniqueIndex').on(sql`lower(${table.email})`), uniqueIndex('emailUniqueIndex').on(lower(table.email)), ], ); // custom lower function export function lower(email: AnyPgColumn): SQL { return sql`lower(${email})`; } ``` ```sql CREATE TABLE IF NOT EXISTS "users" ( "id" serial PRIMARY KEY NOT NULL, "name" text NOT NULL, "email" text NOT NULL ); --> statement-breakpoint CREATE UNIQUE INDEX IF NOT EXISTS "emailUniqueIndex" ON "users" USING btree (lower("email")); ``` This is how you can select user by `email` with `lower` function:
```ts copy {10} import { eq } from 'drizzle-orm'; import { lower, users } from './schema'; const db = drizzle(...); const findUserByEmail = async (email: string) => { return await db .select() .from(users) .where(eq(lower(users.email), email.toLowerCase())); }; ``` ```sql select * from "users" where lower(email) = 'john@email.com'; ```
### MySQL In MySQL, the default collation setting for string comparison is case-insensitive, which means that when performing operations like searching or comparing strings in SQL queries, the case of the characters does not affect the results. However, because collation settings can vary and may be configured to be case-sensitive, we will explicitly ensure that the `email` is unique regardless of case by creating a unique index on the lowercased `email` column. Drizzle has simple and flexible API, which lets you easily create such an index using SQL-like syntax: ```ts copy {12,13} import { SQL, sql } from 'drizzle-orm'; import { AnyMySqlColumn, mysqlTable, serial, uniqueIndex, varchar } from 'drizzle-orm/mysql-core'; export const users = mysqlTable( 'users', { id: serial('id').primaryKey(), name: varchar('name', { length: 255 }).notNull(), email: varchar('email', { length: 255 }).notNull(), }, (table) => [ // uniqueIndex('emailUniqueIndex').on(sql`(lower(${table.email}))`), uniqueIndex('emailUniqueIndex').on(lower(table.email)), ] ); // custom lower function export function lower(email: AnyMySqlColumn): SQL { return sql`(lower(${email}))`; } ``` ```sql CREATE TABLE `users` ( `id` serial AUTO_INCREMENT NOT NULL, `name` varchar(255) NOT NULL, `email` varchar(255) NOT NULL, CONSTRAINT `users_id` PRIMARY KEY(`id`), CONSTRAINT `emailUniqueIndex` UNIQUE((lower(`email`))) ); ``` Functional indexes are supported in MySQL starting from version `8.0.13`. For the correct syntax, the expression should be enclosed in parentheses, for example, `(lower(column))`. This is how you can select user by `email` with `lower` function:
```ts copy {10} import { eq } from 'drizzle-orm'; import { lower, users } from './schema'; const db = drizzle(...); const findUserByEmail = async (email: string) => { return await db .select() .from(users) .where(eq(lower(users.email), email.toLowerCase())); }; ``` ```sql select * from `users` where lower(email) = 'john@email.com'; ```
### SQLite To implement a unique and case-insensitive `email` handling in SQLite with Drizzle, you can create a unique index on the lowercased `email` column. This way, you can ensure that the `email` is unique regardless of the case. Drizzle has simple and flexible API, which lets you easily create such an index using SQL-like syntax: ```ts copy {12,13} import { SQL, sql } from 'drizzle-orm'; import { AnySQLiteColumn, integer, sqliteTable, text, uniqueIndex } from 'drizzle-orm/sqlite-core'; export const users = sqliteTable( 'users', { id: integer('id').primaryKey(), name: text('name').notNull(), email: text('email').notNull(), }, (table) => [ // uniqueIndex('emailUniqueIndex').on(sql`lower(${table.email})`), uniqueIndex('emailUniqueIndex').on(lower(table.email)), ] ); // custom lower function export function lower(email: AnySQLiteColumn): SQL { return sql`lower(${email})`; } ``` ```sql CREATE TABLE `users` ( `id` integer PRIMARY KEY NOT NULL, `name` text NOT NULL, `email` text NOT NULL ); --> statement-breakpoint CREATE UNIQUE INDEX `emailUniqueIndex` ON `users` (lower(`email`)); ``` This is how you can select user by `email` with `lower` function:
```ts copy {10} import { eq } from 'drizzle-orm'; import { lower, users } from './schema'; const db = drizzle(...); const findUserByEmail = async (email: string) => { return await db .select() .from(users) .where(eq(lower(users.email), email.toLowerCase())); }; ``` ```sql select * from "users" where lower(email) = 'john@email.com'; ```
Source: https://orm.drizzle.team/docs/update-many-with-different-value import Section from "@mdx/Section.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Update statement](/docs/update) - [Filters](/docs/operators) and [sql operator](/docs/sql) To implement update many with different values for each row within 1 request you can use `sql` operator with `case` statement and `.update().set()` methods like this:
```ts {26, 29, 32, 36, 38, 40} import { SQL, inArray, sql } from 'drizzle-orm'; import { users } from './schema'; const db = drizzle(...); const inputs = [ { id: 1, city: 'New York', }, { id: 2, city: 'Los Angeles', }, { id: 3, city: 'Chicago', }, ]; // You have to be sure that inputs array is not empty if (inputs.length === 0) { return; } const sqlChunks: SQL[] = []; const ids: number[] = []; sqlChunks.push(sql`(case`); for (const input of inputs) { sqlChunks.push(sql`when ${users.id} = ${input.id} then ${input.city}`); ids.push(input.id); } sqlChunks.push(sql`end)`); const finalSql: SQL = sql.join(sqlChunks, sql.raw(' ')); await db.update(users).set({ city: finalSql }).where(inArray(users.id, ids)); ``` ```sql update users set "city" = (case when id = 1 then 'New York' when id = 2 then 'Los Angeles' when id = 3 then 'Chicago' end) where id in (1, 2, 3) ```
Source: https://orm.drizzle.team/docs/upsert import Section from "@mdx/Section.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; - Get started with [PostgreSQL](/docs/get-started-postgresql), [MySQL](/docs/get-started-mysql) and [SQLite](/docs/get-started-sqlite) - [Insert statement](/docs/insert), [onConflictDoUpdate method](/docs/insert#on-conflict-do-update) and [onDuplicateKeyUpdate method](/docs/insert#on-duplicate-key-update) - [Composite primary key](/docs/indexes-constraints#composite-primary-key) - [sql operator](/docs/sql) ### PostgreSQL and SQLite To implement an upsert query in PostgreSQL and SQLite (skip to [MySQL](/docs/guides/upsert#mysql)) with Drizzle you can use `.onConflictDoUpdate()` method:
```ts copy {8,9,10,11} import { users } from './schema'; const db = drizzle(...); await db .insert(users) .values({ id: 1, name: 'John' }) .onConflictDoUpdate({ target: users.id, set: { name: 'Super John' }, }); ``` ```sql insert into users ("id", "name") values (1, 'John') on conflict ("id") do update set name = 'Super John'; ```
To upsert multiple rows in one query in PostgreSQL and SQLite you can use `sql operator` and `excluded` keyword. `excluded` is a special reference that refer to the row that was proposed for insertion, but wasn't inserted because of the conflict. This is how you can do it: ```ts copy {21,24} import { sql } from 'drizzle-orm'; import { users } from './schema'; const values = [ { id: 1, lastLogin: new Date(), }, { id: 2, lastLogin: new Date(Date.now() + 1000 * 60 * 60), }, { id: 3, lastLogin: new Date(Date.now() + 1000 * 60 * 120), }, ]; await db .insert(users) .values(values) .onConflictDoUpdate({ target: users.id, set: { lastLogin: sql.raw(`excluded.${users.lastLogin.name}`) }, }); ``` ```sql insert into users ("id", "last_login") values (1, '2024-03-15T22:29:06.679Z'), (2, '2024-03-15T23:29:06.679Z'), (3, '2024-03-16T00:29:06.679Z') on conflict ("id") do update set last_login = excluded.last_login; ``` ```ts copy import { pgTable, serial, timestamp } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), lastLogin: timestamp('last_login', { mode: 'date' }).notNull(), }); ``` Drizzle has simple and flexible API, which lets you easily create custom solutions. This is how you do custom function for updating specific columns in multiple rows due to the conflict in PostgreSQL and SQLite: ```ts copy {43,46} import { SQL, getTableColumns, sql } from 'drizzle-orm'; import { PgTable } from 'drizzle-orm/pg-core'; import { SQLiteTable } from 'drizzle-orm/sqlite-core'; import { users } from './schema'; const buildConflictUpdateColumns = < T extends PgTable | SQLiteTable, Q extends keyof T['_']['columns'] >( table: T, columns: Q[], ) => { const cls = getTableColumns(table); return columns.reduce((acc, column) => { const colName = cls[column].name; acc[column] = sql.raw(`excluded.${colName}`); return acc; }, {} as Record); }; const values = [ { id: 1, lastLogin: new Date(), active: true, }, { id: 2, lastLogin: new Date(Date.now() + 1000 * 60 * 60), active: true, }, { id: 3, lastLogin: new Date(Date.now() + 1000 * 60 * 120), active: true, }, ]; await db .insert(users) .values(values) .onConflictDoUpdate({ target: users.id, set: buildConflictUpdateColumns(users, ['lastLogin', 'active']), }); ``` ```sql insert into users ("id", "last_login", "active") values (1, '2024-03-16T15:44:41.141Z', true), (2, '2024-03-16T16:44:41.141Z', true), (3, '2024-03-16T17:44:41.141Z', true) on conflict ("id") do update set last_login = excluded.last_login, active = excluded.active; ``` ```ts copy import { boolean, pgTable, serial, timestamp } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), lastLogin: timestamp('last_login', { mode: 'date' }).notNull(), active: boolean('active').notNull().default(false), }); ``` This is how you can implement an upsert query with multiple targets in PostgreSQL and SQLite:
```ts copy {8} import { sql } from 'drizzle-orm'; import { inventory } from './schema'; await db .insert(inventory) .values({ warehouseId: 1, productId: 1, quantity: 100 }) .onConflictDoUpdate({ target: [inventory.warehouseId, inventory.productId], // composite primary key set: { quantity: sql`${inventory.quantity} + 100` }, // add 100 to the existing quantity }); ``` ```sql insert into inventory ("warehouse_id", "product_id", "quantity") values (1, 1, 100) on conflict ("warehouse_id","product_id") do update set quantity = quantity + 100; ```
If you want to implement upsert query with `where` clause for `update` statement, you can use `setWhere` property in `onConflictDoUpdate` method: ```ts copy {25,26,27,28} import { or, sql } from 'drizzle-orm'; import { products } from './schema'; const data = { id: 1, title: 'Phone', price: '999.99', stock: 10, lastUpdated: new Date(), }; const excludedPrice = sql.raw(`excluded.${products.price.name}`); const excludedStock = sql.raw(`excluded.${products.stock.name}`); await db .insert(products) .values(data) .onConflictDoUpdate({ target: products.id, set: { price: excludedPrice, stock: excludedStock, lastUpdated: sql.raw(`excluded.${products.lastUpdated.name}`) }, setWhere: or( sql`${products.stock} != ${excludedStock}`, sql`${products.price} != ${excludedPrice}` ), }); ``` ```sql insert into products ("id", "title", "stock", "price", "last_updated") values (1, 'Phone', 10, '999.99', '2024-04-29T21:56:55.563Z') on conflict ("id") do update set stock = excluded.stock, price = excluded.price, last_updated = excluded.last_updated where (stock != excluded.stock or price != excluded.price); ``` ```ts copy import { integer, numeric, pgTable, serial, text, timestamp } from 'drizzle-orm/pg-core'; export const products = pgTable('products', { id: serial('id').primaryKey(), title: text('title').notNull(), stock: integer('stock').notNull(), price: numeric('price', { precision: 10, scale: 2 }).notNull(), lastUpdated: timestamp('last_updated').notNull().defaultNow(), }); ``` If you want to update all columns except of specific one, you can leave the previous value like this:
```ts copy {16} import { sql } from 'drizzle-orm'; import { users } from './schema'; const data = { id: 1, name: 'John', email: 'john@email.com', age: 29, }; await db .insert(users) .values(data) .onConflictDoUpdate({ target: users.id, set: { ...data, email: sql`${users.email}` }, // leave email as it was }); ``` ```sql insert into users ("id", "name", "email", "age") values (1, 'John', 'john@email.com', 29) on conflict ("id") do update set id = 1, name = 'John', email = email, age = 29; ```
### MySQL To implement an upsert query in MySQL with Drizzle you can use `.onDuplicateKeyUpdate()` method. MySQL will automatically determine the conflict target based on the primary key and unique indexes, and will update the row if any unique index conflicts. This is how you can do it:
```ts copy {4} await db .insert(users) .values({ id: 1, name: 'John' }) .onDuplicateKeyUpdate({ set: { name: 'Super John' } }); ``` ```sql insert into users (`id`, `first_name`) values (1, 'John') on duplicate key update first_name = 'Super John'; ```
To upsert multiple rows in one query in MySQL you can use `sql operator` and `values()` function. `values()` function refers to the value of column that would be inserted if duplicate-key conflict hadn't occurred. ```ts copy {21,24} import { sql } from 'drizzle-orm'; import { users } from './schema'; const values = [ { id: 1, lastLogin: new Date(), }, { id: 2, lastLogin: new Date(Date.now() + 1000 * 60 * 60), }, { id: 3, lastLogin: new Date(Date.now() + 1000 * 60 * 120), }, ]; await db .insert(users) .values(values) .onDuplicateKeyUpdate({ set: { lastLogin: sql`values(${users.lastLogin})`, }, }); ``` ```sql insert into users (`id`, `last_login`) values (1, '2024-03-15 23:08:27.025'), (2, '2024-03-15 00:08:27.025'), (3, '2024-03-15 01:08:27.025') on duplicate key update last_login = values(last_login); ``` ```ts copy import { mysqlTable, serial, timestamp } from 'drizzle-orm/mysql-core'; export const users = mysqlTable('users', { id: serial('id').primaryKey(), lastLogin: timestamp('last_login', { mode: 'date' }).notNull(), }); ``` Drizzle has simple and flexible API, which lets you easily create custom solutions. This is how you do custom function for updating specific columns in multiple rows due to the conflict in MySQL: ```ts copy {36,38} import { SQL, getTableColumns, sql } from 'drizzle-orm'; import { MySqlTable } from 'drizzle-orm/mysql-core'; import { users } from './schema'; const buildConflictUpdateColumns = ( table: T, columns: Q[], ) => { const cls = getTableColumns(table); return columns.reduce((acc, column) => { acc[column] = sql`values(${cls[column]})`; return acc; }, {} as Record); }; const values = [ { id: 1, lastLogin: new Date(), active: true, }, { id: 2, lastLogin: new Date(Date.now() + 1000 * 60 * 60), active: true, }, { id: 3, lastLogin: new Date(Date.now() + 1000 * 60 * 120), active: true, }, ]; await db .insert(users) .values(values) .onDuplicateKeyUpdate({ set: buildConflictUpdateColumns(users, ['lastLogin', 'active']), }); ``` ```sql insert into users (`id`, `last_login`, `active`) values (1, '2024-03-16 15:23:28.013', true), (2, '2024-03-16 16:23:28.013', true), (3, '2024-03-16 17:23:28.013', true) on duplicate key update last_login = values(last_login), active = values(active); ``` ```ts copy import { boolean, mysqlTable, serial, timestamp } from 'drizzle-orm/mysql-core'; export const users = mysqlTable('users', { id: serial('id').primaryKey(), lastLogin: timestamp('last_login', { mode: 'date' }).notNull(), active: boolean('active').notNull().default(false), }); ``` If you want to update all columns except of specific one, you can leave the previous value like this:
```ts copy {15} import { sql } from 'drizzle-orm'; import { users } from './schema'; const data = { id: 1, name: 'John', email: 'john@email.com', age: 29, }; await db .insert(users) .values(data) .onDuplicateKeyUpdate({ set: { ...data, email: sql`${users.email}` }, // leave email as it was }); ``` ```sql insert into users (`id`, `name`, `email`, `age`) values (1, 'John', 'john@email.com', 29) on duplicate key update id = 1, name = 'John', email = email, age = 29; ```
Source: https://orm.drizzle.team/docs/vector-similarity-search import Section from "@mdx/Section.astro"; import IsSupportedChipGroup from "@mdx/IsSupportedChipGroup.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Npm from "@mdx/Npm.astro"; - Get started with [PostgreSQL](/docs/get-started-postgresql) - [Select statement](/docs/select) - [Indexes](/docs/indexes-constraints#indexes) - [sql operator](/docs/sql) - [pgvector extension](/docs/extensions/pg#pg_vector) - [Drizzle kit](/docs/kit-overview) - You should have installed the `openai` [package](https://www.npmjs.com/package/openai) for generating embeddings. openai - You should have `drizzle-orm@0.31.0` and `drizzle-kit@0.22.0` or higher. To implement vector similarity search in PostgreSQL with Drizzle ORM, you can use the `pgvector` extension. This extension provides a set of functions to work with vectors and perform similarity search. As for now, Drizzle doesn't create extension automatically, so you need to create it manually. Create an empty migration file and add SQL query:
```bash npx drizzle-kit generate --custom ``` ```sql CREATE EXTENSION vector; ```
To perform similarity search, you need to create a table with a vector column and an `HNSW` or `IVFFlat` index on this column for better performance: ```ts copy {10, 13} import { index, pgTable, serial, text, vector } from 'drizzle-orm/pg-core'; export const guides = pgTable( 'guides', { id: serial('id').primaryKey(), title: text('title').notNull(), description: text('description').notNull(), url: text('url').notNull(), embedding: vector('embedding', { dimensions: 1536 }), }, (table) => [ index('embeddingIndex').using('hnsw', table.embedding.op('vector_cosine_ops')), ] ); ``` ```sql CREATE TABLE IF NOT EXISTS "guides" ( "id" serial PRIMARY KEY NOT NULL, "title" text NOT NULL, "description" text NOT NULL, "url" text NOT NULL, "embedding" vector(1536) ); --> statement-breakpoint CREATE INDEX IF NOT EXISTS "embeddingIndex" ON "guides" USING hnsw (embedding vector_cosine_ops); ``` The `embedding` column is used to store vector embeddings of the guide descriptions. Vector embedding is just a representation of some data. It converts different types of data into a common format (vectors) that language models can process. This allows us to perform mathematical operations, such as measuring the distance between two vectors, to determine how similar or different two data items are. In this example we will use `OpenAI` model to generate [embeddings](https://platform.openai.com/docs/guides/embeddings) for the description: ```ts copy import OpenAI from 'openai'; const openai = new OpenAI({ apiKey: process.env['OPENAI_API_KEY'], }); export const generateEmbedding = async (value: string): Promise => { const input = value.replaceAll('\n', ' '); const { data } = await openai.embeddings.create({ model: 'text-embedding-ada-002', input, }); return data[0].embedding; }; ``` To search for similar guides by embedding, you can use `gt` and `sql` operators with `cosineDistance` function to calculate the similarity between the `embedding` column and the generated embedding:
```ts copy {10,15,16} import { cosineDistance, desc, gt, sql } from 'drizzle-orm'; import { generateEmbedding } from './embedding'; import { guides } from './schema'; const db = drizzle(...); const findSimilarGuides = async (description: string) => { const embedding = await generateEmbedding(description); const similarity = sql`1 - (${cosineDistance(guides.embedding, embedding)})`; const similarGuides = await db .select({ name: guides.title, url: guides.url, similarity }) .from(guides) .where(gt(similarity, 0.5)) .orderBy((t) => desc(t.similarity)) .limit(4); return similarGuides; }; ``` ```ts const description = 'Guides on using Drizzle ORM with different platforms'; const similarGuides = await findSimilarGuides(description); ``` ```json [ { name: 'Drizzle with Turso', url: '/docs/tutorials/drizzle-with-turso', similarity: 0.8642314333984994 }, { name: 'Drizzle with Supabase Database', url: '/docs/tutorials/drizzle-with-supabase', similarity: 0.8593631126014918 }, { name: 'Drizzle with Neon Postgres', url: '/docs/tutorials/drizzle-with-neon', similarity: 0.8541051184461372 }, { name: 'Drizzle with Vercel Edge Functions', url: '/docs/tutorials/drizzle-with-vercel-edge-functions', similarity: 0.8481551084241092 } ] ```
Source: https://orm.drizzle.team/docs/indexes-constraints import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; # Indexes & Constraints ## Constraints SQL constraints are the rules enforced on table columns. They are used to prevent invalid data from being entered into the database. This ensures the accuracy and reliability of your data in the database. ### Default The `DEFAULT` clause specifies a default value to use for the column if no value provided by the user when doing an `INSERT`. If there is no explicit `DEFAULT` clause attached to a column definition, then the default value of the column is `NULL`. An explicit `DEFAULT` clause may specify that the default value is `NULL`, a string constant, a blob constant, a signed-number, or any constant expression enclosed in parentheses.
```typescript import { sql } from "drizzle-orm"; import { integer, uuid, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { integer1: integer('integer1').default(42), integer2: integer('integer2').default(sql`'42'::integer`), uuid1: uuid('uuid1').defaultRandom(), uuid2: uuid('uuid2').default(sql`gen_random_uuid()`), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "integer1" integer DEFAULT 42, "integer2" integer DEFAULT '42'::integer, "uuid1" uuid DEFAULT gen_random_uuid(), "uuid2" uuid DEFAULT gen_random_uuid() ); ```
```typescript import { sql } from "drizzle-orm"; import { int, time, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable("table", { int: int("int").default(42), time: time("time").default(sql`cast("14:06:10" AS TIME)`), }); ``` ```sql CREATE TABLE `table` ( `int` int DEFAULT 42, `time` time DEFAULT cast("14:06:10" AS TIME) ); ```
```typescript import { sql } from "drizzle-orm"; import { integer, sqliteTable } from "drizzle-orm/sqlite-core"; const table = sqliteTable('table', { int1: integer('int1').default(42), int2: integer('int2').default(sql`(abs(42))`) }); ``` ```sql CREATE TABLE `table` ( `int1` integer DEFAULT 42 `int2` integer DEFAULT (abs(42)) ); ```
```typescript import { sql } from "drizzle-orm"; import { int, time, singlestoreTable } from "drizzle-orm/singlestore-core"; const table = singlestoreTable("table", { int: int("int").default(42), time: time("time").default(sql`cast("14:06:10" AS TIME)`), }); ``` ```sql CREATE TABLE `table` ( `int` int DEFAULT 42, `time` time DEFAULT cast("14:06:10" AS TIME) ); ```
### Not null By default, a column can hold **NULL** values. The `NOT NULL` constraint enforces a column to **NOT** accept **NULL** values. This enforces a field to always contain a value, which means that you cannot insert a new record, or update a record without adding a value to this field.
```typescript copy import { integer, pgTable } from "drizzle-orm/pg-core"; const table = pgTable('table', { integer: integer('integer').notNull(), }); ``` ```sql CREATE TABLE IF NOT EXISTS "table" ( "integer" integer NOT NULL, ); ```
```typescript import { int, mysqlTable } from "drizzle-orm/mysql-core"; const table = mysqlTable('table', { int: int('int').notNull(), }); ``` ```sql CREATE TABLE `table` ( `int` int NOT NULL, ); ```
```typescript copy const table = sqliteTable('table', { numInt: integer('numInt').notNull() }); ``` ```sql CREATE TABLE table ( `numInt` integer NOT NULL ); ```
```typescript import { int, singlestoreTable } from "drizzle-orm/singlestore-core"; const table = singlestoreTable('table', { int: int('int').notNull(), }); ``` ```sql CREATE TABLE `table` ( `int` int NOT NULL, ); ```
### Unique The `UNIQUE` constraint ensures that all values in a column are different. Both the `UNIQUE` and `PRIMARY KEY` constraints provide a guarantee for uniqueness for a column or set of columns. A `PRIMARY KEY` constraint automatically has a `UNIQUE` constraint. You can have many `UNIQUE` constraints per table, but only one `PRIMARY KEY` constraint per table.
```typescript copy import { integer, text, unique, pgTable } from "drizzle-orm/pg-core"; export const user = pgTable('user', { id: integer('id').unique(), }); export const table = pgTable('table', { id: integer('id').unique('custom_name'), }); export const composite = pgTable('composite_example', { id: integer('id'), name: text('name'), }, (t) => [ unique().on(t.id, t.name), unique('custom_name').on(t.id, t.name) ]); // In Postgres 15.0+ NULLS NOT DISTINCT is available // This example demonstrates both available usages export const userNulls = pgTable('user_nulls_example', { id: integer('id').unique("custom_name", { nulls: 'not distinct' }), }, (t) => [ unique().on(t.id).nullsNotDistinct() ]); ``` ```sql CREATE TABLE IF NOT EXISTS "composite_example" ( "id" integer, "name" text, CONSTRAINT "composite_example_id_name_unique" UNIQUE("id","name"), CONSTRAINT "custom_name" UNIQUE("id","name") ); CREATE TABLE IF NOT EXISTS "table" ( "id" integer, CONSTRAINT "custom_name" UNIQUE("id") ); CREATE TABLE IF NOT EXISTS "user" ( "id" integer, CONSTRAINT "user_id_unique" UNIQUE("id") ); CREATE TABLE IF NOT EXISTS "user_nulls_example" ( "id" integer, CONSTRAINT "custom_name" UNIQUE NULLS NOT DISTINCT("id"), CONSTRAINT "user_nulls_example_id_unique" UNIQUE NULLS NOT DISTINCT("id") ); ```
```typescript import { int, varchar, unique, mysqlTable } from "drizzle-orm/mysql-core"; export const user = mysqlTable('user', { id: int('id').unique(), }); export const table = mysqlTable('table', { id: int('id').unique('custom_name'), }); export const composite = mysqlTable('composite_example', { id: int('id'), name: varchar('name', { length: 256 }), }, (t) => [ unique().on(t.id, t.name), unique('custom_name').on(t.id, t.name) ]); ``` ```sql CREATE TABLE `user` ( `id` int, CONSTRAINT `user_id_unique` UNIQUE(`id`) ); CREATE TABLE `table` ( `id` int, CONSTRAINT `custom_name` UNIQUE(`id`) ); CREATE TABLE `composite_example` ( `id` int, `name` varchar(256), CONSTRAINT `composite_example_id_name_unique` UNIQUE(`id`,`name`), CONSTRAINT `custom_name` UNIQUE(`id`,`name`) ); ```
```typescript copy import { int, text, unique, sqliteTable } from "drizzle-orm/sqlite-core"; export const user = sqliteTable('user', { id: int('id').unique(), }); export const table = sqliteTable('table', { id: int('id').unique('custom_name'), }); export const composite = sqliteTable('composite_example', { id: int('id'), name: text('name'), }, (t) => [ unique().on(t.id, t.name), unique('custom_name').on(t.id, t.name) ]); ``` ```sql CREATE TABLE `user` ( `id` integer ); CREATE TABLE `table` ( `id` integer ); CREATE TABLE `composite_example` ( `id` integer, `name` text ); CREATE UNIQUE INDEX `composite_example_id_name_unique` ON `composite_example` (`id`,`name`); CREATE UNIQUE INDEX `custom_name` ON `composite_example` (`id`,`name`); CREATE UNIQUE INDEX `custom_name` ON `table` (`id`); CREATE UNIQUE INDEX `user_id_unique` ON `user` (`id`); ```
```typescript import { int, varchar, unique, singlestoreTable } from "drizzle-orm/singlestore-core"; export const user = singlestoreTable('user', { id: int('id').unique(), }); export const table = singlestoreTable('table', { id: int('id').unique('custom_name'), }); export const composite = singlestoreTable('composite_example', { id: int('id'), name: varchar('name', { length: 256 }), }, (t) => [ unique().on(t.id, t.name), unique('custom_name').on(t.id, t.name) ]); ``` ```sql CREATE TABLE `user` ( `id` int, CONSTRAINT `user_id_unique` UNIQUE(`id`) ); CREATE TABLE `table` ( `id` int, CONSTRAINT `custom_name` UNIQUE(`id`) ); CREATE TABLE `composite_example` ( `id` int, `name` varchar(256), CONSTRAINT `composite_example_id_name_unique` UNIQUE(`id`,`name`), CONSTRAINT `custom_name` UNIQUE(`id`,`name`) ); ```
### Check The `CHECK` constraint is used to limit the value range that can be placed in a column. If you define a `CHECK` constraint on a column it will allow only certain values for this column. If you define a `CHECK` constraint on a table it can limit the values in certain columns based on values in other columns in the row.
```typescript copy import { sql } from "drizzle-orm"; import { check, integer, pgTable, text, uuid } from "drizzle-orm/pg-core"; export const users = pgTable( "users", { id: uuid().defaultRandom().primaryKey(), username: text().notNull(), age: integer(), }, (table) => [ check("age_check1", sql`${table.age} > 21`), ] ); ``` ```sql CREATE TABLE IF NOT EXISTS "users" ( "id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL, "username" text NOT NULL, "age" integer, CONSTRAINT "age_check1" CHECK ("users"."age" > 21) ); ```
```typescript copy import { sql } from "drizzle-orm"; import { check, int, mysqlTable, text } from "drizzle-orm/mysql-core"; export const users = mysqlTable( "users", { id: int().primaryKey(), username: text().notNull(), age: int(), }, (table) => [ check("age_check1", sql`${table.age} > 21`) ] ); ``` ```sql CREATE TABLE `users` ( `id` int NOT NULL, `username` text NOT NULL, `age` int, CONSTRAINT `users_id` PRIMARY KEY(`id`), CONSTRAINT `age_check1` CHECK(`users`.`age` > 21) ); ```
```typescript copy import { sql } from "drizzle-orm"; import { check, int, sqliteTable, text } from "drizzle-orm/sqlite-core"; export const users = sqliteTable( "users", { id: int().primaryKey(), username: text().notNull(), age: int(), }, (table) => [ check("age_check1", sql`${table.age} > 21`) ] ); ``` ```sql CREATE TABLE `users` ( `id` integer PRIMARY KEY NOT NULL, `username` text NOT NULL, `age` integer, CONSTRAINT "age_check1" CHECK("users"."age" > 21) ); ```
Currently not supported in SingleStore
### Primary Key The `PRIMARY KEY` constraint uniquely identifies each record in a table. Primary keys must contain `UNIQUE` values, and cannot contain `NULL` values. A table can have only **ONE** primary key; and in the table, this primary key can consist of single or multiple columns (fields).
```typescript copy import { serial, text, pgTable } from "drizzle-orm/pg-core"; const user = pgTable('user', { id: serial('id').primaryKey(), }); const table = pgTable('table', { id: text('cuid').primaryKey(), }); ``` ```sql CREATE TABLE IF NOT EXISTS "user" ( "id" serial PRIMARY KEY, ); CREATE TABLE IF NOT EXISTS "table" ( "cuid" text PRIMARY KEY, ); ```
```typescript import { int, text, mysqlTable } from "drizzle-orm/mysql-core"; export const user = mysqlTable("user", { id: int("id").autoincrement().primaryKey(), }) export const table = mysqlTable("table", { cuid: text("cuid").primaryKey(), }) ``` ```sql CREATE TABLE `user` ( `id` int AUTO_INCREMENT PRIMARY KEY NOT NULL ); CREATE TABLE `table` ( `cuid` text PRIMARY KEY NOT NULL ); ```
```typescript copy import { integer, sqliteTable } from "drizzle-orm/sqlite-core"; export const user = sqliteTable("user", { id: integer("id").primaryKey(), }) export const pet = sqliteTable("pet", { id: integer("id").primaryKey(), }) ``` ```sql CREATE TABLE `user` ( `id` integer PRIMARY KEY AUTOINCREMENT NOT NULL ); CREATE TABLE `pet` ( `id` integer PRIMARY KEY AUTOINCREMENT ) ```
```typescript import { int, text, singlestoreTable } from "drizzle-orm/singlestore-core"; export const user = singlestoreTable("user", { id: int("id").autoincrement().primaryKey(), }) export const table = singlestoreTable("table", { cuid: text("cuid").primaryKey(), }) ``` ```sql CREATE TABLE `user` ( `id` int AUTO_INCREMENT PRIMARY KEY NOT NULL ); CREATE TABLE `table` ( `cuid` text PRIMARY KEY NOT NULL ); ```
### Composite Primary Key Just like `PRIMARY KEY`, composite primary key uniquely identifies each record in a table using multiple fields. Drizzle ORM provides a standalone `primaryKey` operator for that:
```typescript copy {18, 19} import { serial, text, integer, primaryKey, pgTable } from "drizzle-orm/pg-core"; export const user = pgTable("user", { id: serial("id").primaryKey(), name: text("name"), }); export const book = pgTable("book", { id: serial("id").primaryKey(), name: text("name"), }); export const booksToAuthors = pgTable("books_to_authors", { authorId: integer("author_id"), bookId: integer("book_id"), }, (table) => [ primaryKey({ columns: [table.bookId, table.authorId] }), // Or PK with custom name primaryKey({ name: 'custom_name', columns: [table.bookId, table.authorId] }), ]); ``` ```sql {6, 9} ... CREATE TABLE IF NOT EXISTS "books_to_authors" ( "author_id" integer, "book_id" integer, PRIMARY KEY("book_id","author_id"), ); ALTER TABLE "books_to_authors" ADD CONSTRAINT "custom_name" PRIMARY KEY("book_id","author_id"); ```
```typescript {18, 19} import { int, text, primaryKey, mysqlTable } from "drizzle-orm/mysql-core"; export const user = mysqlTable("user", { id: int("id").autoincrement().primaryKey(), name: text("name"), }); export const book = mysqlTable("book", { id: int("id").autoincrement().primaryKey(), name: text("name"), }); export const booksToAuthors = mysqlTable("books_to_authors", { authorId: int("author_id"), bookId: int("book_id"), }, (table) => [ primaryKey({ columns: [table.bookId, table.authorId] }), // Or PK with custom name primaryKey({ name: 'custom_name', columns: [table.bookId, table.authorId] }) ]); ``` ```sql {6} ... CREATE TABLE `books_to_authors` ( `author_id` int, `book_id` int, PRIMARY KEY(`book_id`,`author_id`) ); ```
```typescript copy {18, 19} import { integer, text, primaryKey, sqliteTable} from "drizzle-orm/sqlite-core"; export const user = sqliteTable("user", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name"), }); export const book = sqliteTable("book", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name"), }); export const bookToAuthor = sqliteTable("book_to_author", { authorId: integer("author_id"), bookId: integer("book_id"), }, (table) => [ primaryKey({ columns: [table.bookId, table.authorId] }), // Or PK with custom name primaryKey({ name: 'custom_name', columns: [table.bookId, table.authorId] }) ]); ``` ```sql {6} ... CREATE TABLE `book_to_author` ( `author_id` integer, `book_id` integer, PRIMARY KEY(`book_id`, `author_id`) ); ```
```typescript {18, 19} import { int, text, primaryKey, mysqlTable } from "drizzle-orm/singlestore-core"; export const user = singlestoreTable("user", { id: int("id").autoincrement().primaryKey(), name: text("name"), }); export const book = singlestoreTable("book", { id: int("id").autoincrement().primaryKey(), name: text("name"), }); export const booksToAuthors = singlestoreTable("books_to_authors", { authorId: int("author_id"), bookId: int("book_id"), }, (table) => [ primaryKey({ columns: [table.bookId, table.authorId] }), // Or PK with custom name primaryKey({ name: 'custom_name', columns: [table.bookId, table.authorId] }), ]); ``` ```sql {6} ... CREATE TABLE `books_to_authors` ( `author_id` int, `book_id` int, PRIMARY KEY(`book_id`,`author_id`) ); ```
### Foreign key The `FOREIGN KEY` constraint is used to prevent actions that would destroy links between tables. A `FOREIGN KEY` is a field (or collection of fields) in one table, that refers to the `PRIMARY KEY` in another table. The table with the foreign key is called the child table, and the table with the primary key is called the referenced or parent table. Drizzle ORM provides several ways to declare foreign keys. You can declare them in a column declaration statement: ```typescript copy {11} import { serial, text, integer, pgTable } from "drizzle-orm/pg-core"; export const user = pgTable("user", { id: serial("id"), name: text("name"), }); export const book = pgTable("book", { id: serial("id"), name: text("name"), authorId: integer("author_id").references(() => user.id) }); ``` ```typescript {11} import { int, text, mysqlTable } from "drizzle-orm/mysql-core"; export const user = mysqlTable("user", { id: int("id").primaryKey().autoincrement(), name: text("name"), }); export const book = mysqlTable("book", { id: int("id").primaryKey().autoincrement(), name: text("name"), authorId: int("author_id").references(() => user.id) }); ``` ```typescript {11} import { integer, text, sqliteTable } from "drizzle-orm/sqlite-core"; export const user = sqliteTable("user", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name"), }); export const book = sqliteTable("book", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name"), authorId: integer("author_id").references(() => user.id) }); ``` Currently not supported in SingleStore If you want to do a self reference, due to a TypeScript limitations you will have to either explicitly set return type for reference callback or use a standalone `foreignKey` operator. ```typescript copy {6,16-19} import { serial, text, integer, foreignKey, pgTable, AnyPgColumn } from "drizzle-orm/pg-core"; export const user = pgTable("user", { id: serial("id"), name: text("name"), parentId: integer("parent_id").references((): AnyPgColumn => user.id) }); // or export const user = pgTable("user", { id: serial("id"), name: text("name"), parentId: integer("parent_id"), }, (table) => [ foreignKey({ columns: [table.parentId], foreignColumns: [table.id], name: "custom_fk" }) ]); ``` ```typescript {6,16-19} import { int, text, foreignKey, AnyMySqlColumn, mysqlTable } from "drizzle-orm/mysql-core"; export const user = mysqlTable("user", { id: int("id").primaryKey().autoincrement(), name: text("name"), parentId: int("parent_id").references((): AnyMySqlColumn => user.id), }); // or export const user = mysqlTable("user", { id: int("id").primaryKey().autoincrement(), name: text("name"), parentId: int("parent_id") }, (table) => [ foreignKey({ columns: [table.parentId], foreignColumns: [table.id], name: "custom_fk" }) ]); ``` ```typescript {6,16-19} import { integer, text, foreignKey, sqliteTable, AnySQLiteColumn } from "drizzle-orm/sqlite-core"; export const user = sqliteTable("user", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name"), parentId: integer("parent_id").references((): AnySQLiteColumn => user.id) }); //or export const user = sqliteTable("user", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name"), parentId: integer("parent_id"), }, (table) => [ foreignKey({ columns: [table.parentId], foreignColumns: [table.id], name: "custom_fk" }) ]); ``` Currently not supported in SingleStore To declare multicolumn foreign keys you can use a dedicated `foreignKey` operator: ```typescript copy {4-5,14-15,18-21} import { serial, text, foreignKey, pgTable, AnyPgColumn } from "drizzle-orm/pg-core"; export const user = pgTable("user", { firstName: text("firstName"), lastName: text("lastName"), }, (table) => [ primaryKey({ columns: [table.firstName, table.lastName]}) ]); export const profile = pgTable("profile", { id: serial("id").primaryKey(), userFirstName: text("user_first_name"), userLastName: text("user_last_name"), }, (table) => [ foreignKey({ columns: [table.userFirstName, table.userLastName], foreignColumns: [user.firstName, user.lastName], name: "custom_fk" }) ]) ``` ```typescript copy {4-5,14-15,18-21} import { int, text, primaryKey, foreignKey, mysqlTable, AnyMySqlColumn } from "drizzle-orm/mysql-core"; export const user = mysqlTable("user", { firstName: text("firstName"), lastName: text("lastName"), }, (table) => [ primaryKey({ columns: [table.firstName, table.lastName]}) ]); export const profile = mysqlTable("profile", { id: int("id").autoincrement().primaryKey(), userFirstName: text("user_first_name"), userLastName: text("user_last_name"), }, (table) => [ foreignKey({ columns: [table.userFirstName, table.userLastName], foreignColumns: [user.firstName, user.lastName], name: "custom_name" }) ]); ``` ```typescript {4-5,14-15,18-21} import { integer, text, primaryKey, foreignKey, sqliteTable, AnySQLiteColumn } from "drizzle-orm/sqlite-core"; export const user = sqliteTable("user", { firstName: text("firstName"), lastName: text("lastName"), }, (table) => [ primaryKey({ columns: [table.firstName, table.lastName]}) ]); export const profile = sqliteTable("profile", { id: integer("id").primaryKey({ autoIncrement: true }), userFirstName: text("user_first_name"), userLastName: text("user_last_name"), }, (table) => [ foreignKey({ columns: [table.userFirstName, table.userLastName], foreignColumns: [user.firstName, user.lastName], name: "custom_name" }) ]); ``` Currently not supported in SingleStore ## Indexes Drizzle ORM provides API for both `index` and `unique index` declaration:
```typescript copy {9-10} import { serial, text, index, uniqueIndex, pgTable } from "drizzle-orm/pg-core"; export const user = pgTable("user", { id: serial("id").primaryKey(), name: text("name"), email: text("email"), }, (table) => [ index("name_idx").on(table.name), uniqueIndex("email_idx").on(table.email) ]); ``` ```sql {5-6} CREATE TABLE "user" ( ... ); CREATE INDEX "name_idx" ON "user" ("name"); CREATE UNIQUE INDEX "email_idx" ON "user" ("email"); ```
For versions before `drizzle-kit@0.22.0` and `drizzle-orm@0.31.0` `drizzle-kit` only supports index `name` and `on()` param. After versions `drizzle-kit@0.22.0` and `drizzle-orm@0.31.0` all fields are supported in drizzle-kit! Starting from 0.31.0 a new index api for Drizzle ORM provides set of all params for index creation: ```ts // First example, with `.on()` index('name') .on(table.column1.asc(), table.column2.nullsFirst(), ...) or .onOnly(table.column1.desc().nullsLast(), table.column2, ...) .concurrently() .where(sql``) .with({ fillfactor: '70' }) // Second Example, with `.using()` index('name') .using('btree', table.column1.asc(), sql`lower(${table.column2})`, table.column1.op('text_ops')) .where(sql``) // sql expression .with({ fillfactor: '70' }) ```
```typescript copy {9-10} import { int, text, index, uniqueIndex, mysqlTable } from "drizzle-orm/mysql-core"; export const user = mysqlTable("user", { id: int("id").primaryKey().autoincrement(), name: text("name"), email: text("email"), }, (table) => [ index("name_idx").on(table.name), uniqueIndex("email_idx").on(table.email), ]); ``` ```sql {5-6} CREATE TABLE `user` ( ... ); CREATE INDEX `name_idx` ON `user` (`name`); CREATE UNIQUE INDEX `email_idx` ON `user` (`email`); ```
As of now `drizzle-kit` only supports index `name` and `on()` param. Drizzle ORM provides set of all params for index creation: ```typescript // Index declaration reference index("name") .on(table.name) .algorythm("default") // "default" | "copy" | "inplace" .using("btree") // "btree" | "hash" .lock("default") // "none" | "default" | "exclusive" | "shared" ```
```typescript {9-10} import { integer, text, index, uniqueIndex, sqliteTable } from "drizzle-orm/sqlite-core"; export const user = sqliteTable("user", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name"), email: text("email"), }, (table) => [ index("name_idx").on(table.name), uniqueIndex("email_idx").on(table.email), ]); ``` ```sql {5-6} CREATE TABLE `user` ( ... ); CREATE INDEX `name_idx` ON `user` (`name`); CREATE UNIQUE INDEX `email_idx` ON `user` (`email`); ```
Drizzle ORM provides set of all params for index creation: ```typescript // Index declaration reference index("name") .on(table.name) .where(sql`...`) ```
```typescript copy {9-10} import { int, text, index, uniqueIndex, singlestoreTable } from "drizzle-orm/singlestore-core"; export const user = singlestoreTable("user", { id: int("id").primaryKey().autoincrement(), name: text("name"), email: text("email"), }, (table) => [ index("name_idx").on(table.name), uniqueIndex("email_idx").on(table.email), ]); ``` ```sql {5-6} CREATE TABLE `user` ( ... ); CREATE INDEX `name_idx` ON `user` (`name`); CREATE UNIQUE INDEX `email_idx` ON `user` (`email`); ```
Source: https://orm.drizzle.team/docs/insert import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import Section from '@mdx/Section.astro'; import Callout from '@mdx/Callout.astro'; import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; # SQL Insert Drizzle ORM provides you the most SQL-like way to insert rows into the database tables. ## Insert one row Inserting data with Drizzle is extremely straightforward and sql-like. See for yourself:
```typescript copy await db.insert(users).values({ name: 'Andrew' }); ``` ```sql insert into "users" ("name") values ("Andrew"); ```
If you need insert type for a particular table you can use `typeof usersTable.$inferInsert` syntax. ```typescript copy type NewUser = typeof users.$inferInsert; const insertUser = async (user: NewUser) => { return db.insert(users).values(user); } const newUser: NewUser = { name: "Alef" }; await insertUser(newUser); ``` ## Insert returning You can insert a row and get it back in PostgreSQL and SQLite like such: ```typescript copy await db.insert(users).values({ name: "Dan" }).returning(); // partial return await db.insert(users).values({ name: "Partial Dan" }).returning({ insertedId: users.id }); ``` ## Insert $returningId MySQL itself doesn't have native support for `RETURNING` after using `INSERT`. There is only one way to do it for `primary keys` with `autoincrement` (or `serial`) types, where you can access `insertId` and `affectedRows` fields. We've prepared an automatic way for you to handle such cases with Drizzle and automatically receive all inserted IDs as separate objects ```ts import { boolean, int, text, mysqlTable } from 'drizzle-orm/mysql-core'; const usersTable = mysqlTable('users', { id: int('id').primaryKey(), name: text('name').notNull(), verified: boolean('verified').notNull().default(false), }); const result = await db.insert(usersTable).values([{ name: 'John' }, { name: 'John1' }]).$returningId(); // ^? { id: number }[] ``` Also with Drizzle, you can specify a `primary key` with `$default` function that will generate custom primary keys at runtime. We will also return those generated keys for you in the `$returningId()` call ```ts import { varchar, text, mysqlTable } from 'drizzle-orm/mysql-core'; import { createId } from '@paralleldrive/cuid2'; const usersTableDefFn = mysqlTable('users_default_fn', { customId: varchar('id', { length: 256 }).primaryKey().$defaultFn(createId), name: text('name').notNull(), }); const result = await db.insert(usersTableDefFn).values([{ name: 'John' }, { name: 'John1' }]).$returningId(); // ^? { customId: string }[] ``` > If there is no primary keys -> type will be `{}[]` for such queries ## Insert multiple rows ```typescript copy await db.insert(users).values([{ name: 'Andrew' }, { name: 'Dan' }]); ``` ## Upserts and conflicts Drizzle ORM provides simple interfaces for handling upserts and conflicts. ### On conflict do nothing `onConflictDoNothing` will cancel the insert if there's a conflict: ```typescript copy await db.insert(users) .values({ id: 1, name: 'John' }) .onConflictDoNothing(); // explicitly specify conflict target await db.insert(users) .values({ id: 1, name: 'John' }) .onConflictDoNothing({ target: users.id }); ``` ### On conflict do update `onConflictDoUpdate` will update the row if there's a conflict: ```typescript await db.insert(users) .values({ id: 1, name: 'Dan' }) .onConflictDoUpdate({ target: users.id, set: { name: 'John' } }); ``` #### `where` clauses `on conflict do update` can have a `where` clause in two different places - as part of the conflict target (i.e. for partial indexes) or as part of the `update` clause: ```sql insert into employees (employee_id, name) values (123, 'John Doe') on conflict (employee_id) where name <> 'John Doe' do update set name = excluded.name insert into employees (employee_id, name) values (123, 'John Doe') on conflict (employee_id) do update set name = excluded.name where name <> 'John Doe'; ``` To specify these conditions in Drizzle, you can use `setWhere` and `targetWhere` clauses: ```typescript await db.insert(employees) .values({ employeeId: 123, name: 'John Doe' }) .onConflictDoUpdate({ target: employees.employeeId, targetWhere: sql`name <> 'John Doe'`, set: { name: sql`excluded.name` } }); await db.insert(employees) .values({ employeeId: 123, name: 'John Doe' }) .onConflictDoUpdate({ target: employees.employeeId, set: { name: 'John Doe' }, setWhere: sql`name <> 'John Doe'` }); ```
Upsert with composite indexes, or composite primary keys for `onConflictDoUpdate`: ```typescript await db.insert(users) .values({ firstName: 'John', lastName: 'Doe' }) .onConflictDoUpdate({ target: [users.firstName, users.lastName], set: { firstName: 'John1' } }); ``` ### On duplicate key update MySQL supports [`ON DUPLICATE KEY UPDATE`](https://dev.mysql.com/doc/refman/8.0/en/insert-on-duplicate.html) instead of `ON CONFLICT` clauses. MySQL will automatically determine the conflict target based on the primary key and unique indexes, and will update the row if *any* unique index conflicts. Drizzle supports this through the `onDuplicateKeyUpdate` method: ```typescript // Note that MySQL automatically determines targets based on the primary key and unique indexes await db.insert(users) .values({ id: 1, name: 'John' }) .onDuplicateKeyUpdate({ set: { name: 'John' } }); ``` While MySQL does not directly support doing nothing on conflict, you can perform a no-op by setting any column's value to itself and achieve the same effect: ```typescript import { sql } from 'drizzle-orm'; await db.insert(users) .values({ id: 1, name: 'John' }) .onDuplicateKeyUpdate({ set: { id: sql`id` } }); ``` ## `with insert` clause Check how to use WITH statement with [select](/docs/select#with-clause), [update](/docs/update#with-update-clause), [delete](/docs/delete#with-delete-clause) Using the `with` clause can help you simplify complex queries by splitting them into smaller subqueries called common table expressions (CTEs):
```typescript copy const userCount = db.$with('user_count').as( db.select({ value: sql`count(*)`.as('value') }).from(users) ); const result = await db.with(userCount) .insert(users) .values([ { username: 'user1', admin: sql`((select * from ${userCount}) = 0)` } ]) .returning({ admin: users.admin }); ``` ```sql with "user_count" as (select count(*) as "value" from "users") insert into "users" ("username", "admin") values ($1, ((select * from "user_count") = 0)) returning "admin" ```
## Insert into ... select As the SQLite documentation mentions: 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. 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: A query (SELECT statement) that supplies the rows to be inserted And as the MySQL documentation mentions: 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
```ts 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 }); ``` ```ts const qb = new QueryBuilder(); await db.insert(employees).select( qb.select({ name: users.name }).from(users).where(eq(users.role, 'employee')) ); ```
```ts await db.insert(employees).select( () => db.select({ name: users.name }).from(users).where(eq(users.role, 'employee')) ); ``` ```ts await db.insert(employees).select( (qb) => qb.select({ name: users.name }).from(users).where(eq(users.role, 'employee')) ); ```
```ts await db.insert(employees).select( sql`select "users"."name" as "name" from "users" where "users"."role" = 'employee'` ); ``` ```ts await db.insert(employees).select( () => sql`select "users"."name" as "name" from "users" where "users"."role" = 'employee'` ); ```
Source: https://orm.drizzle.team/docs/joins import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Section from '@mdx/Section.astro'; # Joins [SQL] Join clause in SQL is used to combine 2 or more tables, based on related columns between them. Drizzle ORM joins syntax is a balance between the SQL-likeness and type safety. ## Join types Drizzle ORM has APIs for `INNER JOIN`, `FULL JOIN`, `LEFT JOIN` and `RIGHT JOIN`. Lets have a quick look at examples based on below table schemas: ```typescript copy export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), }); export const pets = pgTable('pets', { id: serial('id').primaryKey(), name: text('name').notNull(), ownerId: integer('owner_id').notNull().references(() => users.id), }) ``` ### Left Join
```typescript copy const result = await db.select().from(users).leftJoin(pets, eq(users.id, pets.ownerId)) ``` ```sql select ... from "users" left join "pets" on "users"."id" = "pets"."owner_id" ``` ```typescript // result type const result: { user: { id: number; name: string; }; pets: { id: number; name: string; ownerId: number; } | null; }[]; ```
### Right Join
```typescript copy const result = await db.select().from(users).rightJoin(pets, eq(users.id, pets.ownerId)) ``` ```sql select ... from "users" right join "pets" on "users"."id" = "pets"."owner_id" ``` ```typescript // result type const result: { user: { id: number; name: string; } | null; pets: { id: number; name: string; ownerId: number; }; }[]; ```
### Inner Join
```typescript copy const result = await db.select().from(users).innerJoin(pets, eq(users.id, pets.ownerId)) ``` ```sql select ... from "users" inner join "pets" on "users"."id" = "pets"."owner_id" ``` ```typescript // result type const result: { user: { id: number; name: string; }; pets: { id: number; name: string; ownerId: number; }; }[]; ```
### Full Join
```typescript copy const result = await db.select().from(users).fullJoin(pets, eq(users.id, pets.ownerId)) ``` ```sql select ... from "users" full join "pets" on "users"."id" = "pets"."owner_id" ``` ```typescript // result type const result: { user: { id: number; name: string; } | null; pets: { id: number; name: string; ownerId: number; } | null; }[]; ```
## Partial select If you need to select a particular subset of fields or to have a flat response type, Drizzle ORM supports joins with partial select and will automatically infer return type based on `.select({ ... })` structure.
```typescript copy await db.select({ userId: users.id, petId: pets.id, }).from(user).leftJoin(pets, eq(users.id, pets.ownerId)) ``` ```sql select "users"."id", "pets"."id" from "users" left join "pets" on "users"."id" = "pets"."owner_id" ``` ```typescript // result type const result: { userId: number; petId: number | null; }[]; ```
You might've noticed that `petId` can be null now, it's because we're left joining and there can be users without a pet. It's very important to keep in mind when using `sql` operator for partial selection fields and aggregations when needed, you should to use `sql` for proper result type inference, that one is on you!
```typescript copy const result = await db.select({ userId: users.id, petId: pets.id, petName1: sql`upper(${pets.name})`, petName2: sql`upper(${pets.name})`, //˄we should explicitly tell 'string | null' in type, since we're left joining that field }).from(user).leftJoin(pets, eq(users.id, pets.ownerId)) ``` ```sql select "users"."id", "pets"."id", upper("pets"."name")... from "users" left join "pets" on "users"."id" = "pets"."owner_id" ``` ```typescript // result type const result: { userId: number; petId: number | null; petName1: unknown; petName2: string | null; }[]; ```
To avoid plethora of nullable fields when joining tables with lots of columns we can utilise our **nested select object syntax**, our smart type inference will make whole object nullable instead of making all table fields nullable!
```typescript copy await db.select({ userId: users.id, userName: users.name, pet: { id: pets.id, name: pets.name, upperName: sql`upper(${pets.name})` } }).from(user).fullJoin(pets, eq(users.id, pets.ownerId)) ``` ```sql select ... from "users" full join "pets" on "users"."id" = "pets"."owner_id" ``` ```typescript // result type const result: { userId: number | null; userName: string | null; pet: { id: number; name: string; upperName: string; } | null; }[]; ```
## Aliases & Selfjoins Drizzle ORM supports table aliases which comes really handy when you need to do selfjoins. Lets say you need to fetch users with their parents: ```typescript copy import { user } from "./schema"; const parent = aliasedTable(user, "parent") const result = db .select() .from(user) .leftJoin(parent, eq(parent.id, user.parentId)); ``` ```sql select ... from "user" left join "user" "parent" on "parent"."id" = "user"."parent_id" ``` ```typescript // result type const result: { user: { id: number; name: string; parentId: number; }; parent: { id: number; name: string; parentId: number; } | null; }[]; ``` ```typescript export const user = pgTable("user", { id: integer("id").primaryKey({ autoIncrement: true }), name: text("name").notNull(), parentId: integer("parent_id").notNull().references((): AnyPgColumn => user.id) }); ``` ## Aggregating results Drizzle ORM delivers name-mapped results from the driver without changing the structure. You're free to operate with results the way you want, here's an example of mapping many-one relational data: ```typescript type User = typeof users.$inferSelect; type Pet = typeof pets.$inferSelect; const rows = db.select({ user: users, pet: pets, }).from(users).leftJoin(pets, eq(users.id, pets.ownerId)).all(); const result = rows.reduce>( (acc, row) => { const user = row.user; const pet = row.pet; if (!acc[user.id]) { acc[user.id] = { user, pets: [] }; } if (pet) { acc[user.id].pets.push(pet); } return acc; }, {} ); // result type const result: Record; ``` ## Many-to-one example ```typescript import { sqliteTable, text, integer } from 'drizzle-orm/sqlite-core'; import { drizzle } from 'drizzle-orm/better-sqlite3'; const cities = sqliteTable('cities', { id: integer('id').primaryKey(), name: text('name'), }); const users = sqliteTable('users', { id: integer('id').primaryKey(), name: text('name'), cityId: integer('city_id').references(() => cities.id) }); const db = drizzle(); const result = db.select().from(cities).leftJoin(users, eq(cities.id, users.cityId)).all(); ``` ## Many-to-many example ```typescript const users = sqliteTable('users', { id: integer('id').primaryKey(), name: text('name'), }); const chatGroups = sqliteTable('chat_groups', { id: integer('id').primaryKey(), name: text('name'), }); const usersToChatGroups = sqliteTable('usersToChatGroups', { userId: integer('user_id').notNull().references(() => users.id), groupId: integer('group_id').notNull().references(() => chatGroups.id), }); // querying user group with id 1 and all the participants(users) db.select() .from(usersToChatGroups) .leftJoin(users, eq(usersToChatGroups.userId, users.id)) .leftJoin(chatGroups, eq(usersToChatGroups.groupId, chatGroups.id)) .where(eq(chatGroups.id, 1)) .all(); ``` Source: https://orm.drizzle.team/docs/kit-custom-migrations import CodeTab from '@mdx/CodeTab.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import Section from '@mdx/Section.astro'; import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Steps from '@mdx/Steps.astro'; import Prerequisites from "@mdx/Prerequisites.astro" # Migrations with Drizzle Kit - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) - Drizzle Kit [overview](/docs/kit-overview) and [config file](/docs/drizzle-config-file) - `drizzle-kit generate` command - [read here](/docs/drizzle-kit-generate) - `drizzle-kit migrate` command - [read here](/docs/drizzle-kit-migrate) Drizzle lets you generate empty migration files to write your own custom SQL migrations for DDL alternations currently not supported by Drizzle Kit or data seeding, which you can then run with [`drizzle-kit migrate`](/docs/drizzle-kit-migrate) command. ```shell drizzle-kit generate --custom --name=seed-users ```
```plaintext {5} 📦 ├ 📂 drizzle │ ├ 📂 _meta │ ├ 📜 0000_init.sql │ └ 📜 0001_seed-users.sql ├ 📂 src └ … ``` ```sql -- ./drizzle/0001_seed-users.sql INSERT INTO "users" ("name") VALUES('Dan'); INSERT INTO "users" ("name") VALUES('Andrew'); INSERT INTO "users" ("name") VALUES('Dandrew'); ```
### Running JavaScript and TypeScript migrations We will add ability to run custom JavaScript and TypeScript migration/seeding scripts in the upcoming release, you can follow [github discussion](https://github.com/drizzle-team/drizzle-orm/discussions/2832). Source: https://orm.drizzle.team/docs/kit-migrations-for-teams # Drizzle migrations for teams This section will be updated right after our release of the next version of migrations folder structure. You can read an extended [github discussion](https://github.com/drizzle-team/drizzle-orm/discussions/2832) and subscribe to the updates! Source: https://orm.drizzle.team/docs/kit-overview import CodeTab from '@mdx/CodeTab.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import Section from '@mdx/Section.astro'; import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Steps from '@mdx/Steps.astro'; import Prerequisites from "@mdx/Prerequisites.astro" # Migrations with Drizzle Kit - Get started with Drizzle and `drizzle-kit` - [read here](/docs/get-started) - Drizzle schema foundamentals - [read here](/docs/sql-schema-declaration) - Database connection basics - [read here](/docs/connect-overview) - Drizzle migrations foundamentals - [read here](/docs/migrations) **Drizzle Kit** is a CLI tool for managing SQL database migrations with Drizzle. drizzle-kit Make sure to first go through Drizzle [get started](/docs/get-started) and [migration foundamentals](/docs/migrations) and pick SQL migration flow that suits your business needs best. Based on your schema, Drizzle Kit let's you generate and run SQL migration files, push schema directly to the database, pull schema from database, spin up drizzle studio and has a couple of utility commands. drizzle-kit generate drizzle-kit migrate drizzle-kit push drizzle-kit pull drizzle-kit check drizzle-kit up drizzle-kit studio | | | | :--------------------------------------------------- | :----------------------------------------------------------------------------------------------------------------------------------------------------------------- | | [`drizzle-kit generate`](/docs/drizzle-kit-generate) | lets you generate SQL migration files based on your Drizzle schema either upon declaration or on subsequent changes, [see here](/docs/drizzle-kit-generate). | | [`drizzle-kit migrate`](/docs/drizzle-kit-migrate) | lets you apply generated SQL migration files to your database, [see here](/docs/drizzle-kit-migrate). | | [`drizzle-kit pull`](/docs/drizzle-kit-pull) | lets you pull(introspect) database schema, convert it to Drizzle schema and save it to your codebase, [see here](/docs/drizzle-kit-pull) | | [`drizzle-kit push`](/docs/drizzle-kit-push) | lets you push your Drizzle schema to database either upon declaration or on subsequent schema changes, [see here](/docs/drizzle-kit-push) | | [`drizzle-kit studio`](/docs/drizzle-kit-studio) | will connect to your database and spin up proxy server for Drizzle Studio which you can use for convenient database browsing, [see here](/docs/drizzle-kit-studio) | | [`drizzle-kit check`](/docs/drizzle-kit-check) | will walk through all generate migrations and check for any race conditions(collisions) of generated migrations, [see here](/docs/drizzle-kit-check) | | [`drizzle-kit up`](/docs/drizzle-kit-up) | used to upgrade snapshots of previously generated migrations, [see here](/docs/drizzle-kit-up) |
Drizzle Kit is configured through [drizzle.config.ts](/docs/drizzle-config-file) configuration file or via CLI params.
It's required to at least provide SQL `dialect` and `schema` path for Drizzle Kit to know how to generate migrations. ``` 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle.config.ts <--- Drizzle config file ├ 📜 package.json └ 📜 tsconfig.json ``` ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", }); ``` ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ out: "./drizzle", dialect: "postgresql", schema: "./src/schema.ts", driver: "pglite", dbCredentials: { url: "./database/", }, extensionsFilters: ["postgis"], schemaFilter: "public", tablesFilter: "*", introspect: { casing: "camel", }, migrations: { prefix: "timestamp", table: "__drizzle_migrations__", schema: "public", }, breakpoints: true, strict: true, verbose: true, }); ``` You can provide Drizzle Kit config path via CLI param, it's very useful when you have multiple database stages or multiple databases or different databases on the same project: drizzle-kit push --config=drizzle-dev.drizzle.config drizzle-kit push --config=drizzle-prod.drizzle.config ```plaintext {5-6} 📦 ├ 📂 drizzle ├ 📂 src ├ 📜 .env ├ 📜 drizzle-dev.config.ts ├ 📜 drizzle-prod.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` Source: https://orm.drizzle.team/docs/kit-seed-data import CodeTab from '@mdx/CodeTab.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import Section from '@mdx/Section.astro'; import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Steps from '@mdx/Steps.astro'; import Prerequisites from "@mdx/Prerequisites.astro" # Drizzle Kit data seeding This section will be updated right after our release of `drizzle-seed` package. Source: https://orm.drizzle.team/docs/kit-web-mobile import CodeTab from '@mdx/CodeTab.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import Section from '@mdx/Section.astro'; import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import Npm from '@mdx/Npm.astro'; import Npx from '@mdx/Npx.astro'; import Steps from '@mdx/Steps.astro'; import Prerequisites from "@mdx/Prerequisites.astro" # Drizzle migrations in web and mobile environments This section will be updated in the next release. For **Expo SQLite**, **OP SQLite** and **React Native** migrations - please refer to our [Get Started](/docs/get-started/expo-new) guide. Source: https://orm.drizzle.team/docs/migrations export const a = 10; import Callout from '@mdx/Callout.astro'; import Steps from '@mdx/Steps.astro'; import CodeTab from '@mdx/CodeTab.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import Section from '@mdx/Section.astro'; import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Npm from '@mdx/Npm.astro'; import Tag from '@mdx/Tag.astro' # Drizzle migrations fundamentals SQL databases require you to specify a **strict schema** of entities you're going to store upfront and if (when) you need to change the shape of those entities - you will need to do it via **schema migrations**. There're multiple production grade ways of managing database migrations. Drizzle is designed to perfectly suits all of them, regardless of you going **database first** or **codebase first**. **Database first** is when your database schema is a source of truth. You manage your database schema either directly on the database or via database migration tools and then you pull your database schema to your codebase application level entities. **Codebase first** is when database schema in your codebase is a source of truth and is under version control. You declare and manage your database schema in JavaScript/TypeScript and then you apply that schema to the database itself either with Drizzle, directly or via external migration tools. #### How can Drizzle help? We've built [**drizzle-kit**](/docs/kit-overview) - CLI app for managing migrations with Drizzle. ```shell drizzle-kit migrate drizzle-kit generate drizzle-kit push drizzle-kit pull ``` It is designed to let you choose how to approach migrations based on your current business demands. It fits in both database and codebase first approaches, it lets you **push your schema** or **generate SQL migration** files or **pull the schema** from database. It is perfect wether you work alone or in a team.

**Now let's pick the best option for your project:** **Option 1** > I manage database schema myself using external migration tools or by running SQL migrations directly on my database. > From Drizzle I just need to get current state of the schema from my database and save it as TypeScript schema file. That's a **database first** approach. You have your database schema as a **source of truth** and Drizzle lets you pull database schema to TypeScript using [`drizzle-kit pull`](/docs/drizzle-kit-pull) command.
``` ┌────────────────────────┐ ┌─────────────────────────┐ │ │ <--- CREATE TABLE "users" ( ┌──────────────────────────┐ │ │ "id" SERIAL PRIMARY KEY, │ ~ drizzle-kit pull │ │ │ "name" TEXT, └─┬────────────────────────┘ │ DATABASE │ "email" TEXT UNIQUE │ │ │ ); └ Pull datatabase schema -----> │ │ ┌ Generate Drizzle <----- │ │ │ schema TypeScript file └────────────────────────┘ │ v ``` ```typescript import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), email: p.text().unique(), }; ```
**Option 2** > I want to have database schema in my TypeScript codebase, > I don't wanna deal with SQL migration files. > I want Drizzle to "push" my schema directly to the database That's a **codebase first** approach. You have your TypeScript Drizzle schema as a **source of truth** and Drizzle let's you push schema changes to the database using [`drizzle-kit push`](/docs/drizzle-kit-push) command. That's the best approach for rapid prototyping and we've seen dozens of teams and solo developers successfully using it as a primary migrations flow in their production applications.
```typescript {6} filename="src/schema.ts" import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), email: p.text().unique(), // <--- added column }; ``` ``` Add column to `users` table ┌──────────────────────────┐ │ + email: text().unique() │ └─┬────────────────────────┘ │ v ┌──────────────────────────┐ │ ~ drizzle-kit push │ └─┬────────────────────────┘ │ ┌──────────────────────────┐ └ Pull current datatabase schema ---------> │ │ │ │ ┌ Generate alternations based on diff <---- │ DATABASE │ │ │ │ └ Apply migrations to the database -------> │ │ │ └──────────────────────────┘ │ ┌────────────────────────────────────┴──────────────┐ ALTER TABLE `users` ADD COLUMN `email` TEXT UNIQUE; ```
**Option 3** > I want to have database schema in my TypeScript codebase, > I want Drizzle to generate SQL migration files for me and apply them to my database That's a **codebase first** approach. You have your TypeScript Drizzle schema as a source of truth and Drizzle let's you generate SQL migration files based on your schema changes with [`drizzle-kit generate`](/docs/drizzle-kit-generate) and then apply them to the database with [`drizzle-kit migrate`](/docs/drizzle-kit-migrate) commands.
```typescript filename="src/schema.ts" import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), email: p.text().unique(), }; ``` ``` ┌────────────────────────┐ │ $ drizzle-kit generate │ └─┬──────────────────────┘ │ └ 1. read previous migration folders 2. find diff between current and previous schema 3. prompt developer for renames if necessary ┌ 4. generate SQL migration and persist to file │ ┌─┴───────────────────────────────────────┐ │ 📂 drizzle │ └ 📂 20242409125510_premium_mister_fear │ ├ 📜 snapshot.json │ └ 📜 migration.sql v ``` ```sql -- drizzle/20242409125510_premium_mister_fear/migration.sql CREATE TABLE "users" ( "id" SERIAL PRIMARY KEY, "name" TEXT, "email" TEXT UNIQUE ); ``` ``` ┌───────────────────────┐ │ $ drizzle-kit migrate │ └─┬─────────────────────┘ │ ┌──────────────────────────┐ └ 1. read migration.sql files in migrations folder │ │ 2. fetch migration history from database -------------> │ │ ┌ 3. pick previously unapplied migrations <-------------- │ DATABASE │ └ 4. apply new migration to the database ---------------> │ │ │ │ └──────────────────────────┘ [✓] done! ```
**Option 4** > I want to have database schema in my TypeScript codebase, > I want Drizzle to generate SQL migration files for me and I want Drizzle to apply them during runtime That's a **codebase first** approach. You have your TypeScript Drizzle schema as a source of truth and Drizzle let's you generate SQL migration files based on your schema changes with [`drizzle-kit generate`](/docs/drizzle-kit-generate) and then you can apply them to the database during runtime of your application. This approach is widely used for **monolithic** applications when you apply database migrations during zero downtime deployment and rollback DDL changes if something fails. This is also used in **serverless** deployments with migrations running in **custom resource** once during deployment process.
```typescript filename="src/schema.ts" import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), email: p.text().unique(), }; ``` ``` ┌────────────────────────┐ │ $ drizzle-kit generate │ └─┬──────────────────────┘ │ └ 1. read previous migration folders 2. find diff between current and previous schema 3. prompt developer for renames if necessary ┌ 4. generate SQL migration and persist to file │ ┌─┴───────────────────────────────────────┐ │ 📂 drizzle │ └ 📂 20242409125510_premium_mister_fear │ ├ 📜 snapshot.json │ └ 📜 migration.sql v ``` ```sql -- drizzle/20242409125510_premium_mister_fear/migration.sql CREATE TABLE "users" ( "id" SERIAL PRIMARY KEY, "name" TEXT, "email" TEXT UNIQUE ); ``` ```ts // index.ts import { drizzle } from "drizzle-orm/node-postgres" import { migrate } from 'drizzle-orm/node-postgres/migrator'; const db = drizzle(process.env.DATABASE_URL); await migrate(db); ``` ``` ┌───────────────────────┐ │ npx tsx src/index.ts │ └─┬─────────────────────┘ │ ├ 1. init database connection ┌──────────────────────────┐ └ 2. read migration.sql files in migrations folder │ │ 3. fetch migration history from database -------------> │ │ ┌ 4. pick previously unapplied migrations <-------------- │ DATABASE │ └ 5. apply new migration to the database ---------------> │ │ │ │ └──────────────────────────┘ [✓] done! ```
**Option 5** > I want to have database schema in my TypeScript codebase, > I want Drizzle to generate SQL migration files for me, > but I will apply them to my database myself or via external migration tools That's a **codebase first** approach. You have your TypeScript Drizzle schema as a source of truth and Drizzle let's you generate SQL migration files based on your schema changes with [`drizzle-kit generate`](/docs/drizzle-kit-generate) and then you can apply them to the database either directly or via external migration tools.
```typescript filename="src/schema.ts" import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), email: p.text().unique(), }; ``` ``` ┌────────────────────────┐ │ $ drizzle-kit generate │ └─┬──────────────────────┘ │ └ 1. read previous migration folders 2. find diff between current and previous scheama 3. prompt developer for renames if necessary ┌ 4. generate SQL migration and persist to file │ ┌─┴───────────────────────────────────────┐ │ 📂 drizzle │ └ 📂 20242409125510_premium_mister_fear │ ├ 📜 snapshot.json │ └ 📜 migration.sql v ``` ```sql -- drizzle/20242409125510_premium_mister_fear/migration.sql CREATE TABLE "users" ( "id" SERIAL PRIMARY KEY, "name" TEXT, "email" TEXT UNIQUE ); ``` ``` ┌───────────────────────────────────┐ │ (._.) now you run your migrations │ └─┬─────────────────────────────────┘ │ directly to the database │ ┌────────────────────┐ ├────────────────────────────────────┬───>│ │ │ │ │ Database │ or via external tools │ │ │ │ │ └────────────────────┘ │ ┌────────────────────┐ │ └──│ Bytebase ├────────────┘ ├────────────────────┤ │ Liquibase │ ├────────────────────┤ │ Atlas │ ├────────────────────┤ │ etc… │ └────────────────────┘ [✓] done! ```
**Option 6** > I want to have database schema in my TypeScript codebase, > I want Drizzle to output the SQL representation of my Drizzle schema to the console, > and I will apply them to my database via [Atlas](https://atlasgo.io/guides/orms/drizzle) That's a **codebase first** approach. You have your TypeScript Drizzle schema as a source of truth and Drizzle let's you export SQL statements based on your schema changes with [`drizzle-kit export`](/docs/drizzle-kit-generate) and then you can apply them to the database via [Atlas](https://atlasgo.io/guides/orms/drizzle) or other external SQL migration tools.
```typescript filename="src/schema.ts" import * as p from "drizzle-orm/pg-core"; export const users = p.pgTable("users", { id: p.serial().primaryKey(), name: p.text(), email: p.text().unique(), }; ``` ``` ┌────────────────────────┐ │ $ drizzle-kit export │ └─┬──────────────────────┘ │ └ 1. read your drizzle schema 2. generated SQL representation of your schema ┌ 3. outputs to console │ │ v ``` ```sql CREATE TABLE "users" ( "id" SERIAL PRIMARY KEY, "name" TEXT, "email" TEXT UNIQUE ); ``` ``` ┌───────────────────────────────────┐ │ (._.) now you run your migrations │ └─┬─────────────────────────────────┘ │ via Atlas │ ┌──────────────┐ │ ┌────────────────────┐ │ │ └──│ Atlas ├───────────>│ Database │ └────────────────────┘ │ │ └──────────────┘ [✓] done! ```
Source: https://orm.drizzle.team/docs/operators import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import Section from '@mdx/Section.astro'; # Filter and conditional operators We natively support all dialect specific filter and conditional operators. You can import all filter & conditional from `drizzle-orm`: ```typescript copy import { eq, ne, gt, gte, ... } from "drizzle-orm"; ``` ### eq Value equal to `n`
```typescript copy import { eq } from "drizzle-orm"; db.select().from(table).where(eq(table.column, 5)); ``` ```sql copy SELECT * FROM table WHERE table.column = 5 ```
```typescript import { eq } from "drizzle-orm"; db.select().from(table).where(eq(table.column1, table.column2)); ``` ```sql SELECT * FROM table WHERE table.column1 = table.column2 ```
### ne Value is not equal to `n`
```typescript import { ne } from "drizzle-orm"; db.select().from(table).where(ne(table.column, 5)); ``` ```sql SELECT * FROM table WHERE table.column <> 5 ```
```typescript import { ne } from "drizzle-orm"; db.select().from(table).where(ne(table.column1, table.column2)); ``` ```sql SELECT * FROM table WHERE table.column1 <> table.column2 ```
## --- ### gt Value is greater than `n`
```typescript import { gt } from "drizzle-orm"; db.select().from(table).where(gt(table.column, 5)); ``` ```sql SELECT * FROM table WHERE table.column > 5 ```
```typescript import { gt } from "drizzle-orm"; db.select().from(table).where(gt(table.column1, table.column2)); ``` ```sql SELECT * FROM table WHERE table.column1 > table.column2 ```
### gte Value is greater than or equal to `n`
```typescript import { gte } from "drizzle-orm"; db.select().from(table).where(gte(table.column, 5)); ``` ```sql SELECT * FROM table WHERE table.column >= 5 ```
```typescript import { gte } from "drizzle-orm"; db.select().from(table).where(gte(table.column1, table.column2)); ``` ```sql SELECT * FROM table WHERE table.column1 >= table.column2 ```
### lt Value is less than `n`
```typescript import { lt } from "drizzle-orm"; db.select().from(table).where(lt(table.column, 5)); ``` ```sql SELECT * FROM table WHERE table.column < 5 ```
```typescript import { lt } from "drizzle-orm"; db.select().from(table).where(lt(table.column1, table.column2)); ``` ```sql SELECT * FROM table WHERE table.column1 < table.column2 ```
### lte Value is less than or equal to `n`.
```typescript import { lte } from "drizzle-orm"; db.select().from(table).where(lte(table.column, 5)); ``` ```sql SELECT * FROM table WHERE table.column <= 5 ```
```typescript import { lte } from "drizzle-orm"; db.select().from(table).where(lte(table.column1, table.column2)); ``` ```sql SELECT * FROM table WHERE table.column1 <= table.column2 ```
## --- ### exists Value exists
```typescript import { exists } from "drizzle-orm"; const query = db.select().from(table2) db.select().from(table).where(exists(query)); ``` ```sql SELECT * FROM table WHERE EXISTS (SELECT * from table2) ```
### notExists
```typescript import { notExists } from "drizzle-orm"; const query = db.select().from(table2) db.select().from(table).where(notExists(query)); ``` ```sql SELECT * FROM table WHERE NOT EXISTS (SELECT * from table2) ```
### isNull Value is `null`
```typescript import { isNull } from "drizzle-orm"; db.select().from(table).where(isNull(table.column)); ``` ```sql SELECT * FROM table WHERE table.column IS NULL ```
### isNotNull Value is not `null`
```typescript import { isNotNull } from "drizzle-orm"; db.select().from(table).where(isNotNull(table.column)); ``` ```sql SELECT * FROM table WHERE table.column IS NOT NULL ```
## --- ### inArray Value is in array of values
```typescript import { inArray } from "drizzle-orm"; db.select().from(table).where(inArray(table.column, [1, 2, 3, 4])); ``` ```sql SELECT * FROM table WHERE table.column in (1, 2, 3, 4) ```
```typescript import { inArray } from "drizzle-orm"; const query = db.select({ data: table2.column }).from(table2); db.select().from(table).where(inArray(table.column, query)); ``` ```sql SELECT * FROM table WHERE table.column IN (SELECT table2.column FROM table2) ```
### notInArray Value is not in array of values
```typescript import { notInArray } from "drizzle-orm"; db.select().from(table).where(notInArray(table.column, [1, 2, 3, 4])); ``` ```sql SELECT * FROM table WHERE table.column NOT in (1, 2, 3, 4) ```
```typescript import { notInArray } from "drizzle-orm"; const query = db.select({ data: table2.column }).from(table2); db.select().from(table).where(notInArray(table.column, query)); ``` ```sql SELECT * FROM table WHERE table.column NOT IN (SELECT table2.column FROM table2) ```
## --- ### between Value is between two values
```typescript import { between } from "drizzle-orm"; db.select().from(table).where(between(table.column, 2, 7)); ``` ```sql SELECT * FROM table WHERE table.column BETWEEN 2 AND 7 ```
### notBetween Value is not between two value
```typescript import { notBetween } from "drizzle-orm"; db.select().from(table).where(notBetween(table.column, 2, 7)); ``` ```sql SELECT * FROM table WHERE table.column NOT BETWEEN 2 AND 7 ```
## --- ### like Value is like other value, case sensitive
```typescript import { like } from "drizzle-orm"; db.select().from(table).where(like(table.column, "%llo wor%")); ``` ```sql SELECT * FROM table WHERE table.column LIKE '%llo wor%' ```
### ilike Value is like some other value, case insensitive
```typescript import { ilike } from "drizzle-orm"; db.select().from(table).where(ilike(table.column, "%llo wor%")); ``` ```sql SELECT * FROM table WHERE table.column ILIKE '%llo wor%' ```
### notIlike Value is not like some other value, case insensitive
```typescript import { notIlike } from "drizzle-orm"; db.select().from(table).where(notIlike(table.column, "%llo wor%")); ``` ```sql SELECT * FROM table WHERE table.column NOT ILIKE '%llo wor%' ```
## --- ### not All conditions must return `false`.
```typescript import { eq, not } from "drizzle-orm"; db.select().from(table).where(not(eq(table.column, 5))); ``` ```sql SELECT * FROM table WHERE NOT (table.column = 5) ```
### and All conditions must return `true`.
```typescript import { gt, lt, and } from "drizzle-orm"; db.select().from(table).where(and(gt(table.column, 5), lt(table.column, 7))); ``` ```sql SELECT * FROM table WHERE (table.column > 5 AND table.column < 7) ```
### or One or more conditions must return `true`.
```typescript import { gt, lt, or } from "drizzle-orm"; db.select().from(table).where(or(gt(table.column, 5), lt(table.column, 7))); ``` ```sql SELECT * FROM table WHERE (table.column > 5 OR table.column < 7) ```
## --- ### arrayContains Test that a column or expression contains all elements of the list passed as the second argument
```typescript import { arrayContains } from "drizzle-orm"; const contains = await db.select({ id: posts.id }).from(posts) .where(arrayContains(posts.tags, ['Typescript', 'ORM'])); const withSubQuery = await db.select({ id: posts.id }).from(posts) .where(arrayContains( posts.tags, db.select({ tags: posts.tags }).from(posts).where(eq(posts.id, 1)), )); ``` ```sql select "id" from "posts" where "posts"."tags" @> {Typescript,ORM}; select "id" from "posts" where "posts"."tags" @> (select "tags" from "posts" where "posts"."id" = 1); ```
### arrayContained Test that the list passed as the second argument contains all elements of a column or expression
```typescript import { arrayContained } from "drizzle-orm"; const contained = await db.select({ id: posts.id }).from(posts) .where(arrayContained(posts.tags, ['Typescript', 'ORM'])); ``` ```sql select "id" from "posts" where "posts"."tags" <@ {Typescript,ORM}; ```
### arrayOverlaps Test that a column or expression contains any elements of the list passed as the second argument.
```typescript import { arrayOverlaps } from "drizzle-orm"; const overlaps = await db.select({ id: posts.id }).from(posts) .where(arrayOverlaps(posts.tags, ['Typescript', 'ORM'])); ``` ```sql select "id" from "posts" where "posts"."tags" && {Typescript,ORM} ```
Source: https://orm.drizzle.team/docs/overview import Callout from '@mdx/Callout.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import YoutubeCards from '@mdx/YoutubeCards.astro'; import GetStartedLinks from '@mdx/GetStartedLinks/index.astro' # Drizzle ORM Drizzle ORM is a headless TypeScript ORM with a head. 🐲 > Drizzle is a good friend who's there for you when necessary and doesn't bother when you need some space. It looks and feels simple, performs on day _1000_ of your project,\ lets you do things your way, and is there when you need it. **It's the only ORM with both [relational](/docs/rqb) and [SQL-like](/docs/select) query APIs**, providing you the best of both worlds when it comes to accessing your relational data. Drizzle is lightweight, performant, typesafe, non-lactose, gluten-free, sober, flexible and **serverless-ready by design**. Drizzle is not just a library, it's an experience. 🤩 [![Drizzle bestofjs](@/assets/images/bestofjs.jpg)](https://bestofjs.org/projects/drizzle-orm) ## Headless ORM? First and foremost, Drizzle is a library and a collection of complementary opt-in tools. **ORM** stands for _object relational mapping_, and developers tend to call Django-like or Spring-like tools an ORM. We truly believe it's a misconception based on legacy nomenclature, and we call them **data frameworks**. With data frameworks you have to build projects **around them** and not **with them**. **Drizzle** lets you build your project the way you want, without interfering with your project or structure. Using Drizzle you can define and manage database schemas in TypeScript, access your data in a SQL-like or relational way, and take advantage of opt-in tools to push your developer experience _through the roof_. 🤯 ## Why SQL-like? **If you know SQL, you know Drizzle.** Other ORMs and data frameworks tend to deviate/abstract you away from SQL, which leads to a double learning curve: needing to know both SQL and the framework's API. Drizzle is the opposite. We embrace SQL and built Drizzle to be SQL-like at its core, so you can have zero to no learning curve and access to the full power of SQL. We bring all the familiar **[SQL schema](/docs/sql-schema-declaration)**, **[queries](/docs/select)**, **[automatic migrations](/docs/migrations)** and **[one more thing](/docs/rqb)**. ✨ ```typescript copy // Access your data await db .select() .from(countries) .leftJoin(cities, eq(cities.countryId, countries.id)) .where(eq(countries.id, 10)) ``` ```typescript copy // manage your schema export const countries = pgTable('countries', { id: serial('id').primaryKey(), name: varchar('name', { length: 256 }), }); export const cities = pgTable('cities', { id: serial('id').primaryKey(), name: varchar('name', { length: 256 }), countryId: integer('country_id').references(() => countries.id), }); ``` ```sql -- generate migrations CREATE TABLE IF NOT EXISTS "countries" ( "id" serial PRIMARY KEY NOT NULL, "name" varchar(256) ); CREATE TABLE IF NOT EXISTS "cities" ( "id" serial PRIMARY KEY NOT NULL, "name" varchar(256), "country_id" integer ); ALTER TABLE "cities" ADD CONSTRAINT "cities_country_id_countries_id_fk" FOREIGN KEY ("country_id") REFERENCES "countries"("id") ON DELETE no action ON UPDATE no action; ``` ## Why not SQL-like? We're always striving for a perfectly balanced solution, and while SQL-like does cover 100% of the needs, there are certain common scenarios where you can query data in a better way. We've built the **[Queries API](/docs/rqb)** for you, so you can fetch relational nested data from the database in the most convenient and performant way, and never think about joins and data mapping. **Drizzle always outputs exactly 1 SQL query.** Feel free to use it with serverless databases and never worry about performance or roundtrip costs! ```ts const result = await db.query.users.findMany({ with: { posts: true }, }); ``` ## Serverless? The best part is no part. **Drizzle has exactly 0 dependencies!** ![Drizzle is slim an Serverless ready](@/assets/images/drizzle31kb.jpg) Drizzle ORM is dialect-specific, slim, performant and serverless-ready **by design**. We've spent a lot of time to make sure you have best-in-class SQL dialect support, including Postgres, MySQL, and others. Drizzle operates natively through industry-standard database drivers. We support all major **[PostgreSQL](/docs/get-started-postgresql)**, **[MySQL](/docs/get-started-mysql)**, **[SQLite](/docs/get-started-sqlite)** or **[SingleStore](/docs/get-started-singlestore)**drivers out there, and we're adding new ones **[really fast](https://twitter.com/DrizzleORM/status/1653082492742647811?s=20)**. ## Welcome on board! More and more companies are adopting Drizzle in production, experiencing immense benefits in both DX and performance. **We're always there to help, so don't hesitate to reach out. We'll gladly assist you in your Drizzle journey!** We have an outstanding **[Discord community](https://driz.link/discord)** and welcome all builders to our **[Twitter](https://twitter.com/drizzleorm)**. Now go build something awesome with Drizzle and your **[PostgreSQL](/docs/get-started-postgresql)**, **[MySQL](/docs/get-started-mysql)** or **[SQLite](/docs/get-started-sqlite)** database. 🚀 ### Video Showcase {/* tRPC + NextJS App Router = Simple Typesafe APIs Jack Herrington 19:17 https://www.youtube.com/watch?v=qCLV0Iaq9zU */} {/* https://www.youtube.com/watch?v=qDunJ0wVIec */} {/* https://www.youtube.com/watch?v=NZpPMlSAez0 */} {/* https://www.youtube.com/watch?v=-A0kMiJqQRY */} Source: https://orm.drizzle.team/docs/perf-queries import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; # Query performance When it comes to **Drizzle** — we're a thin TypeScript layer on top of SQL with almost 0 overhead and to make it actual 0, you can utilise our prepared statements API. **When you run a query on the database, there are several things that happen:** - all the configurations of the query builder got concatenated to the SQL string - that string and params are sent to the database driver - driver compiles SQL query to the binary SQL executable format and sends it to the database With prepared statements you do SQL concatenation once on the Drizzle ORM side and then database driver is able to reuse precompiled binary SQL instead of parsing query all the time. It has extreme performance benefits on large SQL queries. Different database drivers support prepared statements in different ways and sometimes Drizzle ORM you can go [**faster than better-sqlite3 driver.**](https://twitter.com/_alexblokh/status/1593593415907909634) ## Prepared statement ```typescript copy {3} const db = drizzle(...); const prepared = db.select().from(customers).prepare("statement_name"); const res1 = await prepared.execute(); const res2 = await prepared.execute(); const res3 = await prepared.execute(); ``` ```typescript copy {3} const db = drizzle(...); const prepared = db.select().from(customers).prepare(); const res1 = await prepared.execute(); const res2 = await prepared.execute(); const res3 = await prepared.execute(); ``` ```typescript copy {3} const db = drizzle(...); const prepared = db.select().from(customers).prepare(); const res1 = prepared.all(); const res2 = prepared.all(); const res3 = prepared.all(); ``` ```typescript copy {3} const db = drizzle(...); const prepared = db.select().from(customers).prepare(); const res1 = await prepared.execute(); const res2 = await prepared.execute(); const res3 = await prepared.execute(); ``` ## Placeholder Whenever you need to embed a dynamic runtime value - you can use the `sql.placeholder(...)` api ```ts {6,9-10,15,18} import { sql } from "drizzle-orm"; const p1 = db .select() .from(customers) .where(eq(customers.id, sql.placeholder('id'))) .prepare("p1") await p1.execute({ id: 10 }) // SELECT * FROM customers WHERE id = 10 await p1.execute({ id: 12 }) // SELECT * FROM customers WHERE id = 12 const p2 = db .select() .from(customers) .where(sql`lower(${customers.name}) like ${sql.placeholder('name')}`) .prepare("p2"); await p2.execute({ name: '%an%' }) // SELECT * FROM customers WHERE name ilike '%an%' ``` ```ts copy {6,9-10,15,18} import { sql } from "drizzle-orm"; const p1 = db .select() .from(customers) .where(eq(customers.id, sql.placeholder('id'))) .prepare() await p1.execute({ id: 10 }) // SELECT * FROM customers WHERE id = 10 await p1.execute({ id: 12 }) // SELECT * FROM customers WHERE id = 12 const p2 = db .select() .from(customers) .where(sql`lower(${customers.name}) like ${sql.placeholder('name')}`) .prepare(); await p2.execute({ name: '%an%' }) // SELECT * FROM customers WHERE name ilike '%an%' ``` ```ts copy {6,9-10,15,18} import { sql } from "drizzle-orm"; const p1 = db .select() .from(customers) .where(eq(customers.id, sql.placeholder('id'))) .prepare() p1.get({ id: 10 }) // SELECT * FROM customers WHERE id = 10 p1.get({ id: 12 }) // SELECT * FROM customers WHERE id = 12 const p2 = db .select() .from(customers) .where(sql`lower(${customers.name}) like ${sql.placeholder('name')}`) .prepare(); p2.all({ name: '%an%' }) // SELECT * FROM customers WHERE name ilike '%an%' ``` ```ts copy {6,9-10,15,18} import { sql } from "drizzle-orm"; const p1 = db .select() .from(customers) .where(eq(customers.id, sql.placeholder('id'))) .prepare() await p1.execute({ id: 10 }) // SELECT * FROM customers WHERE id = 10 await p1.execute({ id: 12 }) // SELECT * FROM customers WHERE id = 12 const p2 = db .select() .from(customers) .where(sql`lower(${customers.name}) like ${sql.placeholder('name')}`) .prepare(); await p2.execute({ name: '%an%' }) // SELECT * FROM customers WHERE name ilike '%an%' ``` Source: https://orm.drizzle.team/docs/perf-serverless # Drizzle Serverless performance You can get immense benefits with `serverless functions` like AWS Lamba or Vercel Server Functions (they're AWS Lamba based), since they can live up to 15mins and reuse both database connections and prepared statements. On the other, hand `edge functions` tend to clean up straight after they're invoked which leads to little to no performance benefits. To reuse your database connection and prepared statements you just have to declare them outside of handler scope: ```ts const databaseConnection = ...; const db = drizzle({ client: databaseConnection }); const prepared = db.select().from(...).prepare(); // AWS handler export const handler = async (event: APIGatewayProxyEvent) => { return prepared.execute(); } ``` Source: https://orm.drizzle.team/docs/prisma import Npm from '@mdx/Npm.astro'; import Tabs from '@mdx/Tabs.astro'; import Tab from '@mdx/Tab.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Steps from '@mdx/Steps.astro'; # Drizzle extension for Prisma If you have an existing project with Prisma and want to try Drizzle or gradually adopt it, you can use our first-class extension that will add Drizzle API to your Prisma client. It will allow you to use Drizzle alongside your Prisma queries reusing your existing DB connection. ## How to use #### Install dependencies You need to install Drizzle itself and a generator package that will create Drizzle schema from the Prisma schema. drizzle-orm@latest -D drizzle-prisma-generator #### Update your Prisma schema Add Drizzle generator to your Prisma schema. `output` is the path where generated Drizzle schema TS files will be placed. ```prisma copy filename="schema.prisma" {5-8} generator client { provider = "prisma-client-js" } generator drizzle { provider = "drizzle-prisma-generator" output = "./drizzle" // Where to put generated Drizle tables } // Rest of your Prisma schema datasource db { provider = "postgresql" url = env("DB_URL") } model User { id Int @id @default(autoincrement()) email String @unique name String? } ... ``` #### Generate Drizzle schema ```bash prisma generate ``` #### Add Drizzle extension to your Prisma client ```ts copy import { PrismaClient } from '@prisma/client'; import { drizzle } from 'drizzle-orm/prisma/pg'; const prisma = new PrismaClient().$extends(drizzle()); ``` ```ts copy import { PrismaClient } from '@prisma/client'; import { drizzle } from 'drizzle-orm/prisma/mysql'; const prisma = new PrismaClient().$extends(drizzle()); ``` ```ts copy import { PrismaClient } from '@prisma/client'; import { drizzle } from 'drizzle-orm/prisma/sqlite'; const prisma = new PrismaClient().$extends(drizzle()); ``` #### Run Drizzle queries via `prisma.$drizzle` ✨ In order to use Drizzle query builder, you need references to Drizzle tables. You can import them from the output path that you specified in the generator config. ```ts copy import { User } from './drizzle'; await prisma.$drizzle.insert().into(User).values({ email: 'sorenbs@drizzle.team', name: 'Søren' }); const users = await prisma.$drizzle.select().from(User); ``` ## Limitations - [Relational queries](/docs/rqb) are not supported due to a [Prisma driver limitation](https://github.com/prisma/prisma/issues/17576). Because of it, Prisma unable to return query results in array format, which is required for relational queries to work. - In SQLite, `.values()` (e.g. `await db.select().from(table).values()`) is not supported, because of the same reason as above. - [Prepared statements](/docs/perf-queries#prepared-statement) support is limited - `.prepare()` will only build the SQL query on Drizzle side, because there is no Prisma API for prepared queries. Source: https://orm.drizzle.team/docs/query-utils import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import $count from '@mdx/$count.mdx'; # Drizzle query utils ### $count <$count/> Source: https://orm.drizzle.team/docs/quick import Npm from "@mdx/Npm.astro"; # Quick start Lets build a quick start app with `PostgreSQL` + `postgresjs` and run our first migration. The first thing we need to do is to install `drizzle-orm` and `drizzle-kit`: drizzle-orm postgres -D drizzle-kit Lets declare our `schema.ts`: ```plaintext {4} 📦 ├ ... ├ 📂 src │ └ 📜 schema.ts └ 📜 package.json ``` ```ts copy filename="schema.ts" import { serial, text, timestamp, pgTable } from "drizzle-orm/pg-core"; export const user = pgTable("user", { id: serial("id"), name: text("name"), email: text("email"), password: text("password"), role: text("role").$type<"admin" | "customer">(), createdAt: timestamp("created_at"), updatedAt: timestamp("updated_at"), }); ``` Now lets add drizzle configuration file: ```plaintext {4} 📦 ├ ... ├ 📂 src ├ 📜 drizzle.config.ts └ 📜 package.json ``` ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: "postgresql", schema: "./src/schema.ts", out: "./drizzle", }); ``` Add `generate` and `migrate` commands to `package.json` and run our first migrations generation: ```json filename="package.json" {5,6} { "name": "first time?", "version": "0.0.1", "scripts": { "generate": "drizzle-kit generate", "migrate": "drizzle-kit migrate" }, } ``` ```shell filename="terminal" $ npm run generate ... [✓] Your SQL migration file ➜ drizzle/0000_pale_mister_fear.sql 🚀 ``` Done! We now have our first SQL migration file 🥳 ```plaintext {4} 📦 ├ 📂 drizzle │ ├ 📂 _meta │ └ 📜 0000_pale_mister_fear.sql ├ 📂 src ├ 📜 drizzle.config.ts └ 📜 package.json ``` Now lets run our first migration to the database: ```shell filename="terminal" $ npm run migrate ``` That's it, folks! **My personal congratulations 🎉** Source: https://orm.drizzle.team/docs/read-replicas import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; # Read Replicas When your project involves a set of read replica instances, and you require a convenient method for managing SELECT queries from read replicas, as well as performing create, delete, and update operations on the primary instance, you can leverage the `withReplicas()` function within Drizzle ```ts copy import { sql } from 'drizzle-orm'; import { drizzle } from 'drizzle-orm/node-postgres'; import { boolean, jsonb, pgTable, serial, text, timestamp, withReplicas } from 'drizzle-orm/pg-core'; const usersTable = pgTable('users', { id: serial('id' as string).primaryKey(), name: text('name').notNull(), verified: boolean('verified').notNull().default(false), jsonb: jsonb('jsonb').$type(), createdAt: timestamp('created_at', { withTimezone: true }).notNull().defaultNow(), }); const primaryDb = drizzle("postgres://user:password@host:port/primary_db"); const read1 = drizzle("postgres://user:password@host:port/read_replica_1"); const read2 = drizzle("postgres://user:password@host:port/read_replica_2"); const db = withReplicas(primaryDb, [read1, read2]); ``` ```ts copy import { drizzle } from "drizzle-orm/mysql2"; import mysql from "mysql2/promise"; import { boolean, mysqlTable, serial, text, withReplicas } from 'drizzle-orm/mysql-core'; const usersTable = mysqlTable('users', { id: serial('id' as string).primaryKey(), name: text('name').notNull(), verified: boolean('verified').notNull().default(false), }); const primaryClient = await mysql.createConnection({ host: "host", user: "user", database: "primary_db", }) const primaryDb = drizzle({ client: primaryClient }); const read1Client = await mysql.createConnection({ host: "host", user: "user", database: "read_1", }) const read1 = drizzle({ client: read1Client }); const read2Client = await mysql.createConnection({ host: "host", user: "user", database: "read_2", }) const read2 = drizzle({ client: read2Client }); const db = withReplicas(primaryDb, [read1, read2]); ``` ```ts copy import { sql } from 'drizzle-orm'; import { sqliteTable, int, text, withReplicas } from 'drizzle-orm/sqlite-core'; import { createClient } from '@libsql/client'; import { drizzle } from 'drizzle-orm/libsql'; const usersTable = sqliteTable('users', { id: int('id' as string).primaryKey(), name: text('name').notNull(), }); const primaryDb = drizzle({ client: createClient({ url: 'DATABASE_URL', authToken: 'DATABASE_AUTH_TOKEN' }) }); const read1 = drizzle({ client: createClient({ url: 'DATABASE_URL', authToken: 'DATABASE_AUTH_TOKEN' }) }); const read2 = drizzle({ client: createClient({ url: 'DATABASE_URL', authToken: 'DATABASE_AUTH_TOKEN' }) }); const db = withReplicas(primaryDb, [read1, read2]); ``` ```ts copy import { drizzle } from "drizzle-orm/singlestore"; import mysql from "mysql2/promise"; import { boolean, singlestoreTable, serial, text, withReplicas } from 'drizzle-orm/singlestore-core'; const usersTable = singlestoreTable('users', { id: serial('id' as string).primaryKey(), name: text('name').notNull(), verified: boolean('verified').notNull().default(false), }); const primaryClient = await mysql.createConnection({ host: "host", user: "user", database: "primary_db", }) const primaryDb = drizzle({ client: primaryClient }); const read1Client = await mysql.createConnection({ host: "host", user: "user", database: "read_1", }) const read1 = drizzle({ client: read1Client }); const read2Client = await mysql.createConnection({ host: "host", user: "user", database: "read_2", }) const read2 = drizzle({ client: read2Client }); const db = withReplicas(primaryDb, [read1, read2]); ``` You can now use the `db` instance the same way you did before. Drizzle will handle the choice between read replica and the primary instance automatically ```ts // Read from either the read1 connection or the read2 connection await db.select().from(usersTable) // Use the primary database for the delete operation await db.delete(usersTable).where(eq(usersTable.id, 1)) ``` You can use the `$primary` key to force using primary instances even for read operations ```ts // read from primary await db.$primary.select().from(usersTable); ``` With Drizzle, you can also specify custom logic for choosing read replicas. You can make a weighted decision or any other custom selection method for random read replica choice. Here is an implementation example of custom logic for selecting read replicas, where the first replica has a 70% chance of being chosen, and the second replica has a 30% chance of being selected. Keep in mind that you can implement any type of random selection method for read replicas ```ts const db = withReplicas(primaryDb, [read1, read2], (replicas) => { const weight = [0.7, 0.3]; let cumulativeProbability = 0; const rand = Math.random(); for (const [i, replica] of replicas.entries()) { cumulativeProbability += weight[i]!; if (rand < cumulativeProbability) return replica; } return replicas[0]! }); await db.select().from(usersTable) ``` Source: https://orm.drizzle.team/docs/relations import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; import CodeTab from '@mdx/CodeTab.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; # Drizzle soft relations The sole purpose of Drizzle relations is to let you query your relational data in the most simple and consise way:
```ts import * as schema from './schema'; import { drizzle } from 'drizzle-orm/…'; const db = drizzle(client, { schema }); const result = db.query.users.findMany({ with: { posts: true, }, }); ``` ```ts [{ id: 10, name: "Dan", posts: [ { id: 1, content: "SQL is awesome", authorId: 10, }, { id: 2, content: "But check relational queries", authorId: 10, } ] }] ```
```ts import { drizzle } from 'drizzle-orm/…'; import { eq } from 'drizzle-orm'; import { posts, users } from './schema'; const db = drizzle(client); const res = await db.select() .from(users) .leftJoin(posts, eq(posts.authorId, users.id)) .orderBy(users.id) const mappedResult = ```
### One-to-one Drizzle ORM provides you an API to define `one-to-one` relations between tables with the `relations` operator. An example of a `one-to-one` relation between users and users, where a user can invite another (this example uses a self reference): ```typescript copy {10-15} import { pgTable, serial, text, integer, boolean } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), invitedBy: integer('invited_by'), }); export const usersRelations = relations(users, ({ one }) => ({ invitee: one(users, { fields: [users.invitedBy], references: [users.id], }), })); ``` Another example would be a user having a profile information stored in separate table. In this case, because the foreign key is stored in the "profile_info" table, the user relation have neither fields or references. This tells Typescript that `user.profileInfo` is nullable: ```typescript copy {9-17} import { pgTable, serial, text, integer, jsonb } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const usersRelations = relations(users, ({ one }) => ({ profileInfo: one(profileInfo), })); export const profileInfo = pgTable('profile_info', { id: serial('id').primaryKey(), userId: integer('user_id').references(() => users.id), metadata: jsonb('metadata'), }); export const profileInfoRelations = relations(profileInfo, ({ one }) => ({ user: one(users, { fields: [profileInfo.userId], references: [users.id] }), })); const user = await queryUserWithProfileInfo(); //____^? type { id: number, profileInfo: { ... } | null } ``` ### One-to-many Drizzle ORM provides you an API to define `one-to-many` relations between tables with `relations` operator. Example of `one-to-many` relation between users and posts they've written: ```typescript copy {9-11, 19-24} import { pgTable, serial, text, integer } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const usersRelations = relations(users, ({ many }) => ({ posts: many(posts), })); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content'), authorId: integer('author_id'), }); export const postsRelations = relations(posts, ({ one }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id], }), })); ``` Now lets add comments to the posts: ```typescript copy {14,17-22,24-29} ... export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content'), authorId: integer('author_id'), }); export const postsRelations = relations(posts, ({ one, many }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id], }), comments: many(comments) })); export const comments = pgTable('comments', { id: serial('id').primaryKey(), text: text('text'), authorId: integer('author_id'), postId: integer('post_id'), }); export const commentsRelations = relations(comments, ({ one }) => ({ post: one(posts, { fields: [comments.postId], references: [posts.id], }), })); ``` ### Many-to-many Drizzle ORM provides you an API to define `many-to-many` relations between tables through so called `junction` or `join` tables, they have to be explicitly defined and store associations between related tables. Example of `many-to-many` relation between users and groups: ```typescript copy {9-11, 18-20, 37-46} import { relations } from 'drizzle-orm'; import { integer, pgTable, primaryKey, serial, text } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const usersRelations = relations(users, ({ many }) => ({ usersToGroups: many(usersToGroups), })); export const groups = pgTable('groups', { id: serial('id').primaryKey(), name: text('name'), }); export const groupsRelations = relations(groups, ({ many }) => ({ usersToGroups: many(usersToGroups), })); export const usersToGroups = pgTable( 'users_to_groups', { userId: integer('user_id') .notNull() .references(() => users.id), groupId: integer('group_id') .notNull() .references(() => groups.id), }, (t) => [ primaryKey({ columns: [t.userId, t.groupId] }) ], ); export const usersToGroupsRelations = relations(usersToGroups, ({ one }) => ({ group: one(groups, { fields: [usersToGroups.groupId], references: [groups.id], }), user: one(users, { fields: [usersToGroups.userId], references: [users.id], }), })); ``` ### Foreign keys You might've noticed that `relations` look similar to foreign keys — they even have a `references` property. So what's the difference? While foreign keys serve a similar purpose, defining relations between tables, they work on a different level compared to `relations`. Foreign keys are a database level constraint, they are checked on every `insert`/`update`/`delete` operation and throw an error if a constraint is violated. On the other hand, `relations` are a higher level abstraction, they are used to define relations between tables on the application level only. They do not affect the database schema in any way and do not create foreign keys implicitly. What this means is `relations` and foreign keys can be used together, but they are not dependent on each other. You can define `relations` without using foreign keys (and vice versa), which allows them to be used with databases that do not support foreign keys. The following two examples will work exactly the same in terms of querying the data using Drizzle relational queries. ```ts {15} export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const usersRelations = relations(users, ({ one, many }) => ({ profileInfo: one(users, { fields: [profileInfo.userId], references: [users.id], }), })); export const profileInfo = pgTable('profile_info', { id: serial('id').primaryKey(), userId: integer("user_id"), metadata: jsonb("metadata"), }); ``` ```ts {15} export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const usersRelations = relations(users, ({ one, many }) => ({ profileInfo: one(users, { fields: [profileInfo.userId], references: [users.id], }), })); export const profileInfo = pgTable('profile_info', { id: serial('id').primaryKey(), userId: integer("user_id").references(() => users.id), metadata: jsonb("metadata"), }); ``` ### Foreign key actions for more information check [postgres foreign keys docs](https://www.postgresql.org/docs/current/ddl-constraints.html#DDL-CONSTRAINTS-FK) You can specify actions that should occur when the referenced data in the parent table is modified. These actions are known as "foreign key actions." PostgreSQL provides several options for these actions. On Delete/ Update Actions - `CASCADE`: When a row in the parent table is deleted, all corresponding rows in the child table will also be deleted. This ensures that no orphaned rows exist in the child table. - `NO ACTION`: This is the default action. It prevents the deletion of a row in the parent table if there are related rows in the child table. The DELETE operation in the parent table will fail. - `RESTRICT`: Similar to NO ACTION, it prevents the deletion of a parent row if there are dependent rows in the child table. It is essentially the same as NO ACTION and included for compatibility reasons. - `SET DEFAULT`: If a row in the parent table is deleted, the foreign key column in the child table will be set to its default value if it has one. If it doesn't have a default value, the DELETE operation will fail. - `SET NULL`: When a row in the parent table is deleted, the foreign key column in the child table will be set to NULL. This action assumes that the foreign key column in the child table allows NULL values. > Analogous to ON DELETE there is also ON UPDATE which is invoked when a referenced column is changed (updated). The possible actions are the same, except that column lists cannot be specified for SET NULL and SET DEFAULT. In this case, CASCADE means that the updated values of the referenced column(s) should be copied into the referencing row(s). in drizzle you can add foreign key action using `references()` second argument. type of the actions ```typescript export type UpdateDeleteAction = 'cascade' | 'restrict' | 'no action' | 'set null' | 'set default'; // second argument of references interface actions?: { onUpdate?: UpdateDeleteAction; onDelete?: UpdateDeleteAction; } | undefined ``` In the following example, adding `onDelete: 'cascade'` to the author field on the `posts` schema means that deleting the `user` will also delete all related Post records. ```typescript {11} import { pgTable, serial, text, integer } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), name: text('name'), author: integer('author').references(() => users.id, {onDelete: 'cascade'}).notNull(), }); ``` For constraints specified with the `foreignKey` operator, foreign key actions are defined with the syntax: ```typescript {18-19} import { foreignKey, pgTable, serial, text, integer } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const posts = pgTable('posts', { id: serial('id').primaryKey(), name: text('name'), author: integer('author').notNull(), }, (table) => [ foreignKey({ name: "author_fk", columns: [table.author], foreignColumns: [users.id], }) .onDelete('cascade') .onUpdate('cascade') ]); ``` ### Disambiguating relations Drizzle also provides the `relationName` option as a way to disambiguate relations when you define multiple of them between the same two tables. For example, if you define a `posts` table that has the `author` and `reviewer` relations. ```ts {9-12, 21-32} import { pgTable, serial, text, integer } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name'), }); export const usersRelations = relations(users, ({ many }) => ({ author: many(posts, { relationName: 'author' }), reviewer: many(posts, { relationName: 'reviewer' }), })); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content'), authorId: integer('author_id'), reviewerId: integer('reviewer_id'), }); export const postsRelations = relations(posts, ({ one }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id], relationName: 'author', }), reviewer: one(users, { fields: [posts.reviewerId], references: [users.id], relationName: 'reviewer', }), })); ``` Source: https://orm.drizzle.team/docs/rls import Callout from '@mdx/Callout.astro'; # 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. ```ts 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. ```ts 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. ```ts 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** ```ts 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``, }), ]); ``` **Policy options** | | | | :----------------------- | :---------------------------------------------------------------------------------------------------------------------------------------- | | `as` | Possible values are `permissive` or `restrictive` | | `to` | Specifies the role to which the policy applies. Possible values include `public`, `current_role`, `current_user`, `session_user`, or any other role name as a string. You can also reference a `pgRole` object. | | `for` | Defines the commands this policy will be applied to. Possible values are `all`, `select`, `insert`, `update`, `delete`. | | `using` | The SQL statement that will be applied to the `USING` part of the policy creation statement. | | `withCheck` | An SQL statement that will be applied to the `WITH CHECK` part of the policy creation statement. | **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 ```ts 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`](docs/drizzle-config-file) documentation. By default, `drizzle-kit` does not manage roles for you, so you will need to enable this feature in `drizzle.config.ts`. ```ts {12-14} // 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** ```ts // 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** ```ts // 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** ```ts // 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** ```ts // 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 the `provider` option and `exclude` additional roles: ```ts // 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: ```ts {5} ... 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: ```ts 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: ```ts 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. ```ts // 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})`; export const neonIdentitySchema = pgSchema('neon_identity'); export const usersSync = neonIdentitySchema.table('users_sync', { rawJson: jsonb('raw_json').notNull(), id: text().primaryKey().notNull(), name: text(), email: text(), createdAt: timestamp('created_at', { withTimezone: true, mode: 'string' }), deletedAt: timestamp('deleted_at', { withTimezone: true, mode: 'string' }), }); ``` For example, you can use the `Neon` predefined roles and functions like this: ```ts 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. ```ts // 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: ```ts 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 ```ts // 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( 'messages', { id: bigserial({ mode: 'bigint' }).primaryKey(), topic: text().notNull(), extension: text({ enum: ['presence', 'broadcast', 'postgres_changes'], }).notNull(), }, ); export const authUid = sql`(select auth.uid())`; export const realtimeTopic = sql`realtime.topic()`; ``` This allows you to use it in your code, and Drizzle Kit will treat them as existing databases, using them only as information to connect to other entities ```ts import { foreignKey, pgPolicy, pgTable, text, uuid } from "drizzle-orm/pg-core"; import { sql } from "drizzle-orm/sql"; import { authenticatedRole, authUsers } from "drizzle-orm/supabase"; export const profiles = pgTable( "profiles", { id: uuid().primaryKey().notNull(), email: text().notNull(), }, (table) => [ foreignKey({ columns: [table.id], // reference to the auth table from Supabase foreignColumns: [authUsers.id], name: "profiles_id_fk", }).onDelete("cascade"), pgPolicy("authenticated can view all profiles", { for: "select", // using predefined role from Supabase to: authenticatedRole, using: sql`true`, }), ] ); ``` Let's check an example of adding a policy to a table that exists in `Supabase` ```ts 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); ``` We also have a great example showcasing how to use Drizzle RLS with Supabase and how to make actual queries with it. It also includes a great wrapper, `createDrizzle`, that can handle all the transactional work with Supabase for you. In upcoming releases, it will be moved to drizzle-orm/supabase, allowing you to use it natively Please check [Drizzle SupaSecureSlack repo](https://github.com/rphlmr/drizzle-supabase-rls) Here is an example of an implementation from this repository ```ts type SupabaseToken = { iss?: string; sub?: string; aud?: string[] | string; exp?: number; nbf?: number; iat?: number; jti?: string; role?: string; }; export function createDrizzle(token: SupabaseToken, { admin, client }: { admin: PgDatabase; client: PgDatabase }) { return { admin, rls: (async (transaction, ...rest) => { return await client.transaction(async (tx) => { // Supabase exposes auth.uid() and auth.jwt() // https://supabase.com/docs/guides/database/postgres/row-level-security#helper-functions try { await tx.execute(sql` -- auth.jwt() select set_config('request.jwt.claims', '${sql.raw( JSON.stringify(token) )}', TRUE); -- auth.uid() select set_config('request.jwt.claim.sub', '${sql.raw( token.sub ?? "" )}', TRUE); -- set local role set local role ${sql.raw(token.role ?? "anon")}; `); return await transaction(tx); } finally { await tx.execute(sql` -- reset select set_config('request.jwt.claims', NULL, TRUE); select set_config('request.jwt.claim.sub', NULL, TRUE); reset role; `); } }, ...rest); }) as typeof client.transaction, }; } ``` And it can be used as ```ts // https://github.com/orgs/supabase/discussions/23224 // Should be secure because we use the access token that is signed, and not the data read directly from the storage export async function createDrizzleSupabaseClient() { const { data: { session }, } = await createClient().auth.getSession(); return createDrizzle(decode(session?.access_token ?? ""), { admin, client }); } async function getRooms() { const db = await createDrizzleSupabaseClient(); return db.rls((tx) => tx.select().from(rooms)); } ``` Source: https://orm.drizzle.team/docs/rqb import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Section from '@mdx/Section.astro'; import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; # Drizzle Queries Drizzle ORM is designed to be a thin typed layer on top of SQL. We truly believe we've designed the best way to operate an SQL database from TypeScript and it's time to make it better. Relational queries are meant to provide you with a great developer experience for querying nested relational data from an SQL database, avoiding multiple joins and complex data mappings. It is an extension to the existing schema definition and query builder. You can opt-in to use it based on your needs. We've made sure you have both the best-in-class developer experience and performance. ```typescript copy /schema/3 import * as schema from './schema'; import { drizzle } from 'drizzle-orm/...'; const db = drizzle({ schema }); const result = await db.query.users.findMany({ with: { posts: true }, }); ``` ```ts [{ id: 10, name: "Dan", posts: [ { id: 1, content: "SQL is awesome", authorId: 10, }, { id: 2, content: "But check relational queries", authorId: 10, } ] }] ``` ```typescript copy import { integer, serial, text, pgTable } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), }); export const usersRelations = relations(users, ({ many }) => ({ posts: many(posts), })); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content').notNull(), authorId: integer('author_id').notNull(), }); export const postsRelations = relations(posts, ({ one }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id] }), })); ``` ⚠️ If you have SQL schema declared in multiple files you can do it like that ```typescript copy /schema/3 import * as schema1 from './schema1'; import * as schema2 from './schema2'; import { drizzle } from 'drizzle-orm/...'; const db = drizzle({ schema: { ...schema1, ...schema2 } }); const result = await db.query.users.findMany({ with: { posts: true }, }); ``` ```ts // schema declaration in the first file ``` ```ts // schema declaration in the second file ``` ## Modes Drizzle relational queries always generate exactly one SQL statement to run on the database and it has certain caveats. To have best in class support for every database out there we've introduced **`modes`**. Drizzle relational queries use lateral joins of subqueries under the hood and for now PlanetScale does not support them. When using **mysql2** driver with regular **MySQL** database — you should specify `mode: "default"` When using **mysql2** driver with **PlanetScale** — you need to specify `mode: "planetscale"` ```ts copy import * as schema from './schema'; import { drizzle } from "drizzle-orm/mysql2"; import mysql from "mysql2/promise"; const connection = await mysql.createConnection({ uri: process.env.PLANETSCALE_DATABASE_URL, }); const db = drizzle({ client: connection, schema, mode: 'planetscale' }); ``` ## Querying Relational queries are an extension to Drizzle's original **[query builder](/docs/select)**. You need to provide all `tables` and `relations` from your schema file/files upon `drizzle()` initialization and then just use the `db.query` API. `drizzle` import path depends on the **[database driver](/docs/connect-overview)** you're using. ```ts import * as schema from './schema'; import { drizzle } from 'drizzle-orm/...'; const db = drizzle({ schema }); await db.query.users.findMany(...); ``` ```ts // if you have schema in multiple files import * as schema1 from './schema1'; import * as schema2 from './schema2'; import { drizzle } from 'drizzle-orm/...'; const db = drizzle({ schema: { ...schema1, ...schema2 } }); await db.query.users.findMany(...); ``` ```typescript copy import { type AnyPgColumn, boolean, integer, pgTable, primaryKey, serial, text, timestamp } from 'drizzle-orm/pg-core'; import { relations } from 'drizzle-orm'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), invitedBy: integer('invited_by').references((): AnyPgColumn => users.id), }); export const usersRelations = relations(users, ({ one, many }) => ({ invitee: one(users, { fields: [users.invitedBy], references: [users.id] }), usersToGroups: many(usersToGroups), posts: many(posts), })); export const groups = pgTable('groups', { id: serial('id').primaryKey(), name: text('name').notNull(), description: text('description'), }); export const groupsRelations = relations(groups, ({ many }) => ({ usersToGroups: many(usersToGroups), })); export const usersToGroups = pgTable('users_to_groups', { id: serial('id').primaryKey(), userId: integer('user_id').notNull().references(() => users.id), groupId: integer('group_id').notNull().references(() => groups.id), }, (t) => [ primaryKey(t.userId, t.groupId) ]); export const usersToGroupsRelations = relations(usersToGroups, ({ one }) => ({ group: one(groups, { fields: [usersToGroups.groupId], references: [groups.id] }), user: one(users, { fields: [usersToGroups.userId], references: [users.id] }), })); export const posts = pgTable('posts', { id: serial('id').primaryKey(), content: text('content').notNull(), authorId: integer('author_id').references(() => users.id), createdAt: timestamp('created_at', { withTimezone: true }).notNull().defaultNow(), }); export const postsRelations = relations(posts, ({ one, many }) => ({ author: one(users, { fields: [posts.authorId], references: [users.id] }), comments: many(comments), })); export const comments = pgTable('comments', { id: serial('id').primaryKey(), content: text('content').notNull(), creator: integer('creator').references(() => users.id), postId: integer('post_id').references(() => posts.id), createdAt: timestamp('created_at', { withTimezone: true }).notNull().defaultNow(), }); export const commentsRelations = relations(comments, ({ one, many }) => ({ post: one(posts, { fields: [comments.postId], references: [posts.id] }), author: one(users, { fields: [comments.creator], references: [users.id] }), likes: many(commentLikes), })); export const commentLikes = pgTable('comment_likes', { id: serial('id').primaryKey(), creator: integer('creator').references(() => users.id), commentId: integer('comment_id').references(() => comments.id), createdAt: timestamp('created_at', { withTimezone: true }).notNull().defaultNow(), }); export const commentLikesRelations = relations(commentLikes, ({ one }) => ({ comment: one(comments, { fields: [commentLikes.commentId], references: [comments.id] }), author: one(users, { fields: [commentLikes.creator], references: [users.id] }), })); ``` Drizzle provides `.findMany()` and `.findFirst()` APIs. ### Find many
```typescript copy const users = await db.query.users.findMany(); ``` ```ts // result type const result: { id: number; name: string; verified: boolean; invitedBy: number | null; }[]; ```
### Find first `.findFirst()` will add `limit 1` to the query.
```typescript copy const user = await db.query.users.findFirst(); ``` ```ts // result type const result: { id: number; name: string; verified: boolean; invitedBy: number | null; }; ```
### Include relations `With` operator lets you combine data from multiple related tables and properly aggregate results. **Getting all posts with comments:** ```typescript copy const posts = await db.query.posts.findMany({ with: { comments: true, }, }); ``` **Getting first post with comments:** ```typescript copy const post = await db.query.posts.findFirst({ with: { comments: true, }, }); ``` You can chain nested with statements as much as necessary. For any nested `with` queries Drizzle will infer types using [Core Type API](/docs/goodies#type-api). **Get all users with posts. Each post should contain a list of comments:** ```typescript copy const users = await db.query.users.findMany({ with: { posts: { with: { comments: true, }, }, }, }); ``` ### Partial fields select `columns` parameter lets you include or omit columns you want to get from the database. Drizzle performs partial selects on the query level, no additional data is transferred from the database. Keep in mind that **a single SQL statement is outputted by Drizzle.** **Get all posts with just `id`, `content` and include `comments`:** ```typescript copy const posts = await db.query.posts.findMany({ columns: { id: true, content: true, }, with: { comments: true, } }); ``` **Get all posts without `content`:** ```typescript copy const posts = await db.query.posts.findMany({ columns: { content: false, }, }); ``` When both `true` and `false` select options are present, all `false` options are ignored. If you include the `name` field and exclude the `id` field, `id` exclusion will be redundant, all fields apart from `name` would be excluded anyways. **Exclude and Include fields in the same query:**
```typescript copy const users = await db.query.users.findMany({ columns: { name: true, id: false //ignored }, }); ``` ```ts // result type const users: { name: string; }; ```
**Only include columns from nested relations:**
```typescript copy const res = await db.query.users.findMany({ columns: {}, with: { posts: true } }); ``` ```ts // result type const res: { posts: { id: number, text: string } }[]; ```
### Nested partial fields select Just like with **[`partial select`](#partial-select)**, you can include or exclude columns of nested relations: ```typescript copy const posts = await db.query.posts.findMany({ columns: { id: true, content: true, }, with: { comments: { columns: { authorId: false } } } }); ``` ### Select filters Just like in our SQL-like query builder, relational queries API lets you define filters and conditions with the list of our **[`operators`](/docs/operators)**. You can either import them from `drizzle-orm` or use from the callback syntax:
```typescript copy import { eq } from 'drizzle-orm'; const users = await db.query.users.findMany({ where: eq(users.id, 1) }) ``` ```ts copy const users = await db.query.users.findMany({ where: (users, { eq }) => eq(users.id, 1), }) ```
Find post with `id=1` and comments that were created before particular date: ```typescript copy await db.query.posts.findMany({ where: (posts, { eq }) => (eq(posts.id, 1)), with: { comments: { where: (comments, { lt }) => lt(comments.createdAt, new Date()), }, }, }); ``` ### Limit & Offset Drizzle ORM provides `limit` & `offset` API for queries and for the nested entities. **Find 5 posts:** ```typescript copy await db.query.posts.findMany({ limit: 5, }); ``` **Find posts and get 3 comments at most:** ```typescript copy await db.query.posts.findMany({ with: { comments: { limit: 3, }, }, }); ``` `offset` is only available for top level query. ```typescript await db.query.posts.findMany({ limit: 5, offset: 2, // correct ✅ with: { comments: { offset: 3, // incorrect ❌ limit: 3, }, }, }); ``` Find posts with comments from the 5th to the 10th post: ```typescript copy await db.query.posts.findMany({ limit: 5, offset: 5, with: { comments: true, }, }); ``` ### Order By Drizzle provides API for ordering in the relational query builder. You can use same ordering **[core API](/docs/select#order-by)** or use `order by` operator from the callback with no imports.
```typescript copy import { desc, asc } from 'drizzle-orm'; await db.query.posts.findMany({ orderBy: [asc(posts.id)], }); ``` ```typescript copy await db.query.posts.findMany({ orderBy: (posts, { asc }) => [asc(posts.id)], }); ```
**Order by `asc` + `desc`:** ```typescript copy await db.query.posts.findMany({ orderBy: (posts, { asc }) => [asc(posts.id)], with: { comments: { orderBy: (comments, { desc }) => [desc(comments.id)], }, }, }); ``` ### Include custom fields Relational query API lets you add custom additional fields. It's useful when you need to retrieve data and apply additional functions to it. As of now aggregations are not supported in `extras`, please use **[`core queries`](/docs/select)** for that.
```typescript copy {5} import { sql } from 'drizzle-orm'; await db.query.users.findMany({ extras: { loweredName: sql`lower(${users.name})`.as('lowered_name'), }, }) ``` ```typescript copy {3} await db.query.users.findMany({ extras: { loweredName: (users, { sql }) => sql`lower(${users.name})`.as('lowered_name'), }, }) ```
`lowerName` as a key will be included to all fields in returned object. You have to explicitly specify `.as("")` To retrieve all users with groups, but with the fullName field included (which is a concatenation of firstName and lastName), you can use the following query with the Drizzle relational query builder.
```typescript copy const res = await db.query.users.findMany({ extras: { fullName: sql`concat(${users.name}, " ", ${users.name})`.as('full_name'), }, with: { usersToGroups: { with: { group: true, }, }, }, }); ``` ```ts // result type const res: { id: number; name: string; verified: boolean; invitedBy: number | null; fullName: string; usersToGroups: { group: { id: number; name: string; description: string | null; }; }[]; }[]; ```
To retrieve all posts with comments and add an additional field to calculate the size of the post content and the size of each comment content:
```typescript copy const res = await db.query.posts.findMany({ extras: (table, { sql }) => ({ contentLength: (sql`length(${table.content})`).as('content_length'), }), with: { comments: { extras: { commentSize: sql`length(${comments.content})`.as('comment_size'), }, }, }, }); ``` ```ts // result type const res: { id: number; createdAt: Date; content: string; authorId: number | null; contentLength: number; comments: { id: number; createdAt: Date; content: string; creator: number | null; postId: number | null; commentSize: number; }[]; }; ```
### Prepared statements Prepared statements are designed to massively improve query performance — [see here.](/docs/perf-queries) In this section, you can learn how to define placeholders and execute prepared statements using the Drizzle relational query builder. ##### **Placeholder in `where`**
```ts copy const prepared = db.query.users.findMany({ where: ((users, { eq }) => eq(users.id, placeholder('id'))), with: { posts: { where: ((users, { eq }) => eq(users.id, 1)), }, }, }).prepare('query_name'); const usersWithPosts = await prepared.execute({ id: 1 }); ```
```ts copy const prepared = db.query.users.findMany({ where: ((users, { eq }) => eq(users.id, placeholder('id'))), with: { posts: { where: ((users, { eq }) => eq(users.id, 1)), }, }, }).prepare(); const usersWithPosts = await prepared.execute({ id: 1 }); ```
```ts copy const prepared = db.query.users.findMany({ where: ((users, { eq }) => eq(users.id, placeholder('id'))), with: { posts: { where: ((users, { eq }) => eq(users.id, 1)), }, }, }).prepare(); const usersWithPosts = await prepared.execute({ id: 1 }); ```
##### **Placeholder in `limit`**
```ts copy const prepared = db.query.users.findMany({ with: { posts: { limit: placeholder('limit'), }, }, }).prepare('query_name'); const usersWithPosts = await prepared.execute({ limit: 1 }); ```
```ts copy const prepared = db.query.users.findMany({ with: { posts: { limit: placeholder('limit'), }, }, }).prepare(); const usersWithPosts = await prepared.execute({ limit: 1 }); ```
```ts copy const prepared = db.query.users.findMany({ with: { posts: { limit: placeholder('limit'), }, }, }).prepare(); const usersWithPosts = await prepared.execute({ limit: 1 }); ```
##### **Placeholder in `offset`**
```ts copy const prepared = db.query.users.findMany({ offset: placeholder('offset'), with: { posts: true, }, }).prepare('query_name'); const usersWithPosts = await prepared.execute({ offset: 1 }); ```
```ts copy const prepared = db.query.users.findMany({ offset: placeholder('offset'), with: { posts: true, }, }).prepare(); const usersWithPosts = await prepared.execute({ offset: 1 }); ```
```ts copy const prepared = db.query.users.findMany({ offset: placeholder('offset'), with: { posts: true, }, }).prepare(); const usersWithPosts = await prepared.execute({ offset: 1 }); ```
##### **Multiple placeholders**
```ts copy const prepared = db.query.users.findMany({ limit: placeholder('uLimit'), offset: placeholder('uOffset'), where: ((users, { eq, or }) => or(eq(users.id, placeholder('id')), eq(users.id, 3))), with: { posts: { where: ((users, { eq }) => eq(users.id, placeholder('pid'))), limit: placeholder('pLimit'), }, }, }).prepare('query_name'); const usersWithPosts = await prepared.execute({ pLimit: 1, uLimit: 3, uOffset: 1, id: 2, pid: 6 }); ```
```ts copy const prepared = db.query.users.findMany({ limit: placeholder('uLimit'), offset: placeholder('uOffset'), where: ((users, { eq, or }) => or(eq(users.id, placeholder('id')), eq(users.id, 3))), with: { posts: { where: ((users, { eq }) => eq(users.id, placeholder('pid'))), limit: placeholder('pLimit'), }, }, }).prepare(); const usersWithPosts = await prepared.execute({ pLimit: 1, uLimit: 3, uOffset: 1, id: 2, pid: 6 }); ```
```ts copy const prepared = db.query.users.findMany({ limit: placeholder('uLimit'), offset: placeholder('uOffset'), where: ((users, { eq, or }) => or(eq(users.id, placeholder('id')), eq(users.id, 3))), with: { posts: { where: ((users, { eq }) => eq(users.id, placeholder('pid'))), limit: placeholder('pLimit'), }, }, }).prepare(); const usersWithPosts = await prepared.execute({ pLimit: 1, uLimit: 3, uOffset: 1, id: 2, pid: 6 }); ```
Source: https://orm.drizzle.team/docs/schemas import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import Section from '@mdx/Section.astro'; import Callout from '@mdx/Callout.astro'; # Table schemas Drizzle ORM provides you an API for declaring SQL schemas for PostgreSQL and MySQL dialects. If you declare an entity within a schema, query builder will prepend schema names in queries:
`select * from "schema"."users"`
```ts copy {3,5,7} import { serial, text, pgTable, pgSchema } from "drizzle-orm/pg-core"; export const mySchema = pgSchema("my_schema"); export const colors = mySchema.enum('colors', ['red', 'green', 'blue']); export const mySchemaUsers = mySchema.table('users', { id: serial('id').primaryKey(), name: text('name'), color: colors('color').default('red'), }); ``` ```sql CREATE SCHEMA "my_schema"; CREATE TYPE "my_schema"."colors" AS ENUM ('red', 'green', 'blue'); CREATE TABLE "my_schema"."users" ( "id" serial PRIMARY KEY, "name" text, "color" "my_schema"."colors" DEFAULT 'red' ); ```
```ts {3,5} import { int, text, mysqlTable, mysqlSchema } from "drizzle-orm/mysql-core"; export const mySchema = mysqlSchema("my_schema") export const mySchemaUsers = mySchema.table("users", { id: int("id").primaryKey().autoincrement(), name: text("name"), }); ``` ```sql CREATE SCHEMA "my_schema"; CREATE TABLE "my_schema"."users" ( "id" serial PRIMARY KEY, "name" text ); ```
SQLite does not have support for schemas 😕
```ts {3,5} import { int, text, mysqlTable, singlestoreSchema } from "drizzle-orm/singlestore-core"; export const mySchema = singlestoreSchema("my_schema") export const mySchemaUsers = mySchema.table("users", { id: int("id").primaryKey().autoincrement(), name: text("name"), }); ``` ```sql CREATE SCHEMA "my_schema"; CREATE TABLE "my_schema"."users" ( "id" serial PRIMARY KEY, "name" text ); ```
{/* TODO: ??? example > **Warning** > If you will have tables with same names in different schemas then drizzle will respond with `never[]` error in result types and error from database > > In this case you may use [alias syntax](./joins#join-aliases-and-self-joins) */} Source: https://orm.drizzle.team/docs/seed-functions import Callout from '@mdx/Callout.astro'; # Generators For now, specifying `arraySize` along with `isUnique` in generators that support it will result in unique values being generated (not unique arrays), which will then be packed into arrays. ## --- ### `default` Generates the same given value each time the generator is called. | | param | default | type |:-| :-------- | :-------- | :-------- | |`defaultValue` |-- |`any` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ posts: { columns: { content: funcs.default({ // value you want to generate defaultValue: "post content", // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `valuesFromArray` Generates values from given array | | param | default | type |:-| :-------- | :-------- | :-------- | |`values` |-- |`any[]` \| `{ weight: number; values: any[] }[]` | |`isUnique` |database column uniqueness |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ posts: { columns: { title: funcs.valuesFromArray({ // Array of values you want to generate (can be an array of weighted values) values: ["Title1", "Title2", "Title3", "Title4", "Title5"], // Property that controls whether the generated values will be unique or not isUnique: true, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `intPrimaryKey` Generates sequential integers starting from 1. | | param | default | type |:-| :-------- | :-------- | :-------- | |-- |-- |-- ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ posts: { columns: { id: funcs.intPrimaryKey(), }, }, })); ``` ### `number` Generates numbers with a floating point within the given range | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |database column uniqueness |`boolean` | |`precision` |`100` |`number` | |`maxValue` |``` `precision * 1000` if isUnique equals false``` ``` `precision * count` if isUnique equals true``` |`number` | |`minValue` |`-maxValue` |`number` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ products: { columns: { unitPrice: funcs.number({ // lower border of range. minValue: 10, // upper border of range. maxValue: 120, // precision of generated number: // precision equals 10 means that values will be accurate to one tenth (1.2, 34.6); // precision equals 100 means that values will be accurate to one hundredth (1.23, 34.67). precision: 100, // property that controls if generated values gonna be unique or not. isUnique: false, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `int` Generates integers within the given range | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |database column uniqueness |`boolean` | |`maxValue` |``` `1000` if isUnique equals false``` ``` `count * 10` if isUnique equals true``` |`number \| bigint` | |`minValue` |`-maxValue` |`number \| bigint` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ products: { columns: { unitsInStock: funcs.int({ // lower border of range. minValue: 0, // lower border of range. maxValue: 100, // property that controls if generated values gonna be unique or not. isUnique: false, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `boolean` Generates boolean values (true or false) | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { isAvailable: funcs.boolean({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `date` Generates a date within the given range | | param | default | type |:-| :-------- | :-------------- | :-------- | |`minDate` |`new Date('2020-05-08')` | `string \| Date` | |`maxDate` |`new Date('2028-05-08')` | `string \| Date` | |`arraySize` |-- |`number` If only one of the parameters (`minDate` or `maxDate`) is provided, the unspecified parameter will be calculated by adding or subtracting 8 years to/from the specified one ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { birthDate: funcs.date({ // lower border of range. minDate: "1990-01-01", // upper border of range. maxDate: "2010-12-31", // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `time` Generates time in 24-hour format | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { birthTime: funcs.time({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `timestamp` Generates timestamps | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ orders: { columns: { shippedDate: funcs.timestamp({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `datetime` Generates datetime objects | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ orders: { columns: { shippedDate: funcs.datetime({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `year` Generates years in `YYYY` format | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { birthYear: funcs.year({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `json` Generates JSON objects with a fixed structure ```ts { email, name, isGraduated, hasJob, salary, startedWorking, visitedCountries} // or { email, name, isGraduated, hasJob, visitedCountries } ``` > The JSON structure will be picked randomly | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { metadata: funcs.json({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `interval` Generates time intervals. Example of a generated value: `1 year 12 days 5 minutes` | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` | column uniqueness |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { timeSpentOnWebsite: funcs.interval({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: true, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `string` Generates random strings | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { hashedPassword: funcs.string({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: false, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `uuid` Generates v4 UUID strings | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ products: { columns: { id: funcs.uuid({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `firstName` Generates a person's first name | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { firstName: funcs.firstName({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: true, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `lastName` Generates a person's last name | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { lastName: funcs.lastName({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: false, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `fullName` Generates a person's full name | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { fullName: funcs.fullName({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: true, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `email` Generates unique email addresses | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { email: funcs.email({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `phoneNumber` Generates unique phone numbers | | param | default | type |:-| :-------- | :-------- | :-------- | |`template` |-- |`string` | |`prefixes` |[Used dataset for prefixes](https://github.com/OleksiiKH0240/drizzle-orm/blob/main/drizzle-seed/src/datasets/phonesInfo.ts) |`string[]` | |`generatedDigitsNumbers` | `7` - `if prefixes was defined` |`number \| number[]` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; //generate phone number using template property await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { phoneNumber: funcs.phoneNumber({ // `template` - phone number template, where all '#' symbols will be substituted with generated digits. template: "+(380) ###-####", // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ```ts import { seed } from "drizzle-seed"; //generate phone number using prefixes and generatedDigitsNumbers properties await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { phoneNumber: funcs.phoneNumber({ // `prefixes` - array of any string you want to be your phone number prefixes.(not compatible with `template` property) prefixes: ["+380 99", "+380 67"], // `generatedDigitsNumbers` - number of digits that will be added at the end of prefixes.(not compatible with `template` property) generatedDigitsNumbers: 7, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ```ts import { seed } from "drizzle-seed"; // generate phone number using prefixes and generatedDigitsNumbers properties but with different generatedDigitsNumbers for prefixes await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { phoneNumber: funcs.phoneNumber({ // `prefixes` - array of any string you want to be your phone number prefixes.(not compatible with `template` property) prefixes: ["+380 99", "+380 67", "+1"], // `generatedDigitsNumbers` - number of digits that will be added at the end of prefixes.(not compatible with `template` property) generatedDigitsNumbers: [7, 7, 10], // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `country` Generates country's names | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { country: funcs.country({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: false, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `city` Generates city's names | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { city: funcs.city({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: false, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `streetAddress` Generates street address | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { streetAddress: funcs.streetAddress({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: false, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `jobTitle` Generates job titles | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { jobTitle: funcs.jobTitle({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `postcode` Generates postal codes | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { postcode: funcs.postcode({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: true, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `state` Generates US states | | param | default | type |:-| :-------- | :-------- | :-------- | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { state: funcs.state({ // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `companyName` Generates random company's names | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |-- |`boolean` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ users: { columns: { company: funcs.companyName({ // `isUnique` - property that controls whether the generated values will be unique or not isUnique: true, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `loremIpsum` Generates `lorem ipsum` text sentences. | | param | default | type |:-| :-------- | :-------- | :-------- | |`sentencesCount` | 1 |`number` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ posts: { columns: { content: funcs.loremIpsum({ // `sentencesCount` - number of sentences you want to generate as one generated value(string). sentencesCount: 2, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `point` Generates 2D points within specified ranges for x and y coordinates. | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |database column uniqueness |`boolean` | |`maxXValue` |``` `10 * 1000` if isUnique equals false``` ``` `10 * count` if isUnique equals true``` |`number` | |`minXValue` |`-maxXValue` |`number` | |`maxYValue` |``` `10 * 1000` if isUnique equals false``` ``` `10 * count` if isUnique equals true``` |`number` | |`minYValue` |`-maxYValue` |`number` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ triangles: { columns: { pointCoords: funcs.point({ // `isUnique` - property that controls if generated values gonna be unique or not. isUnique: true, // `minXValue` - lower bound of range for x coordinate. minXValue: -5, // `maxXValue` - upper bound of range for x coordinate. maxXValue: 20, // `minYValue` - lower bound of range for y coordinate. minYValue: 0, // `maxYValue` - upper bound of range for y coordinate. maxYValue: 30, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` ### `line` Generates 2D lines within specified ranges for a, b and c parameters of line. ``` line equation: a*x + b*y + c = 0 ``` | | param | default | type |:-| :-------- | :-------- | :-------- | |`isUnique` |database column uniqueness |`boolean` | |`maxAValue` |``` `10 * 1000` if isUnique equals false``` ``` `10 * count` if isUnique equals true``` |`number` | |`minAValue` |`-maxAValue` |`number` | |`maxBValue` |``` `10 * 1000` if isUnique equals false``` ``` `10 * count` if isUnique equals true``` |`number` | |`minBValue` |`-maxBValue` |`number` | |`maxCValue` |``` `10 * 1000` if isUnique equals false``` ``` `10 * count` if isUnique equals true``` |`number` | |`minCValue` |`-maxCValue` |`number` | |`arraySize` |-- |`number` ```ts import { seed } from "drizzle-seed"; await seed(db, schema, { count: 1000 }).refine((funcs) => ({ lines: { columns: { lineParams: funcs.point({ // `isUnique` - property that controls if generated values gonna be unique or not. isUnique: true, // `minAValue` - lower bound of range for a parameter. minAValue: -5, // `maxAValue` - upper bound of range for x parameter. maxAValue: 20, // `minBValue` - lower bound of range for y parameter. minBValue: 0, // `maxBValue` - upper bound of range for y parameter. maxBValue: 30, // `minCValue` - lower bound of range for y parameter. minCValue: 0, // `maxCValue` - upper bound of range for y parameter. maxCValue: 10, // number of elements in each one-dimensional array. // (If specified, arrays will be generated.) arraySize: 3 }), }, }, })); ``` Source: https://orm.drizzle.team/docs/seed-limitations // type limitations for third param Source: https://orm.drizzle.team/docs/seed-overview import Npm from "@mdx/Npm.astro"; import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from '@mdx/Callout.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from "@mdx/Section.astro"; import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; # Drizzle Seed `drizzle-seed` can only be used with `drizzle-orm@0.36.4` or higher. Versions lower than this may work at runtime but could have type issues and identity column issues, as this patch was introduced in `drizzle-orm@0.36.4` `drizzle-seed` is a TypeScript library that helps you generate deterministic, yet realistic, fake data to populate your database. By leveraging a seedable pseudorandom number generator (pRNG), it ensures that the data you generate is consistent and reproducible across different runs. This is especially useful for testing, development, and debugging purposes. #### What is Deterministic Data Generation? Deterministic data generation means that the same input will always produce the same output. In the context of `drizzle-seed`, when you initialize the library with the same seed number, it will generate the same sequence of fake data every time. This allows for predictable and repeatable data sets. #### Pseudorandom Number Generator (pRNG) A pseudorandom number generator is an algorithm that produces a sequence of numbers that approximates the properties of random numbers. However, because it's based on an initial value called a seed, you can control its randomness. By using the same seed, the pRNG will produce the same sequence of numbers, making your data generation process reproducible. #### Benefits of Using a pRNG: - Consistency: Ensures that your tests run on the same data every time. - Debugging: Makes it easier to reproduce and fix bugs by providing a consistent data set. - Collaboration: Team members can share seed numbers to work with the same data sets. With drizzle-seed, you get the best of both worlds: the ability to generate realistic fake data and the control to reproduce it whenever needed. ## Installation drizzle-seed ## Basic Usage In this example we will create 10 users with random names and ids ```ts {12} import { pgTable, integer, text } from "drizzle-orm/pg-core"; import { drizzle } from "drizzle-orm/node-postgres"; import { seed } from "drizzle-seed"; const users = pgTable("users", { id: integer().primaryKey(), name: text().notNull(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { users }); } main(); ``` ## Options **`count`** By default, the `seed` function will create 10 entities. However, if you need more for your tests, you can specify this in the seed options object ```ts await seed(db, schema, { count: 1000 }); ``` **`seed`** If you need a seed to generate a different set of values for all subsequent runs, you can define a different number in the `seed` option. Any new number will generate a unique set of values ```ts await seed(db, schema, { seed: 12345 }); ``` ## Reset database With `drizzle-seed`, you can easily reset your database and seed it with new values, for example, in your test suites ```ts // path to a file with schema you want to reset import * as schema from "./schema.ts"; import { reset } from "drizzle-seed"; async function main() { const db = drizzle(process.env.DATABASE_URL!); await reset(db, schema); } main(); ``` Different dialects will have different strategies for database resetting For PostgreSQL, the `drizzle-seed` package will generate `TRUNCATE` statements with the `CASCADE` option to ensure that all tables are empty after running the reset function ```sql TRUNCATE tableName1, tableName2, ... CASCADE; ``` For MySQL, the `drizzle-seed` package will first disable `FOREIGN_KEY_CHECKS` to ensure the next step won't fail, and then generate `TRUNCATE` statements to empty the content of all tables ```sql SET FOREIGN_KEY_CHECKS = 0; TRUNCATE tableName1; TRUNCATE tableName2; ... SET FOREIGN_KEY_CHECKS = 1; ``` For SQLite, the `drizzle-seed` package will first disable the `foreign_keys` pragma to ensure the next step won't fail, and then generate `DELETE FROM` statements to empty the content of all tables ```sql PRAGMA foreign_keys = OFF; DELETE FROM tableName1; DELETE FROM tableName2; ... PRAGMA foreign_keys = ON; ``` ## Refinements In case you need to change the behavior of the seed generator functions that `drizzle-seed` uses by default, you can specify your own implementation and even use your own list of values for the seeding process `.refine` is a callback that receives a list of all available generator functions from `drizzle-seed`. It should return an object with keys representing the tables you want to refine, defining their behavior as needed. Each table can specify several properties to simplify seeding your database: - `columns`: Refine the default behavior of each column by specifying the required generator function. - `count`: Specify the number of rows to insert into the database. By default, it's 10. If a global count is defined in the `seed()` options, the count defined here will override it for this specific table. - `with`: Define how many referenced entities to create for each parent table if you want to generate associated entities. You can also specify a weighted random distribution for the number of referenced values you want to create. For details on this API, you can refer to [Weighted Random docs](#weighted-random) docs section **API** ```ts await seed(db, schema).refine((f) => ({ users: { columns: {}, count: 10, with: { posts: 10 } }, })); ``` Let's check a few examples with an explanation of what will happen: ```ts filename='schema.ts' import { pgTable, integer, text } from "drizzle-orm/pg-core"; export const users = pgTable("users", { id: integer().primaryKey(), name: text().notNull(), }); export const posts = pgTable("posts", { id: integer().primaryKey(), description: text(), userId: integer().references(() => users.id), }); ``` **Example 1**: Seed only the `users` table with 20 entities and with refined seed logic for the `name` column ```ts filename='index.ts' import { drizzle } from "drizzle-orm/node-postgres"; import { seed } from "drizzle-seed"; import * as schema from './schema.ts' async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { users: schema.users }).refine((f) => ({ users: { columns: { name: f.fullName(), }, count: 20 } })); } main(); ``` **Example 2**: Seed the `users` table with 20 entities and add 10 `posts` for each `user` by seeding the `posts` table and creating a reference from `posts` to `users` ```ts filename='index.ts' import { drizzle } from "drizzle-orm/node-postgres"; import { seed } from "drizzle-seed"; import * as schema from './schema.ts' async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, schema).refine((f) => ({ users: { count: 20, with: { posts: 10 } } })); } main(); ``` **Example 3**: Seed the `users` table with 5 entities and populate the database with 100 `posts` without connecting them to the `users` entities. Refine `id` generation for `users` so that it will give any int from `10000` to `20000` and remains unique, and refine `posts` to retrieve values from a self-defined array ```ts filename='index.ts' import { drizzle } from "drizzle-orm/node-postgres"; import { seed } from "drizzle-seed"; import * as schema from './schema.ts' async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, schema).refine((f) => ({ users: { count: 5, columns: { id: f.int({ minValue: 10000, maxValue: 20000, isUnique: true, }), } }, posts: { count: 100, columns: { description: f.valuesFromArray({ values: [ "The sun set behind the mountains, painting the sky in hues of orange and purple", "I can't believe how good this homemade pizza turned out!", "Sometimes, all you need is a good book and a quiet corner.", "Who else thinks rainy days are perfect for binge-watching old movies?", "Tried a new hiking trail today and found the most amazing waterfall!", // ... ], }) } } })); } main(); ``` There are many more possibilities that we will define in these docs, but for now, you can explore a few sections in this documentation. Check the [Generators](#generators) section to get familiar with all the available generator functions you can use. A particularly great feature is the ability to use weighted randomization, both for generator values created for a column and for determining the number of related entities that can be generated by `drizzle-seed`. Please check [Weighted Random docs](#weighted-random) for more info. ## Weighted Random There may be cases where you need to use multiple datasets with a different priority that should be inserted into your database during the seed stage. For such cases, drizzle-seed provides an API called weighted random The Drizzle Seed package has a few places where weighted random can be used: - Columns inside each table refinements - The `with` property, determining the amount of related entities to be created Let's check an example for both: ```ts filename="schema.ts" import { pgTable, integer, text, varchar, doublePrecision } from "drizzle-orm/pg-core"; export const orders = pgTable( "orders", { id: integer().primaryKey(), name: text().notNull(), quantityPerUnit: varchar().notNull(), unitPrice: doublePrecision().notNull(), unitsInStock: integer().notNull(), unitsOnOrder: integer().notNull(), reorderLevel: integer().notNull(), discontinued: integer().notNull(), } ); export const details = pgTable( "details", { unitPrice: doublePrecision().notNull(), quantity: integer().notNull(), discount: doublePrecision().notNull(), orderId: integer() .notNull() .references(() => orders.id, { onDelete: "cascade" }), } ); ``` **Example 1**: Refine the `unitPrice` generation logic to generate `5000` random prices, with a 30% chance of prices between 10-100 and a 70% chance of prices between 100-300 ```ts filename="index.ts" import { drizzle } from "drizzle-orm/node-postgres"; import { seed } from "drizzle-seed"; import * as schema from './schema.ts' async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, schema).refine((f) => ({ orders: { count: 5000, columns: { unitPrice: f.weightedRandom( [ { weight: 0.3, value: funcs.int({ minValue: 10, maxValue: 100 }) }, { weight: 0.7, value: funcs.number({ minValue: 100, maxValue: 300, precision: 100 }) } ] ), } } })); } main(); ``` **Example 2**: For each order, generate 1 to 3 details with a 60% chance, 5 to 7 details with a 30% chance, and 8 to 10 details with a 10% chance ```ts filename="index.ts" import { drizzle } from "drizzle-orm/node-postgres"; import { seed } from "drizzle-seed"; import * as schema from './schema.ts' async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, schema).refine((f) => ({ orders: { with: { details: [ { weight: 0.6, count: [1, 2, 3] }, { weight: 0.3, count: [5, 6, 7] }, { weight: 0.1, count: [8, 9, 10] }, ] } } })); } main(); ``` ## Complex example
```ts import { seed } from "drizzle-seed"; import * as schema from "./schema.ts"; const main = async () => { const titlesOfCourtesy = ["Ms.", "Mrs.", "Dr."]; const unitsOnOrders = [0, 10, 20, 30, 50, 60, 70, 80, 100]; const reorderLevels = [0, 5, 10, 15, 20, 25, 30]; const quantityPerUnit = [ "100 - 100 g pieces", "100 - 250 g bags", "10 - 200 g glasses", "10 - 4 oz boxes", "10 - 500 g pkgs.", "10 - 500 g pkgs." ]; const discounts = [0.05, 0.15, 0.2, 0.25]; await seed(db, schema).refine((funcs) => ({ customers: { count: 10000, columns: { companyName: funcs.companyName(), contactName: funcs.fullName(), contactTitle: funcs.jobTitle(), address: funcs.streetAddress(), city: funcs.city(), postalCode: funcs.postcode(), region: funcs.state(), country: funcs.country(), phone: funcs.phoneNumber({ template: "(###) ###-####" }), fax: funcs.phoneNumber({ template: "(###) ###-####" }) } }, employees: { count: 200, columns: { firstName: funcs.firstName(), lastName: funcs.lastName(), title: funcs.jobTitle(), titleOfCourtesy: funcs.valuesFromArray({ values: titlesOfCourtesy }), birthDate: funcs.date({ minDate: "2010-12-31", maxDate: "2010-12-31" }), hireDate: funcs.date({ minDate: "2010-12-31", maxDate: "2024-08-26" }), address: funcs.streetAddress(), city: funcs.city(), postalCode: funcs.postcode(), country: funcs.country(), homePhone: funcs.phoneNumber({ template: "(###) ###-####" }), extension: funcs.int({ minValue: 428, maxValue: 5467 }), notes: funcs.loremIpsum() } }, orders: { count: 50000, columns: { shipVia: funcs.int({ minValue: 1, maxValue: 3 }), freight: funcs.number({ minValue: 0, maxValue: 1000, precision: 100 }), shipName: funcs.streetAddress(), shipCity: funcs.city(), shipRegion: funcs.state(), shipPostalCode: funcs.postcode(), shipCountry: funcs.country() }, with: { details: [ { weight: 0.6, count: [1, 2, 3, 4] }, { weight: 0.2, count: [5, 6, 7, 8, 9, 10] }, { weight: 0.15, count: [11, 12, 13, 14, 15, 16, 17] }, { weight: 0.05, count: [18, 19, 20, 21, 22, 23, 24, 25] }, ] } }, suppliers: { count: 1000, columns: { companyName: funcs.companyName(), contactName: funcs.fullName(), contactTitle: funcs.jobTitle(), address: funcs.streetAddress(), city: funcs.city(), postalCode: funcs.postcode(), region: funcs.state(), country: funcs.country(), phone: funcs.phoneNumber({ template: "(###) ###-####" }) } }, products: { count: 5000, columns: { name: funcs.companyName(), quantityPerUnit: funcs.valuesFromArray({ values: quantityPerUnit }), unitPrice: funcs.weightedRandom( [ { weight: 0.5, value: funcs.int({ minValue: 3, maxValue: 300 }) }, { weight: 0.5, value: funcs.number({ minValue: 3, maxValue: 300, precision: 100 }) } ] ), unitsInStock: funcs.int({ minValue: 0, maxValue: 125 }), unitsOnOrder: funcs.valuesFromArray({ values: unitsOnOrders }), reorderLevel: funcs.valuesFromArray({ values: reorderLevels }), discontinued: funcs.int({ minValue: 0, maxValue: 1 }) } }, details: { columns: { unitPrice: funcs.number({ minValue: 10, maxValue: 130 }), quantity: funcs.int({ minValue: 1, maxValue: 130 }), discount: funcs.weightedRandom( [ { weight: 0.5, value: funcs.valuesFromArray({ values: discounts }) }, { weight: 0.5, value: funcs.default({ defaultValue: 0 }) } ] ) } } })); } main(); ```
```ts import type { AnyPgColumn } from "drizzle-orm/pg-core"; import { integer, numeric, pgTable, text, timestamp, varchar } from "drizzle-orm/pg-core"; export const customers = pgTable('customer', { id: varchar({ length: 256 }).primaryKey(), companyName: text().notNull(), contactName: text().notNull(), contactTitle: text().notNull(), address: text().notNull(), city: text().notNull(), postalCode: text(), region: text(), country: text().notNull(), phone: text().notNull(), fax: text(), }); export const employees = pgTable( 'employee', { id: integer().primaryKey(), lastName: text().notNull(), firstName: text(), title: text().notNull(), titleOfCourtesy: text().notNull(), birthDate: timestamp().notNull(), hireDate: timestamp().notNull(), address: text().notNull(), city: text().notNull(), postalCode: text().notNull(), country: text().notNull(), homePhone: text().notNull(), extension: integer().notNull(), notes: text().notNull(), reportsTo: integer().references((): AnyPgColumn => employees.id), photoPath: text(), }, ); export const orders = pgTable('order', { id: integer().primaryKey(), orderDate: timestamp().notNull(), requiredDate: timestamp().notNull(), shippedDate: timestamp(), shipVia: integer().notNull(), freight: numeric().notNull(), shipName: text().notNull(), shipCity: text().notNull(), shipRegion: text(), shipPostalCode: text(), shipCountry: text().notNull(), customerId: text().notNull().references(() => customers.id, { onDelete: 'cascade' }), employeeId: integer().notNull().references(() => employees.id, { onDelete: 'cascade' }), }); export const suppliers = pgTable('supplier', { id: integer().primaryKey(), companyName: text().notNull(), contactName: text().notNull(), contactTitle: text().notNull(), address: text().notNull(), city: text().notNull(), region: text(), postalCode: text().notNull(), country: text().notNull(), phone: text().notNull(), }); export const products = pgTable('product', { id: integer().primaryKey(), name: text().notNull(), quantityPerUnit: text().notNull(), unitPrice: numeric().notNull(), unitsInStock: integer().notNull(), unitsOnOrder: integer().notNull(), reorderLevel: integer().notNull(), discontinued: integer().notNull(), supplierId: integer().notNull().references(() => suppliers.id, { onDelete: 'cascade' }), }); export const details = pgTable('order_detail', { unitPrice: numeric().notNull(), quantity: integer().notNull(), discount: numeric().notNull(), orderId: integer().notNull().references(() => orders.id, { onDelete: 'cascade' }), productId: integer().notNull().references(() => products.id, { onDelete: 'cascade' }), }); ```
## Limitations #### Types limitations for `with` Due to certain TypeScript limitations and the current API in Drizzle, it is not possible to properly infer references between tables, especially when circular dependencies between tables exist. This means the `with` option will display all tables in the schema, and you will need to manually select the one that has a one-to-many relationship The `with` option works for one-to-many relationships. For example, if you have one `user` and many `posts`, you can use users `with` posts, but you cannot use posts `with` users #### Type limitations for the third parameter in Drizzle tables: Currently, we do not have type support for the third parameter in Drizzle tables. While it will work at runtime, it will not function correctly at the type level Source: https://orm.drizzle.team/docs/seed-versioning import Tab from "@mdx/Tab.astro"; import Tabs from "@mdx/Tabs.astro"; import Callout from "@mdx/Callout.astro"; import TableWrapper from "@mdx/TableWrapper.astro"; # Versioning `drizzle-seed` uses versioning to manage outputs for static and dynamic data. To ensure true determinism, ensure that values remain unchanged when using the same `seed` number. If changes are made to static data sources or dynamic data generation logic, the version will be updated, allowing you to choose between sticking with the previous version or using the latest. You can upgrade to the latest `drizzle-seed` version for new features, such as additional generators, while maintaining deterministic outputs with a previous version if needed. This is particularly useful when you need to rely on existing deterministic data while accessing new functionality. ```ts await seed(db, schema, { version: '2' }); ``` ## History | api version | npm version | Changed generators | | :-------------- | :-------------- | :------------- | | `v1` | `0.1.1` | | | `v2 (LTS) ` | `0.2.1` |`string()`, `interval({ isUnique: true })` | > This is not an actual API change; it is just an example of how we will proceed with `drizzle-seed` versioning. For example, `lastName` generator was changed, and new version, `V2`, of this generator became available. Later, `firstName` generator was changed, making `V3` version of this generator available. | | `V1` | `V2` | `V3(latest)` | | :--------------: | :--------------: | :-------------: | :--------------: | | **LastNameGen** | `LastNameGenV1` | `LastNameGenV2` | | | **FirstNameGen** | `FirstNameGenV1` | | `FirstNameGenV3` | ##### Use the `firstName` generator of version 3 and the `lastName` generator of version 2 ```ts await seed(db, schema); ``` If you are not ready to use latest generator version right away, you can specify max version to use ##### Use the `firstName` generator of version 1 and the `lastName` generator of version 2 ```ts await seed(db, schema, { version: '2' }); ``` ##### Use the `firstName` generator of version 1 and the `lastName` generator of version 1. ```ts await seed(db, schema, { version: '1' }); ``` ## Version 2 #### Unique `interval` generator was changed An older version of the generator could produce intervals like `1 minute 60 seconds` and `2 minutes 0 seconds`, treating them as distinct intervals. However, when the `1 minute 60 seconds` interval is inserted into a PostgreSQL database, it is automatically converted to `2 minutes 0 seconds`. As a result, attempting to insert the `2 minutes 0 seconds` interval into a unique column afterwards will cause an error You will be affected, if your table includes a unique column of type `interval`: ```ts import { drizzle } from "drizzle-orm/node-postgres"; import { pgTable, interval } from "drizzle-orm/pg-core"; import { seed } from "drizzle-seed"; const intervals = pgTable("intervals", { interval: interval().unique() }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { intervals }); } main(); ``` You will be affected, if you use the unique `interval` generator in your seeding script, as shown in the script below: ```ts import { drizzle } from "drizzle-orm/node-postgres"; import { pgTable, interval, char, varchar, text } from "drizzle-orm/pg-core"; import { seed } from "drizzle-seed"; const intervals = pgTable("intervals", { interval: interval().unique(), interval1: interval(), interval2: char({ length: 256 }).unique(), interval3: char({ length: 256 }), interval4: varchar().unique(), interval5: varchar(), interval6: text().unique(), interval7: text(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { intervals }).refine((f) => ({ intervals: { columns: { interval: f.interval({ isUnique: true }), interval1: f.interval({ isUnique: true }), interval2: f.interval({ isUnique: true }), interval3: f.interval({ isUnique: true }), interval4: f.interval({ isUnique: true }), interval5: f.interval({ isUnique: true }), interval6: f.interval({ isUnique: true }), interval7: f.interval({ isUnique: true }), } } })); } main(); ``` ```ts import { binary, char, mysqlTable, text, varbinary, varchar } from 'drizzle-orm/mysql-core'; import { drizzle } from 'drizzle-orm/mysql2'; import { seed } from "drizzle-seed"; const intervals = mysqlTable('intervals', { interval1: char({ length: 255 }).unique(), interval2: char({ length: 255 }), interval3: varchar({ length: 255 }).unique(), interval4: varchar({ length: 255 }), interval5: binary({ length: 255 }).unique(), interval6: binary({ length: 255 }), interval7: varbinary({ length: 255 }).unique(), interval8: varbinary({ length: 255 }), interval9: text(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { intervals }, { version: '2' }).refine((f) => ({ intervals: { columns: { interval: f.interval({ isUnique: true }), interval1: f.interval({ isUnique: true }), interval2: f.interval({ isUnique: true }), interval3: f.interval({ isUnique: true }), interval4: f.interval({ isUnique: true }), interval5: f.interval({ isUnique: true }), interval6: f.interval({ isUnique: true }), interval7: f.interval({ isUnique: true }), interval8: f.interval({ isUnique: true }), interval9: f.interval({ isUnique: true }), }, }, })); } main(); ``` ```ts import { blob, sqliteTable, text } from 'drizzle-orm/sqlite-core'; import { drizzle } from 'drizzle-orm/better-sqlite3'; import { seed } from 'drizzle-seed'; const intervals = sqliteTable('intervals', { interval1: text().unique(), interval2: text(), interval3: blob().unique(), interval4: blob(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { intervals }).refine((f) => ({ intervals: { columns: { interval1: f.interval({ isUnique: true }), interval2: f.interval({ isUnique: true }), interval3: f.interval({ isUnique: true }), interval4: f.interval({ isUnique: true }), }, }, })); } main(); ``` #### `string` generators were changed: both non-unique and unique Ability to generate a unique string based on the length of the text column (e.g., `varchar(20)`) You will be affected, if your table includes a column of a text-like type with a maximum length parameter or a unique column of a text-like type: ```ts import { drizzle } from "drizzle-orm/node-postgres"; import { pgTable, char, varchar, text } from "drizzle-orm/pg-core"; import { seed } from "drizzle-seed"; const strings = pgTable("strings", { string2: char({ length: 256 }).unique(), string3: char({ length: 256 }), string4: varchar().unique(), string5: varchar({ length: 256 }).unique(), string6: varchar({ length: 256 }), string7: text().unique(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { strings }); } main(); ``` ```ts import { binary, char, mysqlTable, varbinary, varchar } from 'drizzle-orm/mysql-core'; import { drizzle } from 'drizzle-orm/mysql2'; import { seed } from "drizzle-seed"; const strings = mysqlTable('strings', { string1: char({ length: 255 }).unique(), string2: char({ length: 255 }), string3: varchar({ length: 255 }).unique(), string4: varchar({ length: 255 }), string5: binary({ length: 255 }).unique(), string6: binary({ length: 255 }), string7: varbinary({ length: 255 }).unique(), string8: varbinary({ length: 255 }), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { strings }); } main(); ``` ```ts import { drizzle } from 'drizzle-orm/better-sqlite3'; import { blob, sqliteTable, text } from 'drizzle-orm/sqlite-core'; import { seed } from "drizzle-seed"; const strings = sqliteTable('strings', { string1: text().unique(), string2: text({ length: 256 }), string3: text({ length: 256 }).unique(), string4: blob().unique(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { strings }); } main(); ``` You will be affected, if you use the `string` generator in your seeding script, as shown in the script below: ```ts import { drizzle } from "drizzle-orm/node-postgres"; import { pgTable, char, varchar, text } from "drizzle-orm/pg-core"; import { seed } from "drizzle-seed"; const strings = pgTable("strings", { string1: char({ length: 256 }).unique(), string2: char({ length: 256 }), string3: char({ length: 256 }), string4: varchar(), string5: varchar().unique(), string6: varchar({ length: 256 }).unique(), string7: varchar({ length: 256 }), string8: varchar({ length: 256 }), string9: text().unique(), string10: text(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { strings }).refine((f) => ({ strings: { columns: { string1: f.string({ isUnique: true }), string2: f.string(), string3: f.string({ isUnique: true }), string4: f.string({ isUnique: true }), string5: f.string({ isUnique: true }), string6: f.string({ isUnique: true }), string7: f.string(), string8: f.string({ isUnique: true }), string9: f.string({ isUnique: true }), string10: f.string({ isUnique: true }), } } })); } main(); ``` ```ts import { binary, char, mysqlTable, text, varbinary, varchar } from 'drizzle-orm/mysql-core'; import { drizzle } from 'drizzle-orm/mysql2'; import { seed } from "drizzle-seed"; const strings = mysqlTable('strings', { string1: char({ length: 255 }).unique(), string2: char({ length: 255 }), string3: char({ length: 255 }), string4: varchar({ length: 255 }).unique(), string5: varchar({ length: 255 }), string6: varchar({ length: 255 }), string7: binary({ length: 255 }).unique(), string8: binary({ length: 255 }), string9: binary({ length: 255 }), string10: varbinary({ length: 255 }).unique(), string11: varbinary({ length: 255 }), string12: varbinary({ length: 255 }), string13: text(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { strings }).refine((f) => ({ strings: { columns: { string1: f.string({ isUnique: true }), string2: f.string({ isUnique: true }), string3: f.string(), string4: f.string({ isUnique: true }), string5: f.string({ isUnique: true }), string6: f.string(), string7: f.string({ isUnique: true }), string8: f.string({ isUnique: true }), string9: f.string(), string10: f.string({ isUnique: true }), string11: f.string({ isUnique: true }), string12: f.string(), string13: f.string({ isUnique: true }), }, }, })); } main(); ``` ```ts import { blob, sqliteTable, text } from 'drizzle-orm/sqlite-core'; import { drizzle } from 'drizzle-orm/better-sqlite3'; import { seed } from "drizzle-seed"; const strings = sqliteTable("strings", { string1: text().unique(), string2: text(), string3: text({ length: 256 }).unique(), string4: text({ length: 256 }), string5: text({ length: 256 }), string6: blob().unique(), string7: blob(), }); async function main() { const db = drizzle(process.env.DATABASE_URL!); await seed(db, { strings }).refine((f) => ({ strings: { columns: { string1: f.string({ isUnique: true }), string2: f.string({ isUnique: true }), string3: f.string({ isUnique: true }), string4: f.string({ isUnique: true }), string5: f.string(), string6: f.string({ isUnique: true }), string7: f.string({ isUnique: true }), }, }, })); } main(); ``` Source: https://orm.drizzle.team/docs/select import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import $count from '@mdx/$count.mdx'; # SQL Select Drizzle provides you the most SQL-like way to fetch data from your database, while remaining type-safe and composable. It natively supports mostly every query feature and capability of every dialect, and whatever it doesn't support yet, can be added by the user with the powerful [`sql`](/docs/sql) operator. For the following examples, let's assume you have a `users` table defined like this: ```typescript import { pgTable, serial, text } from 'drizzle-orm/pg-core'; export const users = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age'), }); ``` ```typescript import { mysqlTable, serial, text, int } from 'drizzle-orm/mysql-core'; export const users = mysqlTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), age: int('age'), }); ``` ```typescript import { sqliteTable, integer, text } from 'drizzle-orm/sqlite-core'; export const users = sqliteTable('users', { id: integer('id').primaryKey(), name: text('name').notNull(), age: integer('age'), }); ``` ```typescript import { singlestoreTable, serial, text, int } from 'drizzle-orm/singlestore-core'; export const users = singlestoreTable('users', { id: int('id').primaryKey(), name: text('name').notNull(), age: int('age'), }); ``` ### Basic select Select all rows from a table including all columns:
```typescript const result = await db.select().from(users); /* { id: number; name: string; age: number | null; }[] */ ``` ```sql select "id", "name", "age" from "users"; ```
Notice that the result type is inferred automatically based on the table definition, including columns nullability. Drizzle always explicitly lists columns in the `select` clause instead of using `select *`.
This is required internally to guarantee the fields order in the query result, and is also generally considered a good practice.
### Partial select In some cases, you might want to select only a subset of columns from a table. You can do that by providing a selection object to the `.select()` method:
```typescript copy const result = await db.select({ field1: users.id, field2: users.name, }).from(users); const { field1, field2 } = result[0]; ``` ```sql select "id", "name" from "users"; ```
Like in SQL, you can use arbitrary expressions as selection fields, not just table columns:
```typescript const result = await db.select({ id: users.id, lowerName: sql`lower(${users.name})`, }).from(users); ``` ```sql select "id", lower("name") from "users"; ```
By specifying `sql`, you are telling Drizzle that the **expected** type of the field is `string`.
If you specify it incorrectly (e.g. use `sql` for a field that will be returned as a string), the runtime value won't match the expected type. Drizzle cannot perform any type casts based on the provided type generic, because that information is not available at runtime. If you need to apply runtime transformations to the returned value, you can use the [`.mapWith()`](/docs/sql#sqlmapwith) method.
### Conditional select You can have a dynamic selection object based on some condition: ```typescript async function selectUsers(withName: boolean) { return db .select({ id: users.id, ...(withName ? { name: users.name } : {}), }) .from(users); } const users = await selectUsers(true); ``` ### Distinct select You can use `.selectDistinct()` instead of `.select()` to retrieve only unique rows from a dataset:
```ts await db.selectDistinct().from(users).orderBy(usersTable.id, usersTable.name); await db.selectDistinct({ id: users.id }).from(users).orderBy(usersTable.id); ``` ```sql select distinct "id", "name" from "users" order by "id", "name"; select distinct "id" from "users" order by "id"; ```
In PostgreSQL, you can also use the `distinct on` clause to specify how the unique rows are determined: `distinct on` clause is only supported in PostgreSQL.
```ts await db.selectDistinctOn([users.id]).from(users).orderBy(users.id); await db.selectDistinctOn([users.name], { name: users.name }).from(users).orderBy(users.name); ``` ```sql select distinct on ("id") "id", "name" from "users" order by "id"; select distinct on ("name") "name" from "users" order by "name"; ```
### Advanced select Powered by TypeScript, Drizzle APIs let you build your select queries in a variety of flexible ways. Sneak peek of advanced partial select, for more detailed advaced usage examples - see our [dedicated guide](/docs/guides/include-or-exclude-columns). ```ts import { getTableColumns, sql } from 'drizzle-orm'; await db.select({ ...getTableColumns(posts), titleLength: sql`length(${posts.title})`, }).from(posts); ``` ```ts import { getTableColumns } from 'drizzle-orm'; const { content, ...rest } = getTableColumns(posts); // exclude "content" column await db.select({ ...rest }).from(posts); // select all other columns ``` ```ts await db.query.posts.findMany({ columns: { title: true, }, }); ``` ```ts await db.query.posts.findMany({ columns: { content: false, }, }); ``` ## --- ### Filters You can filter the query results using the [filter operators](/docs/operators) in the `.where()` method:
```typescript copy import { eq, lt, gte, ne } from 'drizzle-orm'; await db.select().from(users).where(eq(users.id, 42)); await db.select().from(users).where(lt(users.id, 42)); await db.select().from(users).where(gte(users.id, 42)); await db.select().from(users).where(ne(users.id, 42)); ... ``` ```sql select "id", "name", "age" from "users" where "id" = 42; select "id", "name", "age" from "users" where "id" < 42; select "id", "name", "age" from "users" where "id" >= 42; select "id", "name", "age" from "users" where "id" <> 42; ```
All filter operators are implemented using the [`sql`](/docs/sql) function. You can use it yourself to write arbitrary SQL filters, or build your own operators. For inspiration, you can check how the operators provided by Drizzle are [implemented](https://github.com/drizzle-team/drizzle-orm/blob/main/drizzle-orm/src/sql/expressions/conditions.ts).
```typescript copy import { sql } from 'drizzle-orm'; function equals42(col: Column) { return sql`${col} = 42`; } await db.select().from(users).where(sql`${users.id} < 42`); await db.select().from(users).where(sql`${users.id} = 42`); await db.select().from(users).where(equals42(users.id)); await db.select().from(users).where(sql`${users.id} >= 42`); await db.select().from(users).where(sql`${users.id} <> 42`); await db.select().from(users).where(sql`lower(${users.name}) = 'aaron'`); ``` ```sql select "id", "name", "age" from "users" where 'id' < 42; select "id", "name", "age" from "users" where 'id' = 42; select "id", "name", "age" from "users" where 'id' = 42; select "id", "name", "age" from "users" where 'id' >= 42; select "id", "name", "age" from "users" where 'id' <> 42; select "id", "name", "age" from "users" where lower("name") = 'aaron'; ```
All the values provided to filter operators and to the `sql` function are parameterized automatically. For example, this query: ```ts await db.select().from(users).where(eq(users.id, 42)); ``` will be translated to: ```sql select "id", "name", "age" from "users" where "id" = $1; -- params: [42] ``` Inverting condition with a `not` operator:
```typescript copy import { eq, not, sql } from 'drizzle-orm'; await db.select().from(users).where(not(eq(users.id, 42))); await db.select().from(users).where(sql`not ${users.id} = 42`); ``` ```sql select "id", "name", "age" from "users" where not ("id" = 42); select "id", "name", "age" from "users" where not ("id" = 42); ```
You can safely alter schema, rename tables and columns and it will be automatically reflected in your queries because of template interpolation, as opposed to hardcoding column or table names when writing raw SQL. ### Combining filters You can logically combine filter operators with `and()` and `or()` operators:
```typescript copy import { eq, and, sql } from 'drizzle-orm'; await db.select().from(users).where( and( eq(users.id, 42), eq(users.name, 'Dan') ) ); await db.select().from(users).where(sql`${users.id} = 42 and ${users.name} = 'Dan'`); ``` ```sql select "id", "name", "age" from "users" where "id" = 42 and "name" = 'Dan'; select "id", "name", "age" from "users" where "id" = 42 and "name" = 'Dan'; ```
```typescript copy import { eq, or, sql } from 'drizzle-orm'; await db.select().from(users).where( or( eq(users.id, 42), eq(users.name, 'Dan') ) ); await db.select().from(users).where(sql`${users.id} = 42 or ${users.name} = 'Dan'`); ``` ```sql select "id", "name", "age" from "users" where "id" = 42 or "name" = 'Dan'; select "id", "name", "age" from "users" where "id" = 42 or "name" = 'Dan'; ```
### Advanced filters In combination with TypeScript, Drizzle APIs provide you powerful and flexible ways to combine filters in queries. Sneak peek of conditional filtering, for more detailed advaced usage examples - see our [dedicated guide](/docs/guides/conditional-filters-in-query). ```ts const searchPosts = async (term?: string) => { await db .select() .from(posts) .where(term ? ilike(posts.title, term) : undefined); }; await searchPosts(); await searchPosts('AI'); ``` ```ts const searchPosts = async (filters: SQL[]) => { await db .select() .from(posts) .where(and(...filters)); }; const filters: SQL[] = []; filters.push(ilike(posts.title, 'AI')); filters.push(inArray(posts.category, ['Tech', 'Art', 'Science'])); filters.push(gt(posts.views, 200)); await searchPosts(filters); ``` ## --- ### Limit & offset Use `.limit()` and `.offset()` to add `limit` and `offset` clauses to the query - for example, to implement pagination:
```typescript await db.select().from(users).limit(10); await db.select().from(users).limit(10).offset(10); ``` ```sql select "id", "name", "age" from "users" limit 10; select "id", "name", "age" from "users" limit 10 offset 10; ```
### Order By Use `.orderBy()` to add `order by` clause to the query, sorting the results by the specified fields:
```typescript import { asc, desc } from 'drizzle-orm'; await db.select().from(users).orderBy(users.name); await db.select().from(users).orderBy(desc(users.name)); // order by multiple fields await db.select().from(users).orderBy(users.name, users.name2); await db.select().from(users).orderBy(asc(users.name), desc(users.name2)); ``` ```sql select "id", "name", "age" from "users" order by "name"; select "id", "name", "age" from "users" order by "name" desc; select "id", "name", "age" from "users" order by "name", "name2"; select "id", "name", "age" from "users" order by "name" asc, "name2" desc; ```
### Advanced pagination Powered by TypeScript, Drizzle APIs let you implement all possible SQL paginations and sorting approaches. Sneak peek of advanced pagination, for more detailed advaced usage examples - see our dedicated [limit offset pagination](/docs/guides/limit-offset-pagination) and [cursor pagination](/docs/guides/cursor-based-pagination) guides. ```ts await db .select() .from(users) .orderBy(asc(users.id)) // order by is mandatory .limit(4) // the number of rows to return .offset(4); // the number of rows to skip ``` ```ts const getUsers = async (page = 1, pageSize = 3) => { await db.query.users.findMany({ orderBy: (users, { asc }) => asc(users.id), limit: pageSize, offset: (page - 1) * pageSize, }); }; await getUsers(); ``` ```ts const getUsers = async (page = 1, pageSize = 10) => { const sq = db .select({ id: users.id }) .from(users) .orderBy(users.id) .limit(pageSize) .offset((page - 1) * pageSize) .as('subquery'); await db.select().from(users).innerJoin(sq, eq(users.id, sq.id)).orderBy(users.id); }; ``` ```ts const nextUserPage = async (cursor?: number, pageSize = 3) => { await db .select() .from(users) .where(cursor ? gt(users.id, cursor) : undefined) // if cursor is provided, get rows after it .limit(pageSize) // the number of rows to return .orderBy(asc(users.id)); // ordering }; // pass the cursor of the last row of the previous page (id) await nextUserPage(3); ``` ## --- ### WITH clause Check how to use WITH statement with [insert](/docs/insert#with-insert-clause), [update](/docs/update#with-update-clause), [delete](/docs/delete#with-delete-clause) Using the `with` clause can help you simplify complex queries by splitting them into smaller subqueries called common table expressions (CTEs):
```typescript copy const sq = db.$with('sq').as(db.select().from(users).where(eq(users.id, 42))); const result = await db.with(sq).select().from(sq); ``` ```sql with sq as (select "id", "name", "age" from "users" where "id" = 42) select "id", "name", "age" from sq; ```
You can also provide `insert`, `update` and `delete` statements inside `with`
```typescript copy const sq = db.$with('sq').as( db.insert(users).values({ name: 'John' }).returning(), ); const result = await db.with(sq).select().from(sq); ``` ```sql with "sq" as (insert into "users" ("id", "name") values (default, 'John') returning "id", "name") select "id", "name" from "sq" ```
```typescript copy const sq = db.$with('sq').as( db.update(users).set({ age: 25 }).where(eq(users.name, 'John')).returning(), ); const result = await db.with(sq).select().from(sq); ``` ```sql with "sq" as (update "users" set "age" = 25 where "users"."name" = 'John' returning "id", "name", "age") select "id", "name", "age" from "sq" ```
```typescript copy const sq = db.$with('sq').as( db.delete(users).where(eq(users.name, 'John')).returning(), ); const result = await db.with(sq).select().from(sq); ``` ```sql with "sq" as (delete from "users" where "users"."name" = $1 returning "id", "name", "age") select "id", "name", "age" from "sq" ```
To select arbitrary SQL values as fields in a CTE and reference them in other CTEs or in the main query, you need to add aliases to them: ```typescript copy const sq = db.$with('sq').as(db.select({ name: sql`upper(${users.name})`.as('name'), }) .from(users)); const result = await db.with(sq).select({ name: sq.name }).from(sq); ``` If you don't provide an alias, the field type will become `DrizzleTypeError` and you won't be able to reference it in other queries. If you ignore the type error and still try to use the field, you will get a runtime error, since there's no way to reference that field without an alias. ### Select from subquery Just like in SQL, you can embed queries into other queries by using the subquery API:
```typescript copy const sq = db.select().from(users).where(eq(users.id, 42)).as('sq'); const result = await db.select().from(sq); ``` ```sql select "id", "name", "age" from (select "id", "name", "age" from "users" where "id" = 42) "sq"; ```
Subqueries can be used in any place where a table can be used, for example in joins:
```typescript copy const sq = db.select().from(users).where(eq(users.id, 42)).as('sq'); const result = await db.select().from(users).leftJoin(sq, eq(users.id, sq.id)); ``` ```sql select "users"."id", "users"."name", "users"."age", "sq"."id", "sq"."name", "sq"."age" from "users" left join (select "id", "name", "age" from "users" where "id" = 42) "sq" on "users"."id" = "sq"."id"; ```
## --- ### Aggregations With Drizzle, you can do aggregations using functions like `sum`, `count`, `avg`, etc. by grouping and filtering with `.groupBy()` and `.having()` respectfully, same as you would do in raw SQL:
```typescript import { gt } from 'drizzle-orm'; await db.select({ age: users.age, count: sql`cast(count(${users.id}) as int)`, }) .from(users) .groupBy(users.age); await db.select({ age: users.age, count: sql`cast(count(${users.id}) as int)`, }) .from(users) .groupBy(users.age) .having(({ count }) => gt(count, 1)); ``` ```sql select "age", cast(count("id") as int) from "users" group by "age"; select "age", cast(count("id") as int) from "users" group by "age" having cast(count("id") as int) > 1; ```
`cast(... as int)` is necessary because `count()` returns `bigint` in PostgreSQL and `decimal` in MySQL, which are treated as string values instead of numbers. Alternatively, you can use [`.mapWith(Number)`](/docs/sql#sqlmapwith) to cast the value to a number at runtime. If you need count aggregation - we recommend using our [`$count`](/docs/select#count) API ### Aggregations helpers Drizzle has a set of wrapped `sql` functions, so you don't need to write `sql` templates for common cases in your app Remember, aggregation functions are often used with the GROUP BY clause of the SELECT statement. So if you are selecting using aggregating functions and other columns in one query, be sure to use the `.groupBy` clause **count** Returns the number of values in `expression`.
```ts import { count } from 'drizzle-orm' await db.select({ value: count() }).from(users); await db.select({ value: count(users.id) }).from(users); ``` ```sql select count("*") from "users"; select count("id") from "users"; ``` ```ts // It's equivalent to writing await db.select({ value: sql`count('*'))`.mapWith(Number) }).from(users); await db.select({ value: sql`count(${users.id})`.mapWith(Number) }).from(users); ```
**countDistinct** Returns the number of non-duplicate values in `expression`.
```ts import { countDistinct } from 'drizzle-orm' await db.select({ value: countDistinct(users.id) }).from(users); ``` ```sql select count(distinct "id") from "users"; ``` ```ts // It's equivalent to writing await db.select({ value: sql`count(${users.id})`.mapWith(Number) }).from(users); ```
**avg** Returns the average (arithmetic mean) of all non-null values in `expression`.
```ts import { avg } from 'drizzle-orm' await db.select({ value: avg(users.id) }).from(users); ``` ```sql select avg("id") from "users"; ``` ```ts // It's equivalent to writing await db.select({ value: sql`avg(${users.id})`.mapWith(String) }).from(users); ```
**avgDistinct** Returns the average (arithmetic mean) of all non-null values in `expression`.
```ts import { avgDistinct } from 'drizzle-orm' await db.select({ value: avgDistinct(users.id) }).from(users); ``` ```sql select avg(distinct "id") from "users"; ``` ```ts // It's equivalent to writing await db.select({ value: sql`avg(distinct ${users.id})`.mapWith(String) }).from(users); ```
**sum** Returns the sum of all non-null values in `expression`.
```ts import { sum } from 'drizzle-orm' await db.select({ value: sum(users.id) }).from(users); ``` ```sql select sum("id") from "users"; ``` ```ts // It's equivalent to writing await db.select({ value: sql`sum(${users.id})`.mapWith(String) }).from(users); ```
**sumDistinct** Returns the sum of all non-null and non-duplicate values in `expression`.
```ts import { sumDistinct } from 'drizzle-orm' await db.select({ value: sumDistinct(users.id) }).from(users); ``` ```sql select sum(distinct "id") from "users"; ``` ```ts // It's equivalent to writing await db.select({ value: sql`sum(distinct ${users.id})`.mapWith(String) }).from(users); ```
**max** Returns the maximum value in `expression`.
```ts import { max } from 'drizzle-orm' await db.select({ value: max(users.id) }).from(users); ``` ```sql select max("id") from "users"; ``` ```ts // It's equivalent to writing await db.select({ value: sql`max(${expression})`.mapWith(users.id) }).from(users); ```
**min** Returns the minimum value in `expression`.
```ts import { min } from 'drizzle-orm' await db.select({ value: min(users.id) }).from(users); ``` ```sql select min("id") from "users"; ``` ```ts // It's equivalent to writing await db.select({ value: sql`min(${users.id})`.mapWith(users.id) }).from(users); ```
A more advanced example: ```typescript copy const orders = sqliteTable('order', { id: integer('id').primaryKey(), orderDate: integer('order_date', { mode: 'timestamp' }).notNull(), requiredDate: integer('required_date', { mode: 'timestamp' }).notNull(), shippedDate: integer('shipped_date', { mode: 'timestamp' }), shipVia: integer('ship_via').notNull(), freight: numeric('freight').notNull(), shipName: text('ship_name').notNull(), shipCity: text('ship_city').notNull(), shipRegion: text('ship_region'), shipPostalCode: text('ship_postal_code'), shipCountry: text('ship_country').notNull(), customerId: text('customer_id').notNull(), employeeId: integer('employee_id').notNull(), }); const details = sqliteTable('order_detail', { unitPrice: numeric('unit_price').notNull(), quantity: integer('quantity').notNull(), discount: numeric('discount').notNull(), orderId: integer('order_id').notNull(), productId: integer('product_id').notNull(), }); db .select({ id: orders.id, shippedDate: orders.shippedDate, shipName: orders.shipName, shipCity: orders.shipCity, shipCountry: orders.shipCountry, productsCount: sql`cast(count(${details.productId}) as int)`, quantitySum: sql`sum(${details.quantity})`, totalPrice: sql`sum(${details.quantity} * ${details.unitPrice})`, }) .from(orders) .leftJoin(details, eq(orders.id, details.orderId)) .groupBy(orders.id) .orderBy(asc(orders.id)) .all(); ``` ### $count <$count /> ## --- ### Iterator If you need to return a very large amount of rows from a query and you don't want to load them all into memory, you can use `.iterator()` to convert the query into an async iterator: ```ts copy const iterator = await db.select().from(users).iterator(); for await (const row of iterator) { console.log(row); } ``` It also works with prepared statements: ```ts copy const query = await db.select().from(users).prepare(); const iterator = await query.iterator(); for await (const row of iterator) { console.log(row); } ``` ## --- ### Use Index The `USE INDEX` hint suggests to the optimizer which indexes to consider when processing the query. The optimizer is not forced to use these indexes but will prioritize them if they are suitable. ```ts copy export const users = mysqlTable('users', { id: int('id').primaryKey(), name: varchar('name', { length: 100 }).notNull(), }, () => [usersTableNameIndex]); const usersTableNameIndex = index('users_name_index').on(users.name); await db.select() .from(users, { useIndex: usersTableNameIndex }) .where(eq(users.name, 'David')); ``` You can also use this option on any join you want ```ts await db.select() .from(users) .leftJoin(posts, eq(posts.userId, users.id), { useIndex: usersTableNameIndex }) .where(eq(users.name, 'David')); ``` ### Ignore Index The `IGNORE INDEX` hint tells the optimizer to avoid using specific indexes for the query. MySQL will consider all other indexes (if any) or perform a full table scan if necessary. ```ts copy export const users = mysqlTable('users', { id: int('id').primaryKey(), name: varchar('name', { length: 100 }).notNull(), }, () => [usersTableNameIndex]); const usersTableNameIndex = index('users_name_index').on(users.name); await db.select() .from(users, { ignoreIndex: usersTableNameIndex }) .where(eq(users.name, 'David')); ``` You can also use this option on any join you want ```ts await db.select() .from(users) .leftJoin(posts, eq(posts.userId, users.id), { useIndex: usersTableNameIndex }) .where(eq(users.name, 'David')); ``` ### Force Index The `FORCE INDEX` hint forces the optimizer to use the specified index(es) for the query. If the specified index cannot be used, MySQL will not fall back to other indexes; it might resort to a full table scan instead. ```ts copy export const users = mysqlTable('users', { id: int('id').primaryKey(), name: varchar('name', { length: 100 }).notNull(), }, () => [usersTableNameIndex]); const usersTableNameIndex = index('users_name_index').on(users.name); await db.select() .from(users, { forceIndex: usersTableNameIndex }) .where(eq(users.name, 'David')); ``` You can also use this option on any join you want ```ts await db.select() .from(users) .leftJoin(posts, eq(posts.userId, users.id), { useIndex: usersTableNameIndex }) .where(eq(users.name, 'David')); ``` Source: https://orm.drizzle.team/docs/sequences import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import Callout from '@mdx/Callout.astro'; # Sequences To use this feature you would need to have `drizzle-orm@0.32.0` or higher and `drizzle-kit@0.23.0` or higher Sequences in PostgreSQL are special single-row tables created to generate unique identifiers, often used for auto-incrementing primary key values. They provide a thread-safe way to generate unique sequential values across multiple sessions.
**Key Features** - Creation and Initialization: Use CREATE SEQUENCE to create a new sequence. Parameters such as increment value, start value, min/max values, and cache size can be specified. - Manipulation Functions - `nextval('sequence_name')`: Advances the sequence and returns the next value. - `currval('sequence_name')`: Returns the current value of the sequence for the current session. - `setval('sequence_name', value)`: Sets the sequence's current value. - `lastval()`: Returns the last value returned by nextval in the current session. - Ownership: Sequences can be linked to table columns using the OWNED BY clause. Dropping the table or column will automatically drop the associated sequence. - Cycling: Sequences can be set to cycle when they reach their maximum or minimum value using the CYCLE option. The default is NO CYCLE. - Caching: Sequence values can be preallocated using the CACHE option for improved performance.
**Limitations** - Gaps: Sequences are not gapless. Aborted transactions or crashes can lead to gaps in the sequence values. - Concurrency: While sequences provide unique values across sessions, the values may be out of order when considering all sessions. - No Rollback: Changes to sequences are not rolled back if a transaction fails. This ensures unique values but can lead to gaps. - Crash Recovery: Unlogged sequences or sequences modified before a crash might not be properly restored to their previous state.
**Practical Use** - Default Behavior: By default, sequences increment by 1 and start at 1. - Custom Behavior: Custom start points, increments, min/max values, and cycling can be specified. - Associations: Commonly associated with table columns for auto-incrementing fields, making management of unique identifiers seamless.
**Usage Example** ```ts import { pgSchema, pgSequence } from "drizzle-orm/pg-core"; // No params specified export const customSequence = pgSequence("name"); // Sequence with params export const customSequence = pgSequence("name", { startWith: 100, maxValue: 10000, minValue: 100, cycle: true, cache: 10, increment: 2 }); // Sequence in custom schema export const customSchema = pgSchema('custom_schema'); export const customSequence = customSchema.sequence("name"); ``` Source: https://orm.drizzle.team/docs/set-operations import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Callout from '@mdx/Callout.astro'; # Set Operations SQL set operations combine the results of multiple query blocks into a single result. The SQL standard defines the following three set operations: `UNION`, `INTERSECT`, `EXCEPT`, `UNION ALL`, `INTERSECT ALL`, `EXCEPT ALL`. ### Union Combine all results from two query blocks into a single result, omitting any duplicates. Get all names from customers and users tables without duplicates. ```typescript copy import { union } from 'drizzle-orm/pg-core' import { users, customers } from './schema' const allNamesForUserQuery = db.select({ name: users.name }).from(users); const result = await union( allNamesForUserQuery, db.select({ name: customers.name }).from(customers) ).limit(10); ``` ```sql (select "name" from "sellers") union (select "name" from "customers") limit $1 ``` ```ts copy import { users, customers } from './schema' const result = await db .select({ name: users.name }) .from(users) .union(db.select({ name: customers.name }).from(customers)) .limit(10); ``` ```sql (select "name" from "sellers") union (select "name" from "customers") limit $1 ``` ```typescript copy import { integer, pgTable, text, varchar } from "drizzle-orm/pg-core"; const users = pgTable('sellers', { id: integer('id').primaryKey(), name: varchar('name', { length: 256 }).notNull(), address: text('address'), }); const customers = pgTable('customers', { id: integer('id').primaryKey(), name: varchar('name', { length: 256 }).notNull(), city: text('city'), email: varchar('email', { length: 256 }).notNull() }); ``` ```typescript copy import { union } from 'drizzle-orm/mysql-core' import { users, customers } from './schema' const allNamesForUserQuery = db.select({ name: users.name }).from(users); const result = await union( allNamesForUserQuery, db.select({ name: customers.name }).from(customers) ).limit(10); ``` ```sql (select `name` from `sellers`) union (select `name` from `customers`) limit ? ``` ```ts copy import { users, customers } from './schema' const result = await db .select({ name: users.name }) .from(users) .union(db.select({ name: customers.name }).from(customers)) .limit(10); ``` ```sql (select `name` from `sellers`) union (select `name` from `customers`) limit ? ``` ```typescript copy import { int, mysqlTable, text, varchar } from "drizzle-orm/mysql-core"; const users = mysqlTable('sellers', { id: int('id').primaryKey(), name: varchar('name', { length: 256 }).notNull(), address: text('address'), }); const customers = mysqlTable('customers', { id: int('id').primaryKey(), name: varchar('name', { length: 256 }).notNull(), city: text('city'), email: varchar('email', { length: 256 }).notNull() }); ``` ```typescript copy import { union } from 'drizzle-orm/sqlite-core' import { users, customers } from './schema' const allNamesForUserQuery = db.select({ name: users.name }).from(users); const result = await union( allNamesForUserQuery, db.select({ name: customers.name }).from(customers) ).limit(10); ``` ```sql (select "name" from "sellers") union (select "name" from "customers") limit ? ``` ```ts copy import { users, customers } from './schema' const result = await db .select({ name: users.name }) .from(users) .union(db.select({ name: customers.name }).from(customers)) .limit(10); ``` ```sql select "name" from "sellers" union select "name" from "customers" limit ? ``` ```typescript copy import { int, sqliteTable, text } from "drizzle-orm/sqlite-core"; const users = sqliteTable('sellers', { id: int('id').primaryKey(), name: text('name').notNull(), address: text('address'), }); const customers = sqliteTable('customers', { id: int('id').primaryKey(), name: text('name').notNull(), city: text('city'), email: text('email').notNull() }); ``` ```typescript copy import { union } from 'drizzle-orm/singlestore-core' import { users, customers } from './schema' const allNamesForUserQuery = db.select({ name: users.name }).from(users); const result = await union( allNamesForUserQuery, db.select({ name: customers.name }).from(customers) ).limit(10); ``` ```sql (select `name` from `sellers`) union (select `name` from `customers`) limit ? ``` ```ts copy import { users, customers } from './schema' const result = await db .select({ name: users.name }) .from(users) .union(db.select({ name: customers.name }).from(customers)) .limit(10); ``` ```sql (select `name` from `sellers`) union (select `name` from `customers`) limit ? ``` ```typescript copy import { int, mysqlTable, text, varchar } from "drizzle-orm/singlestore-core"; const users = mysqlTable('sellers', { id: int('id').primaryKey(), name: varchar('name', { length: 256 }).notNull(), address: text('address'), }); const customers = mysqlTable('customers', { id: int('id').primaryKey(), name: varchar('name', { length: 256 }).notNull(), city: text('city'), email: varchar('email', { length: 256 }).notNull() }); ``` ### Union All Combine all results from two query blocks into a single result, with duplicates. Let's consider a scenario where you have two tables, one representing online sales and the other representing in-store sales. In this case, you want to combine the data from both tables into a single result set. Since there might be duplicate transactions, you want to keep all the records and not eliminate duplicates. ```typescript copy import { unionAll } from 'drizzle-orm/pg-core' import { onlineSales, inStoreSales } from './schema' const onlineTransactions = db.select({ transaction: onlineSales.transactionId }).from(onlineSales); const inStoreTransactions = db.select({ transaction: inStoreSales.transactionId }).from(inStoreSales); const result = await unionAll(onlineTransactions, inStoreTransactions); ``` ```sql select "transaction_id" from "online_sales" union all select "transaction_id" from "in_store_sales" ``` ```ts copy import { onlineSales, inStoreSales } from './schema' const result = await db .select({ transaction: onlineSales.transactionId }) .from(onlineSales) .unionAll( db.select({ transaction: inStoreSales.transactionId }).from(inStoreSales) ); ``` ```sql select "transaction_id" from "online_sales" union all select "transaction_id" from "in_store_sales" ``` ```typescript copy import { integer, pgTable, text, timestamp, varchar } from "drizzle-orm/pg-core"; const onlineSales = pgTable('online_sales', { transactionId: integer('transaction_id').primaryKey(), productId: integer('product_id').unique(), quantitySold: integer('quantity_sold'), saleDate: timestamp('sale_date', { mode: 'date' }), }); const inStoreSales = pgTable('in_store_sales', { transactionId: integer('transaction_id').primaryKey(), productId: integer('product_id').unique(), quantitySold: integer('quantity_sold'), saleDate: timestamp('sale_date', { mode: 'date' }), }); ``` ```typescript copy import { unionAll } from 'drizzle-orm/mysql-core' import { onlineSales, inStoreSales } from './schema' const onlineTransactions = db.select({ transaction: onlineSales.transactionId }).from(onlineSales); const inStoreTransactions = db.select({ transaction: inStoreSales.transactionId }).from(inStoreSales); const result = await unionAll(onlineTransactions, inStoreTransactions); ``` ```sql select `transaction_id` from `online_sales` union all select `transaction_id` from `in_store_sales` ``` ```ts copy import { onlineSales, inStoreSales } from './schema' const result = await db .select({ transaction: onlineSales.transactionId }) .from(onlineSales) .unionAll( db.select({ transaction: inStoreSales.transactionId }).from(inStoreSales) ); ``` ```sql (select `transaction_id` from `online_sales`) union all (select `transaction_id` from `in_store_sales`) ``` ```typescript copy import { int, mysqlTable, text, timestamp, varchar } from "drizzle-orm/mysql-core"; const onlineSales = mysqlTable('online_sales', { transactionId: int('transaction_id').primaryKey(), productId: int('product_id').unique(), quantitySold: int('quantity_sold'), saleDate: timestamp('sale_date', { mode: 'date' }), }); const inStoreSales = mysqlTable('in_store_sales', { transactionId: int('transaction_id').primaryKey(), productId: int('product_id').unique(), quantitySold: int('quantity_sold'), saleDate: timestamp('sale_date', { mode: 'date' }), }); ``` ```typescript copy import { unionAll } from 'drizzle-orm/sqlite-core' import { onlineSales, inStoreSales } from './schema' const onlineTransactions = db.select({ transaction: onlineSales.transactionId }).from(onlineSales); const inStoreTransactions = db.select({ transaction: inStoreSales.transactionId }).from(inStoreSales); const result = await unionAll(onlineTransactions, inStoreTransactions); ``` ```sql select "transaction_id" from "online_sales" union all select "transaction_id" from "in_store_sales" ``` ```ts copy import { onlineSales, inStoreSales } from './schema' const result = await db .select({ transaction: onlineSales.transactionId }) .from(onlineSales) .unionAll( db.select({ transaction: inStoreSales.transactionId }).from(inStoreSales) ); ``` ```sql select "transaction_id" from "online_sales" union all select "transaction_id" from "in_store_sales" ``` ```typescript copy import { int, sqliteTable } from "drizzle-orm/sqlite-core"; const onlineSales = sqliteTable('online_sales', { transactionId: int('transaction_id').primaryKey(), productId: int('product_id').unique(), quantitySold: int('quantity_sold'), saleDate: int('sale_date', { mode: 'timestamp' }), }); const inStoreSales = sqliteTable('in_store_sales', { transactionId: int('transaction_id').primaryKey(), productId: int('product_id').unique(), quantitySold: int('quantity_sold'), saleDate: int('sale_date', { mode: 'timestamp' }), }); ``` UNION ALL with ORDER BY behavior inconsistent with MySQL: SingleStore parses UNION ALL followed by ORDER BY commands differently from MySQL. In SingleStore, the following query is valid. In MySQL, it is invalid. ```typescript copy import { unionAll } from 'drizzle-orm/singlestore-core' import { onlineSales, inStoreSales } from './schema' const onlineTransactions = db.select({ transaction: onlineSales.transactionId }).from(onlineSales); const inStoreTransactions = db.select({ transaction: inStoreSales.transactionId }).from(inStoreSales); const result = await unionAll(onlineTransactions, inStoreTransactions); ``` ```sql select `transaction_id` from `online_sales` union all select `transaction_id` from `in_store_sales` ``` ```ts copy import { onlineSales, inStoreSales } from './schema' const result = await db .select({ transaction: onlineSales.transactionId }) .from(onlineSales) .unionAll( db.select({ transaction: inStoreSales.transactionId }).from(inStoreSales) ); ``` ```sql (select `transaction_id` from `online_sales`) union all (select `transaction_id` from `in_store_sales`) ``` ```typescript copy import { int, mysqlTable, text, timestamp, varchar } from "drizzle-orm/singlestore-core"; const onlineSales = mysqlTable('online_sales', { transactionId: int('transaction_id').primaryKey(), productId: int('product_id').unique(), quantitySold: int('quantity_sold'), saleDate: timestamp('sale_date', { mode: 'date' }), }); const inStoreSales = mysqlTable('in_store_sales', { transactionId: int('transaction_id').primaryKey(), productId: int('product_id').unique(), quantitySold: int('quantity_sold'), saleDate: timestamp('sale_date', { mode: 'date' }), }); ``` ### Intersect Combine only those rows which the results of two query blocks have in common, omitting any duplicates. Suppose you have two tables that store information about students' course enrollments. You want to find the courses that are common between two different departments, but you want distinct course names, and you're not interested in counting multiple enrollments of the same course by the same student. In this scenario, you want to find courses that are common between the two departments but don't want to count the same course multiple times even if multiple students from the same department are enrolled in it. ```typescript copy import { intersect } from 'drizzle-orm/pg-core' import { depA, depB } from './schema' const departmentACourses = db.select({ courseName: depA.courseName }).from(depA); const departmentBCourses = db.select({ courseName: depB.courseName }).from(depB); const result = await intersect(departmentACourses, departmentBCourses); ``` ```sql select "course_name" from "department_a_courses" intersect select "course_name" from "department_b_courses" ``` ```typescript copy import { depA, depB } from './schema' const result = await db .select({ courseName: depA.courseName }) .from(depA) .intersect(db.select({ courseName: depB.courseName }).from(depB)); ``` ```sql select "course_name" from "department_a_courses" intersect select "course_name" from "department_b_courses" ``` ```typescript copy import { integer, pgTable, varchar } from "drizzle-orm/pg-core"; const depA = pgTable('department_a_courses', { studentId: integer('student_id'), courseName: varchar('course_name').notNull(), }); const depB = pgTable('department_b_courses', { studentId: integer('student_id'), courseName: varchar('course_name').notNull(), }); ``` ```typescript copy import { intersect } from 'drizzle-orm/mysql-core' import { depA, depB } from './schema' const departmentACourses = db.select({ courseName: depA.courseName }).from(depA); const departmentBCourses = db.select({ courseName: depB.courseName }).from(depB); const result = await intersect(departmentACourses, departmentBCourses); ``` ```sql select `projects_name` from `department_a_projects` intersect select `projects_name` from `department_b_projects` ``` ```typescript copy import { depA, depB } from './schema' const result = await db .select({ courseName: depA.courseName }) .from(depA) .intersect(db.select({ courseName: depB.courseName }).from(depB)); ``` ```sql select `projects_name` from `department_a_projects` intersect select `projects_name` from `department_b_projects` ``` ```typescript copy import { int, mysqlTable, varchar } from "drizzle-orm/mysql-core"; const depA = mysqlTable('department_a_courses', { studentId: int('student_id'), courseName: varchar('course_name', { length: 256 }).notNull(), }); const depB = pgTable('department_b_courses', { studentId: int('student_id'), courseName: varchar('course_name', { length: 256 }).notNull(), }); ``` ```typescript copy import { intersect } from 'drizzle-orm/sqlite-core' import { depA, depB } from './schema' const departmentACourses = db.select({ courseName: depA.courseName }).from(depA); const departmentBCourses = db.select({ courseName: depB.courseName }).from(depB); const result = await intersect(departmentACourses, departmentBCourses); ``` ```sql select "course_name" from "department_a_courses" intersect select "course_name" from "department_b_courses" ``` ```typescript copy import { depA, depB } from './schema' const result = await db .select({ courseName: depA.courseName }) .from(depA) .intersect(db.select({ courseName: depB.courseName }).from(depB)); ``` ```sql select "course_name" from "department_a_courses" intersect select "course_name" from "department_b_courses" ``` ```typescript copy import { int, sqliteTable, text } from "drizzle-orm/sqlite-core"; const depA = sqliteTable('department_a_courses', { studentId: int('student_id'), courseName: text('course_name').notNull(), }); const depB = sqliteTable('department_b_courses', { studentId: int('student_id'), courseName: text('course_name').notNull(), }); ``` ```typescript copy import { intersect } from 'drizzle-orm/singlestore-core' import { depA, depB } from './schema' const departmentACourses = db.select({ courseName: depA.courseName }).from(depA); const departmentBCourses = db.select({ courseName: depB.courseName }).from(depB); const result = await intersect(departmentACourses, departmentBCourses); ``` ```sql select `projects_name` from `department_a_projects` intersect select `projects_name` from `department_b_projects` ``` ```typescript copy import { depA, depB } from './schema' const result = await db .select({ courseName: depA.courseName }) .from(depA) .intersect(db.select({ courseName: depB.courseName }).from(depB)); ``` ```sql select `projects_name` from `department_a_projects` intersect select `projects_name` from `department_b_projects` ``` ```typescript copy import { int, mysqlTable, varchar } from "drizzle-orm/singlestore-core"; const depA = mysqlTable('department_a_courses', { studentId: int('student_id'), courseName: varchar('course_name', { length: 256 }).notNull(), }); const depB = pgTable('department_b_courses', { studentId: int('student_id'), courseName: varchar('course_name', { length: 256 }).notNull(), }); ``` ### Intersect All Combine only those rows which the results of two query blocks have in common, with duplicates. Let's consider a scenario where you have two tables containing data about customer orders, and you want to identify products that are ordered by both regular customers and VIP customers. In this case, you want to keep track of the quantity of each product, even if it's ordered multiple times by different customers. In this scenario, you want to find products that are ordered by both regular customers and VIP customers, but you want to retain the quantity information, even if the same product is ordered multiple times by different customers. ```typescript copy import { intersectAll } from 'drizzle-orm/pg-core' import { regularCustomerOrders, vipCustomerOrders } from './schema' const regularOrders = db.select({ productId: regularCustomerOrders.productId, quantityOrdered: regularCustomerOrders.quantityOrdered } ).from(regularCustomerOrders); const vipOrders = db.select({ productId: vipCustomerOrders.productId, quantityOrdered: vipCustomerOrders.quantityOrdered } ).from(vipCustomerOrders); const result = await intersectAll(regularOrders, vipOrders); ``` ```sql select "product_id", "quantity_ordered" from "regular_customer_orders" intersect all select "product_id", "quantity_ordered" from "vip_customer_orders" ``` ```ts copy import { regularCustomerOrders, vipCustomerOrders } from './schema' const result = await db .select({ productId: regularCustomerOrders.productId, quantityOrdered: regularCustomerOrders.quantityOrdered, }) .from(regularCustomerOrders) .intersectAll( db .select({ productId: vipCustomerOrders.productId, quantityOrdered: vipCustomerOrders.quantityOrdered, }) .from(vipCustomerOrders) ); ``` ```sql select "product_id", "quantity_ordered" from "regular_customer_orders" intersect all select "product_id", "quantity_ordered" from "vip_customer_orders" ``` ```typescript copy import { integer, pgTable } from "drizzle-orm/pg-core"; const regularCustomerOrders = pgTable('regular_customer_orders', { customerId: integer('customer_id').primaryKey(), productId: integer('product_id').notNull(), quantityOrdered: integer('quantity_ordered').notNull(), }); const vipCustomerOrders = pgTable('vip_customer_orders', { customerId: integer('customer_id').primaryKey(), productId: integer('product_id').notNull(), quantityOrdered: integer('quantity_ordered').notNull(), }); ``` ```typescript copy import { intersectAll } from 'drizzle-orm/mysql-core' import { regularCustomerOrders, vipCustomerOrders } from './schema' const regularOrders = db.select({ productId: regularCustomerOrders.productId, quantityOrdered: regularCustomerOrders.quantityOrdered } ).from(regularCustomerOrders); const vipOrders = db.select({ productId: vipCustomerOrders.productId, quantityOrdered: vipCustomerOrders.quantityOrdered } ).from(vipCustomerOrders); const result = await intersectAll(regularOrders, vipOrders); ``` ```sql select `product_id`, `quantity_ordered` from `regular_customer_orders` intersect all select `product_id`, `quantity_ordered` from `vip_customer_orders` ``` ```ts copy import { regularCustomerOrders, vipCustomerOrders } from './schema' const result = await db .select({ productId: regularCustomerOrders.productId, quantityOrdered: regularCustomerOrders.quantityOrdered, }) .from(regularCustomerOrders) .intersectAll( db .select({ productId: vipCustomerOrders.productId, quantityOrdered: vipCustomerOrders.quantityOrdered, }) .from(vipCustomerOrders) ); ``` ```sql select `product_id`, `quantity_ordered` from `regular_customer_orders` intersect all select `product_id`, `quantity_ordered` from `vip_customer_orders` ``` ```typescript copy import { int, mysqlTable } from "drizzle-orm/mysql-core"; const regularCustomerOrders = mysqlTable('regular_customer_orders', { customerId: int('customer_id').primaryKey(), productId: int('product_id').notNull(), quantityOrdered: int('quantity_ordered').notNull(), }); const vipCustomerOrders = mysqlTable('vip_customer_orders', { customerId: int('customer_id').primaryKey(), productId: int('product_id').notNull(), quantityOrdered: int('quantity_ordered').notNull(), }); ``` Not supported by SingleStore ### Except For two query blocks A and B, return all results from A which are not also present in B, omitting any duplicates. Suppose you have two tables that store information about employees' project assignments. You want to find the projects that are unique to one department and not shared with another department, excluding duplicates. In this scenario, you want to identify the projects that are exclusive to one department and not shared with the other department. You don't want to count the same project multiple times, even if multiple employees from the same department are assigned to it. ```typescript copy import { except } from 'drizzle-orm/pg-core' import { depA, depB } from './schema' const departmentACourses = db.select({ courseName: depA.projectsName }).from(depA); const departmentBCourses = db.select({ courseName: depB.projectsName }).from(depB); const result = await except(departmentACourses, departmentBCourses); ``` ```sql select "projects_name" from "department_a_projects" except select "projects_name" from "department_b_projects" ``` ```ts copy import { depA, depB } from './schema' const result = await db .select({ courseName: depA.projectsName }) .from(depA) .except(db.select({ courseName: depB.projectsName }).from(depB)); ``` ```sql select "projects_name" from "department_a_projects" except select "projects_name" from "department_b_projects" ``` ```typescript copy import { integer, pgTable, varchar } from "drizzle-orm/pg-core"; const depA = pgTable('department_a_projects', { employeeId: integer('employee_id'), projectsName: varchar('projects_name').notNull(), }); const depB = pgTable('department_b_projects', { employeeId: integer('employee_id'), projectsName: varchar('projects_name').notNull(), }); ``` ```typescript copy import { except } from 'drizzle-orm/mysql-core' import { depA, depB } from './schema' const departmentACourses = db.select({ courseName: depA.projectsName }).from(depA); const departmentBCourses = db.select({ courseName: depB.projectsName }).from(depB); const result = await except(departmentACourses, departmentBCourses); ``` ```sql select `projects_name` from `department_a_projects` except select `projects_name` from `department_b_projects` ``` ```ts copy import { depA, depB } from './schema' const result = await db .select({ courseName: depA.projectsName }) .from(depA) .except(db.select({ courseName: depB.projectsName }).from(depB)); ``` ```sql select `projects_name` from `department_a_projects` except select `projects_name` from `department_b_projects` ``` ```typescript import { int, mysqlTable, varchar } from "drizzle-orm/mysql-core"; const depA = mysqlTable('department_a_projects', { employeeId: int('employee_id'), projectsName: varchar('projects_name', { length: 256 }).notNull(), }); const depB = mysqlTable('department_b_projects', { employeeId: int('employee_id'), projectsName: varchar('projects_name', { length: 256 }).notNull(), }); ``` ```typescript copy import { except } from 'drizzle-orm/sqlite-core' import { depA, depB } from './schema' const departmentACourses = db.select({ courseName: depA.projectsName }).from(depA); const departmentBCourses = db.select({ courseName: depB.projectsName }).from(depB); const result = await except(departmentACourses, departmentBCourses); ``` ```sql select "projects_name" from "department_a_projects" except select "projects_name" from "department_b_projects" ``` ```ts copy import { depA, depB } from './schema' const result = await db .select({ courseName: depA.projectsName }) .from(depA) .except(db.select({ courseName: depB.projectsName }).from(depB)); ``` ```sql select "projects_name" from "department_a_projects" except select "projects_name" from "department_b_projects" ``` ```typescript copy import { int, sqliteTable, text } from "drizzle-orm/sqlite-core"; const depA = sqliteTable('department_a_projects', { employeeId: int('employee_id'), projectsName: text('projects_name').notNull(), }); const depB = sqliteTable('department_b_projects', { employeeId: int('employee_id'), projectsName: text('projects_name').notNull(), }); ``` ```typescript copy import { except } from 'drizzle-orm/singlestore-core' import { depA, depB } from './schema' const departmentACourses = db.select({ courseName: depA.projectsName }).from(depA); const departmentBCourses = db.select({ courseName: depB.projectsName }).from(depB); const result = await except(departmentACourses, departmentBCourses); ``` ```sql select `projects_name` from `department_a_projects` except select `projects_name` from `department_b_projects` ``` ```ts copy import { depA, depB } from './schema' const result = await db .select({ courseName: depA.projectsName }) .from(depA) .except(db.select({ courseName: depB.projectsName }).from(depB)); ``` ```sql select `projects_name` from `department_a_projects` except select `projects_name` from `department_b_projects` ``` ```typescript import { int, mysqlTable, varchar } from "drizzle-orm/singlestore-core"; const depA = mysqlTable('department_a_projects', { employeeId: int('employee_id'), projectsName: varchar('projects_name', { length: 256 }).notNull(), }); const depB = mysqlTable('department_b_projects', { employeeId: int('employee_id'), projectsName: varchar('projects_name', { length: 256 }).notNull(), }); ``` ### Except All For two query blocks A and B, return all results from A which are not also present in B, with duplicates. Let's consider a scenario where you have two tables containing data about customer orders, and you want to identify products that are exclusively ordered by regular customers (without VIP customers). In this case, you want to keep track of the quantity of each product, even if it's ordered multiple times by different regular customers. In this scenario, you want to find products that are exclusively ordered by regular customers and not ordered by VIP customers. You want to retain the quantity information, even if the same product is ordered multiple times by different regular customers. ```typescript copy import { exceptAll } from 'drizzle-orm/pg-core' import { regularCustomerOrders, vipCustomerOrders } from './schema' const regularOrders = db.select({ productId: regularCustomerOrders.productId, quantityOrdered: regularCustomerOrders.quantityOrdered } ).from(regularCustomerOrders); const vipOrders = db.select({ productId: vipCustomerOrders.productId, quantityOrdered: vipCustomerOrders.quantityOrdered } ).from(vipCustomerOrders); const result = await exceptAll(regularOrders, vipOrders); ``` ```sql select "product_id", "quantity_ordered" from "regular_customer_orders" except all select "product_id", "quantity_ordered" from "vip_customer_orders" ``` ```ts copy import { regularCustomerOrders, vipCustomerOrders } from './schema' const result = await db .select({ productId: regularCustomerOrders.productId, quantityOrdered: regularCustomerOrders.quantityOrdered, }) .from(regularCustomerOrders) .exceptAll( db .select({ productId: vipCustomerOrders.productId, quantityOrdered: vipCustomerOrders.quantityOrdered, }) .from(vipCustomerOrders) ); ``` ```sql select "product_id", "quantity_ordered" from "regular_customer_orders" except all select "product_id", "quantity_ordered" from "vip_customer_orders" ``` ```typescript copy import { integer, pgTable } from "drizzle-orm/pg-core"; const regularCustomerOrders = pgTable('regular_customer_orders', { customerId: integer('customer_id').primaryKey(), productId: integer('product_id').notNull(), quantityOrdered: integer('quantity_ordered').notNull(), }); const vipCustomerOrders = pgTable('vip_customer_orders', { customerId: integer('customer_id').primaryKey(), productId: integer('product_id').notNull(), quantityOrdered: integer('quantity_ordered').notNull(), }); ``` ```typescript copy import { exceptAll } from 'drizzle-orm/mysql-core' import { regularCustomerOrders, vipCustomerOrders } from './schema' const regularOrders = db.select({ productId: regularCustomerOrders.productId, quantityOrdered: regularCustomerOrders.quantityOrdered } ).from(regularCustomerOrders); const vipOrders = db.select({ productId: vipCustomerOrders.productId, quantityOrdered: vipCustomerOrders.quantityOrdered } ).from(vipCustomerOrders); const result = await exceptAll(regularOrders, vipOrders); ``` ```sql select `product_id`, `quantity_ordered` from `regular_customer_orders` except all select `product_id`, `quantity_ordered` from `vip_customer_orders` ``` ```ts copy import { regularCustomerOrders, vipCustomerOrders } from './schema' const result = await db .select({ productId: regularCustomerOrders.productId, quantityOrdered: regularCustomerOrders.quantityOrdered, }) .from(regularCustomerOrders) .exceptAll( db .select({ productId: vipCustomerOrders.productId, quantityOrdered: vipCustomerOrders.quantityOrdered, }) .from(vipCustomerOrders) ); ``` ```sql select `product_id`, `quantity_ordered` from `regular_customer_orders` except all select `product_id`, `quantity_ordered` from `vip_customer_orders` ``` ```typescript copy const regularCustomerOrders = mysqlTable('regular_customer_orders', { customerId: int('customer_id').primaryKey(), productId: int('product_id').notNull(), quantityOrdered: int('quantity_ordered').notNull(), }); const vipCustomerOrders = mysqlTable('vip_customer_orders', { customerId: int('customer_id').primaryKey(), productId: int('product_id').notNull(), quantityOrdered: int('quantity_ordered').notNull(), }); ``` Not supported by SingleStore Source: https://orm.drizzle.team/docs/sql-schema-declaration import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import Callout from '@mdx/Callout.astro'; import SimpleLinkCards from '@mdx/SimpleLinkCards.astro'; import CodeTabs from "@mdx/CodeTabs.astro"; import Section from '@mdx/Section.astro'; import Flex from "@mdx/Flex.astro" import LinksList from "@mdx/LinksList.astro" # Drizzle schema Drizzle lets you define a schema in TypeScript with various models and properties supported by the underlying database. When you define your schema, it serves as the source of truth for future modifications in queries (using Drizzle-ORM) and migrations (using Drizzle-Kit). If you are using Drizzle-Kit for the migration process, make sure to export all the models defined in your schema files so that Drizzle-Kit can import them and use them in the migration diff process. ## Organize your schema files You can declare your SQL schema directly in TypeScript either in a single `schema.ts` file, or you can spread them around — whichever you prefer, all the freedom! #### Schema in 1 file The most common way to declare your schema with Drizzle is to put all your tables into one `schema.ts` file. > Note: You can name your schema file whatever you like. For example, it could be `models.ts`, or something else. This approach works well if you don't have too many table models defined, or if you're okay with keeping them all in one file Example: ```plaintext 📦 └ 📂 src └ 📂 db └ 📜 schema.ts ``` In the `drizzle.config.ts` file, you need to specify the path to your schema file. With this configuration, Drizzle will read from the `schema.ts` file and use this information during the migration generation process. For more information about the `drizzle.config.ts` file and migrations with Drizzle, please check: [link](/docs/drizzle-config-file) ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: 'postgresql', // 'mysql' | 'sqlite' | 'turso' schema: './src/db/schema.ts' }) ``` #### Schema in multiple files You can place your Drizzle models — such as tables, enums, sequences, etc. — not only in one file but in any file you prefer. The only thing you must ensure is that you export all the models from those files so that the Drizzle kit can import them and use them in migrations. One use case would be to separate each table into its own file. ```plaintext 📦 └ 📂 src └ 📂 db └ 📂 schema ├ 📜 users.ts ├ 📜 countries.ts ├ 📜 cities.ts ├ 📜 products.ts ├ 📜 clients.ts └ 📜 etc.ts ``` In the `drizzle.config.ts` file, you need to specify the path to your schema folder. With this configuration, Drizzle will read from the `schema` folder and find all the files recursively and get all the drizzle tables from there. For more information about the `drizzle.config.ts` file and migrations with Drizzle, please check: [link](/docs/drizzle-config-file) ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: 'postgresql', // 'mysql' | 'sqlite' | 'turso' schema: './src/db/schema' }) ``` You can also group them in any way you like, such as creating groups for user-related tables, messaging-related tables, product-related tables, etc. ```plaintext 📦 └ 📂 src └ 📂 db └ 📂 schema ├ 📜 users.ts ├ 📜 messaging.ts └ 📜 products.ts ``` In the `drizzle.config.ts` file, you need to specify the path to your schema file. With this configuration, Drizzle will read from the `schema.ts` file and use this information during the migration generation process. For more information about the `drizzle.config.ts` file and migrations with Drizzle, please check: [link](/docs/drizzle-config-file) ```ts import { defineConfig } from "drizzle-kit"; export default defineConfig({ dialect: 'postgresql', // 'mysql' | 'sqlite' | 'turso' schema: './src/db/schema' }) ``` ## Shape your data schema Drizzle schema consists of several model types from database you are using. With drizzle you can specify: - Tables with columns, constraints, etc. - Schemas(PostgreSQL only) - Enums - Sequences(PostgreSQL only) - Views - Materialized Views - etc. Let's go one by one and check how the schema should be defined with drizzle #### **Tables and columns declaration** A table in Drizzle should be defined with at least 1 column, the same as it should be done in database. There is one important thing to know, there is no such thing as a common table object in drizzle. You need to choose a dialect you are using, PostgreSQL, MySQL or SQLite ![](@/assets/images/table-structure.svg) ```ts copy import { pgTable, integer } from "drizzle-orm/pg-core" export const users = pgTable('users', { id: integer() }); ``` ```ts copy import { mysqlTable, int } from "drizzle-orm/mysql-core" export const users = mysqlTable('users', { id: int() }); ``` ```ts copy import { sqliteTable, integer } from "drizzle-orm/sqlite-core" export const users = sqliteTable('users', { id: integer() }); ``` By default, Drizzle will use the TypeScript key names for columns in database queries. Therefore, the schema and query from the example will generate the SQL query shown below This example uses a db object, whose initialization is not covered in this part of the documentation. To learn how to connect to the database, please refer to the [Connections Docs](/docs/get-started-postgresql) \ **TypeScript key = database key**
```ts // schema.ts import { integer, pgTable, varchar } from "drizzle-orm/pg-core"; export const users = pgTable('users', { id: integer(), first_name: varchar() }) ``` ```ts // query.ts await db.select().from(users); ``` ```sql SELECT "id", "first_name" from users; ```
If you want to use different names in your TypeScript code and in the database, you can use column aliases
```ts // schema.ts import { integer, pgTable, varchar } from "drizzle-orm/pg-core"; export const users = pgTable('users', { id: integer(), firstName: varchar('first_name') }) ``` ```ts // query.ts await db.select().from(users); ``` ```sql SELECT "id", "first_name" from users; ```
### Camel and Snake casing Database model names often use `snake_case` conventions, while in TypeScript, it is common to use `camelCase` for naming models. This can lead to a lot of alias definitions in the schema. To address this, Drizzle provides a way to automatically map `camelCase` from TypeScript to `snake_case` in the database by including one optional parameter during Drizzle database initialization For such mapping, you can use the `casing` option in the Drizzle DB declaration. This parameter will help you specify the database model naming convention and will attempt to map all JavaScript keys accordingly
```ts // schema.ts import { drizzle } from "drizzle-orm/node-postgres"; import { integer, pgTable, varchar } from "drizzle-orm/pg-core"; export const users = pgTable('users', { id: integer(), firstName: varchar() }) ``` ```ts // db.ts const db = drizzle({ connection: process.env.DATABASE_URL, casing: 'snake_case' }) ``` ```ts // query.ts await db.select().from(users); ``` ```sql SELECT "id", "first_name" from users; ```
### Advanced There are a few tricks you can use with Drizzle ORM. As long as Drizzle is entirely in TypeScript files, you can essentially do anything you would in a simple TypeScript project with your code. One common feature is to separate columns into different places and then reuse them. For example, consider the `updated_at`, `created_at`, and `deleted_at` columns. Many tables/models may need these three fields to track and analyze the creation, deletion, and updates of entities in a system We can define those columns in a separate file and then import and spread them across all the table objects you have
```ts // columns.helpers.ts const timestamps = { updated_at: timestamp(), created_at: timestamp().defaultNow().notNull(), deleted_at: timestamp(), } ``` ```ts // users.sql.ts export const users = pgTable('users', { id: integer(), ...timestamps }) ``` ```ts // posts.sql.ts export const posts = pgTable('posts', { id: integer(), ...timestamps }) ```
#### **Schemas** \ In PostgreSQL, there is an entity called a `schema` (which we believe should be called `folders`). This creates a structure in PostgreSQL: ![](@/assets/images/postgresql-db-structure.png) You can manage your PostgreSQL schemas with `pgSchema` and place any other models inside it. Define the schema you want to manage using Drizzle ```ts import { pgSchema } from "drizzle-orm/pg-core" export const customSchema = pgSchema('custom'); ``` Then place the table inside the schema object ```ts {5-7} import { integer, pgSchema } from "drizzle-orm/pg-core"; export const customSchema = pgSchema('custom'); export const users = customSchema.table('users', { id: integer() }) ``` \ In MySQL, there is an entity called `Schema`, but in MySQL terms, this is equivalent to a `Database`. You can define them with `drizzle-orm` and use them in queries, but they won't be detected by `drizzle-kit` or included in the migration flow ![](@/assets/images/mysql-db-structure.png) Define the schema you want to manage using Drizzle ```ts import { mysqlSchema } from "drizzle-orm/mysql-core" export const customSchema = mysqlSchema('custom'); ``` Then place the table inside the schema object ```ts {5-7} import { int, mysqlSchema } from "drizzle-orm/mysql-core"; export const customSchema = mysqlSchema('custom'); export const users = customSchema.table('users', { id: int() }) ``` \ In SQLite, there is no concept of a schema, so you can only define tables within a single SQLite file context ![](@/assets/images/sqlite-db-structure.png) ### Example Once you know the basics, let's define a schema example for a real project to get a better view and understanding > All examples will use `generateUniqueString`. The implementation for it will be provided after all the schema examples ```ts copy import { AnyPgColumn } from "drizzle-orm/pg-core"; import { pgEnum, pgTable as table } from "drizzle-orm/pg-core"; import * as t from "drizzle-orm/pg-core"; export const rolesEnum = pgEnum("roles", ["guest", "user", "admin"]); export const users = table( "users", { id: t.integer().primaryKey().generatedAlwaysAsIdentity(), firstName: t.varchar("first_name", { length: 256 }), lastName: t.varchar("last_name", { length: 256 }), email: t.varchar().notNull(), invitee: t.integer().references((): AnyPgColumn => users.id), role: rolesEnum().default("guest"), }, (table) => [ t.uniqueIndex("email_idx").on(table.email) ] ); export const posts = table( "posts", { id: t.integer().primaryKey().generatedAlwaysAsIdentity(), slug: t.varchar().$default(() => generateUniqueString(16)), title: t.varchar({ length: 256 }), ownerId: t.integer("owner_id").references(() => users.id), }, (table) => [ t.uniqueIndex("slug_idx").on(table.slug), t.index("title_idx").on(table.title), ] ); export const comments = table("comments", { id: t.integer().primaryKey().generatedAlwaysAsIdentity(), text: t.varchar({ length: 256 }), postId: t.integer("post_id").references(() => posts.id), ownerId: t.integer("owner_id").references(() => users.id), }); ``` ```ts copy import { mysqlTable as table } from "drizzle-orm/mysql-core"; import * as t from "drizzle-orm/mysql-core"; import { AnyMySqlColumn } from "drizzle-orm/mysql-core"; export const users = table( "users", { id: t.int().primaryKey().autoincrement(), firstName: t.varchar("first_name", { length: 256 }), lastName: t.varchar("last_name", { length: 256 }), email: t.varchar({ length: 256 }).notNull(), invitee: t.int().references((): AnyMySqlColumn => users.id), role: t.mysqlEnum(["guest", "user", "admin"]).default("guest"), }, (table) => [ t.uniqueIndex("email_idx").on(table.email) ] ); export const posts = table( "posts", { id: t.int().primaryKey().autoincrement(), slug: t.varchar({ length: 256 }).$default(() => generateUniqueString(16)), title: t.varchar({ length: 256 }), ownerId: t.int("owner_id").references(() => users.id), }, (table) => [ t.uniqueIndex("slug_idx").on(table.slug), t.index("title_idx").on(table.title), ] ); export const comments = table("comments", { id: t.int().primaryKey().autoincrement(), text: t.varchar({ length: 256 }), postId: t.int("post_id").references(() => posts.id), ownerId: t.int("owner_id").references(() => users.id), }); ``` ```ts copy import { sqliteTable as table } from "drizzle-orm/sqlite-core"; import * as t from "drizzle-orm/sqlite-core"; import { AnySQLiteColumn } from "drizzle-orm/sqlite-core"; export const users = table( "users", { id: t.int().primaryKey({ autoIncrement: true }), firstName: t.text("first_name"), lastName: t.text("last_name"), email: t.text().notNull(), invitee: t.int().references((): AnySQLiteColumn => users.id), role: t.text().$type<"guest" | "user" | "admin">().default("guest"), }, (table) => [ t.uniqueIndex("email_idx").on(table.email) ] ); export const posts = table( "posts", { id: t.int().primaryKey({ autoIncrement: true }), slug: t.text().$default(() => generateUniqueString(16)), title: t.text(), ownerId: t.int("owner_id").references(() => users.id), }, (table) => [ t.uniqueIndex("slug_idx").on(table.slug), t.index("title_idx").on(table.title), ] ); export const comments = table("comments", { id: t.int().primaryKey({ autoIncrement: true }), text: t.text({ length: 256 }), postId: t.int("post_id").references(() => posts.id), ownerId: t.int("owner_id").references(() => users.id), }); ``` **`generateUniqueString` implementation:** ```ts function generateUniqueString(length: number = 12): string { const characters = "ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789"; let uniqueString = ""; for (let i = 0; i < length; i++) { const randomIndex = Math.floor(Math.random() * characters.length); uniqueString += characters[randomIndex]; } return uniqueString; } ``` #### What's next?
Source: https://orm.drizzle.team/docs/sql import Callout from '@mdx/Callout.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import CodeTab from '@mdx/CodeTab.astro'; import Section from '@mdx/Section.astro'; # Magical `sql` operator 🪄 When working with an ORM library, there may be cases where you find it challenging to write a specific query using the provided ORM syntax. In such situations, you can resort to using raw queries, which involve constructing a query as a raw string. However, raw queries often lack the benefits of type safety and query parameterization. To address this, many libraries have introduced the concept of an `sql` template. This template allows you to write more type-safe and parameterized queries, enhancing the overall safety and flexibility of your code. Drizzle, being a powerful ORM library, also supports the sql template. With Drizzle's `sql` template, you can go even further in crafting queries. If you encounter difficulties in writing an entire query using the library's query builder, you can selectively use the `sql` template within specific sections of the Drizzle query. This flexibility enables you to employ the sql template in partial SELECT statements, WHERE clauses, ORDER BY clauses, HAVING clauses, GROUP BY clauses, and even in relational query builders. By leveraging the capabilities of the sql template in Drizzle, you can maintain the advantages of type safety and query parameterization while achieving the desired query structure and complexity. This empowers you to create more robust and maintainable code within your application. ## sql`` template One of the most common usages you may encounter in other ORMs as well is the ability to use `sql` queries as-is for raw queries. ```typescript copy import { sql } from 'drizzle-orm' const id = 69; await db.execute(sql`select * from ${usersTable} where ${usersTable.id} = ${id}`) ``` It will generate the current query ```sql select * from "users" where "users"."id" = $1; --> [69] ``` Any tables and columns provided to the sql parameter are automatically mapped to their corresponding SQL syntax with escaped names for tables, and the escaped table names are appended to column names. Additionally, any dynamic parameters such as `${id}` will be mapped to the $1 placeholder, and the corresponding values will be moved to an array of values that are passed separately to the database. This approach effectively prevents any potential SQL Injection vulnerabilities. ## `sql` Please note that `sql` does not perform any runtime mapping. The type you define using `sql` is purely a helper for Drizzle. It is important to understand that there is no feasible way to determine the exact type dynamically, as SQL queries can be highly versatile and customizable. You can define a custom type in Drizzle to be used in places where fields require a specific type other than `unknown`. This feature is particularly useful in partial select queries, ensuring consistent typing for selected fields: ```typescript // without sql type defined const response: { id: unknown }[] = await db.select({ lowerName: sql`lower(${usersTable.id})` }).from(usersTable); // with sql type defined const response: { id: string }[] = await db.select({ lowerName: sql`lower(${usersTable.id})` }).from(usersTable); ``` ## `sql``.mapWith()` For the cases you need to make a runtime mapping for values passed from database driver to drizzle you can use `.mapWith()` This function accepts different values, that will map response in runtime. You can replicate a specific column mapping strategy as long as the interface inside mapWith is the same interface that is implemented by Column. ```typescript const usersTable = pgTable('users', { id: serial('id').primaryKey(), name: text('name').notNull(), }); // at runtime this values will be mapped same as `text` column is mapped in drizzle sql`...`.mapWith(usersTable.name); ``` You can also pass your own implementation for the `DriverValueDecoder` interface: ```ts sql``.mapWith({ mapFromDriverValue: (value: any) => { const mappedValue = value; // mapping you want to apply return mappedValue; }, }); // or sql``.mapWith(Number); ``` ## `sql``.as()` In different cases, it can sometimes be challenging to determine how to name a custom field that you want to use. You may encounter situations where you need to explicitly specify an alias for a field that will be selected. This can be particularly useful when dealing with complex queries. To address these scenarios, we have introduced a helpful `.as('alias_name')` helper, which allows you to define an alias explicitly. By utilizing this feature, you can provide a clear and meaningful name for the field, making your queries more intuitive and readable.
```typescript sql`lower(usersTable.name)`.as('lower_name') ``` ```sql ... "usersTable"."name" as lower_name ... ```
## `sql.raw()` There are cases where you may not need to create parameterized values from input or map tables/columns to escaped ones. Instead, you might simply want to generate queries as they are. For such situations, we provide the `sql.raw()` function. The `sql.raw()` function allows you to include raw SQL statements within your queries without any additional processing or escaping. This can be useful when you have pre-constructed SQL statements or when you need to incorporate complex or dynamic SQL code directly into your queries.
```typescript sql.raw(`select * from users where id = ${12}`); // vs sql`select * from users where id = ${12}`; ``` ```sql select * from users where id = 12; --> vs select * from users where id = $1; --> [12] ```
You can also utilize `sql.raw()` within the sql function, enabling you to include any raw string without escaping it through the main `sql` template function. By using `sql.raw()` inside the `sql` function, you can incorporate unescaped raw strings directly into your queries. This can be particularly useful when you have specific SQL code or expressions that should remain untouched by the template function's automatic escaping or modification.
```typescript sql`select * from ${usersTable} where id = ${12}`; // vs sql`select * from ${usersTable} where id = ${sql.raw(12)}`; ``` ```sql select * from "users" where id = $1; --> [12] --> vs select * from "users" where id = 12; ```
## sql.fromList() The `sql` template generates sql chunks, which are arrays of SQL parts that will be concatenated into the query and params after applying the SQL to the database or query in Drizzle. In certain scenarios, you may need to aggregate these chunks into an array using custom business logic and then concatenate them into a single SQL statement that can be passed to the database or query. For such cases, the fromList function can be quite useful. The fromList function allows you to combine multiple SQL chunks into a single SQL statement. You can use it to aggregate and concatenate the individual SQL parts according to your specific requirements and then obtain a unified SQL query that can be executed.
```typescript const sqlChunks: SQL[] = []; sqlChunks.push(sql`select * from users`); // some logic sqlChunks.push(sql` where `); // some logic for (let i = 0; i < 5; i++) { sqlChunks.push(sql`id = ${i}`); if (i === 4) continue; sqlChunks.push(sql` or `); } const finalSql: SQL = sql.fromList(sqlChunks) ``` ```sql select * from users where id = $1 or id = $2 or id = $3 or id = $4 or id = $5; --> [0, 1, 2, 3, 4] ```
## sql.join() Indeed, the `sql.join` function serves a similar purpose to the fromList helper. However, it provides additional flexibility when it comes to handling spaces between SQL chunks or specifying custom separators for concatenating the SQL chunks. With `sql.join`, you can concatenate SQL chunks together using a specified separator. This separator can be any string or character that you want to insert between the chunks. This is particularly useful when you have specific requirements for formatting or delimiting the SQL chunks. By specifying a custom separator, you can achieve the desired structure and formatting in the final SQL query.
```typescript const sqlChunks: SQL[] = []; sqlChunks.push(sql`select * from users`); // some logic sqlChunks.push(sql`where`); // some logic for (let i = 0; i < 5; i++) { sqlChunks.push(sql`id = ${i}`); if (i === 4) continue; sqlChunks.push(sql`or`); } const finalSql: SQL = sql.join(sqlChunks, sql.raw(' ')); ``` ```sql select * from users where id = $1 or id = $2 or id = $3 or id = $4 or id = $5; --> [0, 1, 2, 3, 4] ```
## sql.append() If you have already generated SQL using the `sql` template, you can achieve the same behavior as `fromList` by using the append function to directly add a new chunk to the generated SQL. By using the append function, you can dynamically add additional SQL chunks to the existing SQL string, effectively concatenating them together. This allows you to incorporate custom logic or business rules for aggregating the chunks into the final SQL query.
```typescript const finalSql = sql`select * from users`; // some logic finalSql.append(sql` where `); // some logic for (let i = 0; i < 5; i++) { finalSql.append(sql`id = ${i}`); if (i === 4) continue; finalSql.append(sql` or `); } ``` ```sql select * from users where id = $1 or id = $2 or id = $3 or id = $4 or id = $5; --> [0, 1, 2, 3, 4] ```
## sql.empty() By using sql.empty(), you can start with a blank SQL object and then dynamically append SQL chunks to it as needed. This allows you to construct the SQL query incrementally, applying custom logic or conditions to determine the contents of each chunk. Once you have initialized the SQL object using sql.empty(), you can take advantage of the full range of sql template features such as parameterization, composition, and escaping. This empowers you to construct the SQL query in a flexible and controlled manner, adapting it to your specific requirements. ```typescript const finalSql = sql.empty(); // some logic finalSql.append(sql`select * from users`); // some logic finalSql.append(sql` where `); // some logic for (let i = 0; i < 5; i++) { finalSql.append(sql`id = ${i}`); if (i === 4) continue; finalSql.append(sql` or `); } ``` ```sql select * from users where id = $1 or id = $2 or id = $3 or id = $4 or id = $5; --> [0, 1, 2, 3, 4] ``` ## Convert `sql` to string and params In all the previous examples, you observed the usage of SQL template syntax in TypeScript along with the generated SQL output. If you need to obtain the query string and corresponding parameters generated from the SQL template, you must specify the database dialect you intend to generate the query for. Different databases have varying syntax for parameterization and escaping, so selecting the appropriate dialect is crucial. Once you have chosen the dialect, you can utilize the corresponding implementation's functionality to convert the SQL template into the desired query string and parameter format. This ensures compatibility with the specific database system you are working with.
```typescript copy import { PgDialect } from 'drizzle-orm/pg-core'; const pgDialect = new PgDialect(); pgDialect.sqlToQuery(sql`select * from ${usersTable} where ${usersTable.id} = ${12}`); ``` ```sql select * from "users" where "users"."id" = $1; --> [ 12 ] ```
```typescript copy import { MySqlDialect } from 'drizzle-orm/mysql-core'; const mysqlDialect = new MySqlDialect(); mysqlDialect.sqlToQuery(sql`select * from ${usersTable} where ${usersTable.id} = ${12}`); ``` ```sql select * from `users` where `users`.`id` = ?; --> [ 12 ] ```
```typescript copy import { SQLiteSyncDialect } from 'drizzle-orm/sqlite-core'; const sqliteDialect = new SQLiteSyncDialect(); sqliteDialect.sqlToQuery(sql`select * from ${usersTable} where ${usersTable.id} = ${12}`); ``` ```sql select * from "users" where "users"."id" = ?; --> [ 12 ] ```
## `sql` select You can use the sql functionality in partial select queries as well. Partial select queries allow you to retrieve specific fields or columns from a table rather than fetching the entire row. For more detailed information about partial select queries, you can refer to the Core API documentation available at **[Core API docs](/docs/select#basic-and-partial-select)**. **Select different custom fields from table** Here you can see a usage for **[`sql`](/docs/sql#sqlt)**, **[`sql``.mapWith()`](/docs/sql#sqlmapwith)**, **[`sql``.as()`](/docs/sql#sqlast)**.
```typescript copy import { sql } from 'drizzle-orm' import { usersTable } from 'schema' await db.select({ id: usersTable.id, lowerName: sql`lower(${usersTable.name})`, aliasedName: sql`lower(${usersTable.name})`.as('aliased_column'), count: sql`count(*)`.mapWith(Number) }).from(usersTable) ``` ```sql select `id`, lower(`name`), lower(`name`) as `aliased_column`, count(*) from `users`; ```
## `sql` in where Indeed, Drizzle provides a set of available expressions that you can use within the sql template. However, it is true that databases often have a wider range of expressions available, including those provided through extensions or other means. To ensure flexibility and enable you to utilize any expressions that are not natively supported by Drizzle, you have the freedom to write the SQL template directly using the sql function. This allows you to leverage the full power of SQL and incorporate any expressions or functionalities specific to your target database. By using the sql template, you are not restricted to only the predefined expressions in Drizzle. Instead, you can express complex queries and incorporate any supported expressions that the underlying database system provides. **Filtering by `id` but with sql**
```typescript copy import { sql } from 'drizzle-orm' import { usersTable } from 'schema' const id = 77 await db.select() .from(usersTable) .where(sql`${usersTable.id} = ${id}`) ``` ```sql select * from "users" where "users"."id" = $1; --> [ 77 ] ```
**Advanced fulltext search where statement**
```typescript copy import { sql } from 'drizzle-orm' import { usersTable } from 'schema' const searchParam = "Ale" await db.select() .from(usersTable) .where(sql`to_tsvector('simple', ${usersTable.name}) @@ to_tsquery('simple', ${searchParam})`) ``` ```sql select * from "users" where to_tsvector('simple', "users"."name") @@ to_tsquery('simple', '$1'); --> [ "Ale" ] ```
## `sql` in orderBy The `sql` template can indeed be used in the ORDER BY clause when you need specific functionality for ordering that is not available in Drizzle, but you prefer not to resort to raw SQL.
```typescript copy import { sql } from 'drizzle-orm' import { usersTable } from 'schema' await db.select().from(usersTable).orderBy(sql`${usersTable.id} desc nulls first`) ``` ```sql select * from "users" order by "users"."id" desc nulls first; ```
## `sql` in having and groupBy The `sql` template can indeed be used in the HAVING and GROUP BY clauses when you need specific functionality for ordering that is not available in Drizzle, but you prefer not to resort to raw SQL.
```typescript copy import { sql } from 'drizzle-orm' import { usersTable } from 'schema' await db.select({ projectId: usersTable.projectId, count: sql`count(${usersTable.id})`.mapWith(Number) }).from(usersTable) .groupBy(sql`${usersTable.projectId}`) .having(sql`count(${usersTable.id}) > 300`) ``` ```sql select "project_id", count("users"."id") from users group by "users"."project_id" having count("users"."id") > 300; ```
Source: https://orm.drizzle.team/docs/transactions import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; # Transactions SQL transaction is a grouping of one or more SQL statements that interact with a database. A transaction in its entirety can commit to a database as a single logical unit or rollback (become undone) as a single logical unit. Drizzle ORM provides APIs to run SQL statements in transactions: ```ts copy const db = drizzle(...) await db.transaction(async (tx) => { await tx.update(accounts).set({ balance: sql`${accounts.balance} - 100.00` }).where(eq(users.name, 'Dan')); await tx.update(accounts).set({ balance: sql`${accounts.balance} + 100.00` }).where(eq(users.name, 'Andrew')); }); ``` Drizzle ORM supports `savepoints` with nested transactions API: ```ts copy {7-9} const db = drizzle(...) await db.transaction(async (tx) => { await tx.update(accounts).set({ balance: sql`${accounts.balance} - 100.00` }).where(eq(users.name, 'Dan')); await tx.update(accounts).set({ balance: sql`${accounts.balance} + 100.00` }).where(eq(users.name, 'Andrew')); await tx.transaction(async (tx2) => { await tx2.update(users).set({ name: "Mr. Dan" }).where(eq(users.name, "Dan")); }); }); ``` You can embed business logic to the transaction and rollback whenever needed: ```ts copy {7} const db = drizzle(...) await db.transaction(async (tx) => { const [account] = await tx.select({ balance: accounts.balance }).from(accounts).where(eq(users.name, 'Dan')); if (account.balance < 100) { // This throws an exception that rollbacks the transaction. tx.rollback() } await tx.update(accounts).set({ balance: sql`${accounts.balance} - 100.00` }).where(eq(users.name, 'Dan')); await tx.update(accounts).set({ balance: sql`${accounts.balance} + 100.00` }).where(eq(users.name, 'Andrew')); }); ``` You can return values from the transaction: ```ts copy {8} const db = drizzle(...) const newBalance: number = await db.transaction(async (tx) => { await tx.update(accounts).set({ balance: sql`${accounts.balance} - 100.00` }).where(eq(users.name, 'Dan')); await tx.update(accounts).set({ balance: sql`${accounts.balance} + 100.00` }).where(eq(users.name, 'Andrew')); const [account] = await tx.select({ balance: accounts.balance }).from(accounts).where(eq(users.name, 'Dan')); return account.balance; }); ``` You can use transactions with **[relational queries](/docs/rqb)**: ```ts const db = drizzle({ schema }) await db.transaction(async (tx) => { await tx.query.users.findMany({ with: { accounts: true } }); }); ``` We provide dialect-specific transaction configuration APIs: ```ts copy {6-8} await db.transaction( async (tx) => { await tx.update(accounts).set({ balance: sql`${accounts.balance} - 100.00` }).where(eq(users.name, "Dan")); await tx.update(accounts).set({ balance: sql`${accounts.balance} + 100.00` }).where(eq(users.name, "Andrew")); }, { isolationLevel: "read committed", accessMode: "read write", deferrable: true, } ); interface PgTransactionConfig { isolationLevel?: | "read uncommitted" | "read committed" | "repeatable read" | "serializable"; accessMode?: "read only" | "read write"; deferrable?: boolean; } ``` ```ts {6-8} await db.transaction( async (tx) => { await tx.update(accounts).set({ balance: sql`${accounts.balance} - 100.00` }).where(eq(users.name, "Dan")); await tx.update(accounts).set({ balance: sql`${accounts.balance} + 100.00` }).where(eq(users.name, "Andrew")); }, { isolationLevel: "read committed", accessMode: "read write", withConsistentSnapshot: true, } ); interface MySqlTransactionConfig { isolationLevel?: | "read uncommitted" | "read committed" | "repeatable read" | "serializable"; accessMode?: "read only" | "read write"; withConsistentSnapshot?: boolean; } ``` ```ts {6} await db.transaction( async (tx) => { await tx.update(accounts).set({ balance: sql`${accounts.balance} - 100.00` }).where(eq(users.name, "Dan")); await tx.update(accounts).set({ balance: sql`${accounts.balance} + 100.00` }).where(eq(users.name, "Andrew")); }, { behavior: "deferred", } ); interface SQLiteTransactionConfig { behavior?: 'deferred' | 'immediate' | 'exclusive'; } ``` ```ts {6-8} await db.transaction( async (tx) => { await tx.update(accounts).set({ balance: sql`${accounts.balance} - 100.00` }).where(eq(users.name, "Dan")); await tx.update(accounts).set({ balance: sql`${accounts.balance} + 100.00` }).where(eq(users.name, "Andrew")); }, { isolationLevel: "read committed", accessMode: "read write", withConsistentSnapshot: true, } ); interface SingleStoreTransactionConfig { isolationLevel?: | "read uncommitted" | "read committed" | "repeatable read" | "serializable"; accessMode?: "read only" | "read write"; withConsistentSnapshot?: boolean; } ``` Source: https://orm.drizzle.team/docs/tutorials import Tutorials from "@components/Tutorials.astro"; Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-netlify-edge-functions-neon import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from '@mdx/Npm.astro'; import Steps from '@mdx/Steps.astro'; import Section from "@mdx/Section.astro"; import Callout from "@mdx/Callout.astro"; This tutorial demonstrates how to use Drizzle ORM with [Netlify Edge Functions](https://docs.netlify.com/edge-functions/overview/) and [Neon Postgres](https://neon.tech/) database. - You should have the latest version of [Netlify CLI](https://docs.netlify.com/cli/get-started/#installation) installed. - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should have installed the `dotenv` package for managing environment variables. If you use Node.js `v20.6.0` or later, there is no need to install it because Node.js natively supports `.env` files. Read more about it [here](https://nodejs.org/en/blog/release/v20.6.0#built-in-env-file-support). dotenv - Optionally, you can install the `@netlify/edge-functions` package to import the types for the `Context` object which will be used later. @netlify/edge-functions These installed packages are used only to create table in the database in [Create a table](#create-a-table), [Setup Drizzle config file](#setup-drizzle-config-file) and [Apply changes to the database](#apply-changes-to-the-database) steps. These packages do not affect the code running inside Netlify Edge Functions. We will use `import_map.json` to import the necessary packages for the Edge Functions. #### Setup Neon Postgres Log in to the [Neon Console](https://console.neon.tech/app/projects) and navigate to the Projects section. Select a project or click the `New Project` button to create a new one. Your Neon projects come with a ready-to-use Postgres database named `neondb`. We'll use it in this tutorial. #### Setup connection string variable In **Project Dashboard** section click the `Connect` button and copy your database connection string. It should look similar to this: ```bash postgres://username:password@ep-cool-darkness-123456.us-east-2.aws.neon.tech/neondb?sslmode=require ``` Add the `DATABASE_URL` environment variable to your `.env` file, which you'll use to connect to the Neon database. ```text copy DATABASE_URL=NEON_DATABASE_CONNECTION_STRING ``` #### Setup Netlify Edge Functions Create `netlify/edge-functions` directory in the root of your project. This is where you'll store your Edge Functions. Create a function `user.ts` in the `netlify/edge-functions` directory. ```typescript copy filename="netlify/edge-functions/user.ts" import type { Context } from "@netlify/edge-functions"; export default async (request: Request, context: Context) => { return new Response("User data"); }; ``` The types for the `Request` and `Response` objects are in the global scope. #### Setup imports Create a `import_map.json` file in the root of your project and add the following content: ```json copy filename="import_map.json" { "imports": { "drizzle-orm/": "https://esm.sh/drizzle-orm/", "@neondatabase/serverless": "https://esm.sh/@neondatabase/serverless" } } ``` Read more about `import_map.json` in Netlify Edge Functions [here](https://docs.netlify.com/edge-functions/api/#import-maps). #### Create a Netlify configuration file Create a `netlify.toml` file in the root of your project and add the following content: ```toml copy filename="netlify.toml" [functions] deno_import_map = "./import_map.json" [[edge_functions]] path = "/user" function = "user" ``` This configuration tells Netlify to use the `import_map.json` file for Deno imports and to route requests to the `/user` path to the `user.ts` function. Read more about `netlify.toml` [here](https://docs.netlify.com/configure-builds/file-based-configuration/). #### Create a table Create a `schema.ts` file in the `netlify/edge-functions/common` directory and declare a table schema: ```typescript copy filename="netlify/edge-functions/common/schema.ts" import { pgTable, serial, text, integer } from "drizzle-orm/pg-core"; export const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull(), email: text('email').notNull().unique(), }) ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import 'dotenv/config'; // remove this line if you use Node.js v20.6.0 or later import type { Config } from "drizzle-kit"; export default { schema: './netlify/edge-functions/common/schema.ts', out: './drizzle', dialect: 'postgresql', dbCredentials: { url: process.env.DATABASE_URL!, }, } satisfies Config; ``` In this tutorial we will use Drizzle kit to push changes to the Neon database. #### Apply changes to the database ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. Alternatively, you can use migrations workflow. Read about it here: [Migrations](/docs/migrations). #### Connect Drizzle ORM to your database Update your `netlify/edge-functions/user.ts` file and set up your database configuration: ```typescript copy filename="netlify/edge-functions/user.ts" import type { Context } from "@netlify/edge-functions"; import { usersTable } from "./common/schema.ts"; import { neon } from '@neondatabase/serverless'; import { drizzle } from 'drizzle-orm/neon-http'; export default async (request: Request, context: Context) => { const sql = neon(Netlify.env.get("DATABASE_URL")!); const db = drizzle({ client: sql }); const users = await db.select().from(usersTable); return new Response(JSON.stringify(users)); }; ``` You might see a red underline under the imports if you're using VS Code. The Edge Function will still execute. To get rid of the red underline, you can configure VS Code to use Edge Functions in the next step. #### Test your code locally Run the following command to start the Netlify dev server: ```bash copy netlify dev ``` When you first run the command it will suggest to configure VS Code to use Edge Functions. Click `Yes` to configure it. `settings.json` file will be created in the `.vscode` directory. If you still see red underlines, you can restart the Deno Language Server. Open your browser and navigate to the route `/user`. You should see the user data returned from the Neon database: ```plaintext [] ``` It could be an empty array if you haven't added any data to the `users_table` table. #### Initialize a new Netlify project Run the following command to initialize a new Netlify project: ```bash copy netlify init ``` Answer the questions in the CLI to create a new Netlify project. In this tutorial, we will choose `Yes, create and deploy site manually` -> `` -> ``. #### Setup Netlify environment variables Run the following command to import your environment variables into Netlify: ```bash copy netlify env:import .env ``` Read more about Netlify environment variables [here](https://docs.netlify.com/environment-variables/get-started/). #### Deploy your project Run the following command to deploy your project: ```bash copy netlify deploy ``` Follow the instructions in the CLI to deploy your project to Netlify. In this tutorial our publish directory is `'.'`. It is a [draft deployment](https://docs.netlify.com/cli/get-started/#draft-deploys) by default. To do a production deployment, run the following command: ```bash copy netlify deploy --prod ``` Finally, you can use URL of the deployed website and navigate to the route you created `(e.g. /user)` to access your edge function. Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-netlify-edge-functions-supabase import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from '@mdx/Npm.astro'; import Steps from '@mdx/Steps.astro'; import Section from "@mdx/Section.astro"; import Callout from "@mdx/Callout.astro"; This tutorial demonstrates how to use Drizzle ORM with [Netlify Edge Functions](https://docs.netlify.com/edge-functions/overview/) and [Supabase Database](https://supabase.com/docs/guides/database/overview) database. - You should have the latest version of [Netlify CLI](https://docs.netlify.com/cli/get-started/#installation) installed. - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should have installed the `dotenv` package for managing environment variables. If you use Node.js `v20.6.0` or later, there is no need to install it because Node.js natively supports `.env` files. Read more about it [here](https://nodejs.org/en/blog/release/v20.6.0#built-in-env-file-support). dotenv - Optionally, you can install the `@netlify/edge-functions` package to import the types for the `Context` object which will be used later. @netlify/edge-functions These installed packages are used only to create table in the database in [Create a table](#create-a-table), [Setup Drizzle config file](#setup-drizzle-config-file) and [Apply changes to the database](#apply-changes-to-the-database) steps. These packages do not affect the code running inside Netlify Edge Functions. We will use `import_map.json` to import the necessary packages for the Edge Functions. #### Create a new Supabase project You can create new Supabase project in the [dashboard](https://supabase.com/dashboard) or by following this [link](https://database.new/). #### Setup connection string variable You can find `Project connect details` by clicking **Connect** in the top bar of the dashboard and copy the URI from the `Transaction pooler` section. Remember to replace the password placeholder with your actual database password. Add `DATABASE_URL` variable to your `.env` file. ```plaintext copy DATABASE_URL= ``` Read more about connecting to Supabase Database in the [documentation](https://supabase.com/docs/guides/database/connecting-to-postgres#connection-pooler). #### Setup Netlify Edge Functions Create `netlify/edge-functions` directory in the root of your project. This is where you'll store your Edge Functions. Create a function `user.ts` in the `netlify/edge-functions` directory. ```typescript copy filename="netlify/edge-functions/user.ts" import type { Context } from "@netlify/edge-functions"; export default async (request: Request, context: Context) => { return new Response("User data"); }; ``` The types for the `Request` and `Response` objects are in the global scope. #### Setup imports Create a `import_map.json` file in the root of your project and add the following content: ```json copy filename="import_map.json" { "imports": { "drizzle-orm/": "https://esm.sh/drizzle-orm/", "postgres": "https://esm.sh/postgres" } } ``` Read more about `import_map.json` in Netlify Edge Functions [here](https://docs.netlify.com/edge-functions/api/#import-maps). #### Create a Netlify configuration file Create a `netlify.toml` file in the root of your project and add the following content: ```toml copy filename="netlify.toml" [functions] deno_import_map = "./import_map.json" [[edge_functions]] path = "/user" function = "user" ``` This configuration tells Netlify to use the `import_map.json` file for Deno imports and to route requests to the `/user` path to the `user.ts` function. Read more about `netlify.toml` [here](https://docs.netlify.com/configure-builds/file-based-configuration/). #### Create a table Create a `schema.ts` file in the `netlify/edge-functions/common` directory and declare a table schema: ```typescript copy filename="netlify/edge-functions/common/schema.ts" import { pgTable, serial, text, integer } from "drizzle-orm/pg-core"; export const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull(), email: text('email').notNull().unique(), }) ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import 'dotenv/config'; // remove this line if you use Node.js v20.6.0 or later import type { Config } from "drizzle-kit"; export default { schema: './netlify/edge-functions/common/schema.ts', out: './drizzle', dialect: 'postgresql', dbCredentials: { url: process.env.DATABASE_URL!, }, } satisfies Config; ``` In this tutorial we will use Drizzle kit to push changes to the Neon database. #### Apply changes to the database ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. Alternatively, you can use migrations workflow. Read about it here: [Migrations](/docs/migrations). #### Connect Drizzle ORM to your database Update your `netlify/edge-functions/user.ts` file and set up your database configuration: ```typescript copy filename="netlify/edge-functions/user.ts" import type { Context } from "@netlify/edge-functions"; import { usersTable } from "./common/schema.ts"; import { drizzle } from 'drizzle-orm/postgres-js'; import postgres from 'postgres'; export default async (request: Request, context: Context) => { const queryClient = postgres(Netlify.env.get("DATABASE_URL")!); const db = drizzle({ client: queryClient }); const users = await db.select().from(usersTable); return new Response(JSON.stringify(users)); }; ``` You might see a red underline under the imports if you're using VS Code. The Edge Function will still execute. To get rid of the red underline, you can configure VS Code to use Edge Functions in the next step. #### Test your code locally Run the following command to start the Netlify dev server: ```bash copy netlify dev ``` When you first run the command it will suggest to configure VS Code to use Edge Functions. Click `Yes` to configure it. `settings.json` file will be created in the `.vscode` directory. If you still see red underlines, you can restart the Deno Language Server. Open your browser and navigate to the route `/user`. You should see the user data returned from the Neon database: ```plaintext [] ``` It could be an empty array if you haven't added any data to the `users_table` table. #### Initialize a new Netlify project Run the following command to initialize a new Netlify project: ```bash copy netlify init ``` Answer the questions in the CLI to create a new Netlify project. In this tutorial, we will choose `Yes, create and deploy site manually` -> `` -> ``. #### Setup Netlify environment variables Run the following command to import your environment variables into Netlify: ```bash copy netlify env:import .env ``` Read more about Netlify environment variables [here](https://docs.netlify.com/environment-variables/get-started/). #### Deploy your project Run the following command to deploy your project: ```bash copy netlify deploy ``` Follow the instructions in the CLI to deploy your project to Netlify. In this tutorial our publish directory is `'.'`. It is a [draft deployment](https://docs.netlify.com/cli/get-started/#draft-deploys) by default. To do a production deployment, run the following command: ```bash copy netlify deploy --prod ``` Finally, you can use URL of the deployed website and navigate to the route you created `(e.g. /user)` to access your edge function. Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-supabase-edge-functions import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from '@mdx/Npm.astro'; import Steps from '@mdx/Steps.astro'; import Section from "@mdx/Section.astro"; import Callout from '@mdx/Callout.astro'; This tutorial demonstrates how to use Drizzle ORM with [Supabase Edge Functions](https://supabase.com/docs/guides/functions). - You should have the latest version of [Supabase CLI](https://supabase.com/docs/guides/cli/getting-started#installing-the-supabase-cli) installed. - You should have installed Drizzle ORM and [Drizzle kit](https://orm.drizzle.team/kit-docs/overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should have installed Docker Desktop. It is a prerequisite for local development. Follow the official [docs](https://docs.docker.com/desktop) to install. To learn how to create a basic Edge Function on your local machine and then deploy it, see the [Edge Functions Quickstart](https://supabase.com/docs/guides/functions/quickstart). #### Create a table Create a `schema.ts` file in your `src` directory and declare a table schema: ```typescript copy filename="src/schema.ts" import { pgTable, serial, text, integer } from "drizzle-orm/pg-core"; export const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull() }) ``` This file will be used to generate migrations for your database. #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](https://orm.drizzle.team/kit-docs/overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { defineConfig } from "drizzle-kit"; export default defineConfig({ schema: "./src/schema.ts", out: "./supabase/migrations", dialect: "postgresql", }); ``` In this tutorial we will use Drizzle kit to generate migrations for our schema. #### Initialize a new Supabase project Create a new Supabase project in a folder on your local machine: ```bash copy supabase init ``` It will create `supabase` folder with `config.toml` file: ```text └── supabase └── config.toml ``` If you are using Visual Studio Code, follow the [Supabase documentation](https://supabase.com/docs/guides/functions/local-development#deno-with-visual-studio-code) to setup settings for Deno. #### Generate migrations Run the `drizzle-kit generate` command to generate migrations: ```bash copy npx drizzle-kit generate ``` It will create a new migration file in the `supabase/migrations` directory: #### Apply migrations To start the Supabase local development stack, run the following command: ```bash copy supabase start ``` To apply migrations, run the following command: ```bash copy supabase migration up ``` You can read more about Supabase migrations in the [documentation](https://supabase.com/docs/guides/deployment/database-migrations). Don't forget to run Docker Alternatively, you can apply migrations using the `drizzle-kit migrate` command. Learn more about this migration process in the [documentation](https://orm.drizzle.team/docs/migrations). #### Create a new Edge Function Run the `supabase functions new [FUNCTION_NAME]` command to create a new Edge Function: ```bash copy supabase functions new drizzle-tutorial ``` It will create a new folder with the function name in the `supabase/functions` directory: ```text └── supabase └── functions │ └── drizzle-tutorial │ │ ├── .npmrc ## Function-specific npm configuration (if needed) │ │ ├── deno.json ## Function-specific Deno configuration │ │ └── index.ts ## Your function code ``` When you create a new Edge Function, it will use TypeScript by default. However, it is possible write Edge Function in JavaScript. Learn more about it in the [documentation](https://supabase.com/docs/guides/functions/quickstart#not-using-typescript). #### Setup imports Add the following imports to the `deno.json` file in the `supabase/functions/drizzle-tutorial` directory: ```json copy filename="supabase/functions/drizzle-tutorial/deno.json" { "imports": { "drizzle-orm/": "npm:/drizzle-orm/", "postgres": "npm:postgres" } } ``` You can read more about managing dependencies [here](https://supabase.com/docs/guides/functions/dependencies#managing-dependencies). #### Copy your schema to the functions directory Copy the code that you will use in your edge function from `src/schema.ts` file to the `supabase/functions/drizzle-tutorial/index.ts` file: ```typescript copy filename="supabase/functions/drizzle-tutorial/index.ts" // Setup type definitions for built-in Supabase Runtime APIs import "jsr:@supabase/functions-js/edge-runtime.d.ts" import { pgTable, serial, text, integer } from "drizzle-orm/pg-core"; const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull() }) Deno.serve(async (req) => { const { name } = await req.json() const data = { message: `Hello ${name}!`, } return new Response( JSON.stringify(data), { headers: { "Content-Type": "application/json" } }, ) }) ``` In the Deno ecosystem, each function should be treated as an independent project with its own set of dependencies and configurations. For these reasons, Supabase recommend maintaining separate configuration files (`deno.json`, `.npmrc`, or `import_map.json`) within each function's directory, even if it means duplicating some configurations. Read more [here](https://supabase.com/docs/guides/functions/dependencies#managing-dependencies). #### Connect Drizzle ORM to your database Update your edge function code with your database configuration: ```typescript copy filename="supabase/functions/drizzle-tutorial/index.ts" {14,17,18} // Setup type definitions for built-in Supabase Runtime APIs import { integer, pgTable, serial, text } from "drizzle-orm/pg-core"; import { drizzle } from "drizzle-orm/postgres-js"; import "jsr:@supabase/functions-js/edge-runtime.d.ts"; import postgres from "postgres"; const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull() }) Deno.serve(async () => { const connectionString = Deno.env.get("SUPABASE_DB_URL")!; // Disable prefetch as it is not supported for "Transaction" pool mode const client = postgres(connectionString, { prepare: false }); const db = drizzle({ client }); await db.insert(usersTable).values({ name: "Alice", age: 25 }) const data = await db.select().from(usersTable); return new Response( JSON.stringify(data) ) }) ``` `SUPABASE_DB_URL` is default environment variable for the direct database connection. Learn more about managing environment variables in Supabase Edge Functions in the [documentation](https://supabase.com/docs/guides/functions/secrets). #### Test your code locally Run the following command to test your function locally: ```bash copy supabase functions serve --no-verify-jwt ``` Navigate to the route `(e.g. /drizzle-tutorial)` in your browser: ```plaintext [ { "id": 1, "name": "Alice", "age": 25 } ] ``` #### Link your local project to a hosted Supabase project You can create new Supabase project in the [dashboard](https://supabase.com/dashboard) or by following this [link](https://database.new/). Copy the `Reference ID` from project settings and use it to link your local development project to a hosted Supabase project by running the following command: ```bash copy supabase link --project-ref= ``` Push your schema changes to the hosted Supabase project by running the following command: ```bash copy supabase db push ``` #### Setup environment variables You can find `Project connect details` by clicking **Connect** in the top bar of the dashboard and copy the URI from the `Transaction pooler` section. Remember to replace the password placeholder with your actual database password. Read more about Connection Pooler in the [documentation](https://supabase.com/docs/guides/database/connecting-to-postgres#connection-pooler). Update your edge function code to use the `DATABASE_URL` environment variable instead of `SUPABASE_DB_URL`: ```typescript copy filename="supabase/functions/drizzle-tutorial/index.ts" // imports // const connectionString = Deno.env.get("SUPABASE_DB_URL")!; const connectionString = Deno.env.get("DATABASE_URL")!; // code ``` Run the following command to set the environment variable: ```bash copy supabase secrets set DATABASE_URL= ``` Learn more about managing environment variables in Supabase Edge Functions in the [documentation](https://supabase.com/docs/guides/functions/secrets). #### Deploy your function Deploy your function by running the following command: ```bash copy supabase functions deploy drizzle-tutorial --no-verify-jwt ``` Finally, you can use URL of the deployed project and navigate to the route you created `(e.g. /drizzle-tutorial)` to access your edge function. Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-vercel-edge-functions import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from '@mdx/Npm.astro'; import Steps from '@mdx/Steps.astro'; import Section from "@mdx/Section.astro"; import Callout from "@mdx/Callout.astro"; This tutorial demonstrates how to use Drizzle ORM with [Vercel Functions](https://vercel.com/docs/functions) in [Edge runtime](https://vercel.com/docs/functions/runtimes/edge-runtime). - You should have the latest version of [Vercel CLI](https://vercel.com/docs/cli#) installed. -g vercel - You should have an existing Next.js project or create a new one using the following command: ```bash copy npx create-next-app@latest --typescript ``` - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit In case you face the issue with resolving dependencies during installation: If you're not using React Native, forcing the installation with `--force` or `--legacy-peer-deps` should resolve the issue. If you are using React Native, then you need to use the exact version of React which is compatible with your React Native version. ## Edge-compatible driver When using Drizzle ORM with Vercel Edge functions you have to use edge-compatible drivers because the functions run in [Edge runtime](https://vercel.com/docs/functions/runtimes/edge-runtime) not in Node.js runtime, so there are some limitations of standard Node.js APIs. You can choose one of these drivers according to your database dialect: - [Neon serverless driver](/docs/get-started-postgresql#neon) allows you to query your Neon Postgres databases from serverless and edge environments over HTTP or WebSockets in place of TCP. We recommend using this driver for connecting to `Neon Postgres`. - [Vercel Postgres driver](/docs/get-started-postgresql#vercel-postgres) is built on top of the `Neon serverless driver`. We recommend using this driver for connecting to `Vercel Postgres`. - [PlanetScale serverless driver](/docs/get-started-mysql#planetscale) allows you access any `MySQL` client and execute queries over an HTTP connection, which is generally not blocked by cloud providers. - [libSQL client](/docs/get-started-sqlite#turso) allows you to access [Turso](https://docs.turso.tech/introduction) database. ## Navigation - Navigate directly to the [Neon Postgres](/docs/tutorials/drizzle-with-vercel-edge-functions#neon-postgres) section. - Navigate directly to the [Vercel Postgres](/docs/tutorials/drizzle-with-vercel-edge-functions#vercel-postgres) section. - Navigate directly to the [PlanetScale](/docs/tutorials/drizzle-with-vercel-edge-functions#planetscale) section. - Navigate directly to the [Turso](/docs/tutorials/drizzle-with-vercel-edge-functions#turso) section. ### Neon Postgres #### Install the `@neondatabase/serverless` driver Install the `@neondatabase/serverless` driver: @neondatabase/serverless #### Create a table Create a `schema.ts` file in the `src/db` directory and declare a table schema: ```typescript copy filename="src/db/schema.ts" import { pgTable, serial, text } from "drizzle-orm/pg-core"; export const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: text('age').notNull(), email: text('email').notNull().unique(), }) ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { defineConfig } from "drizzle-kit"; export default defineConfig({ schema: "./src/db/schema.ts", dialect: "postgresql", dbCredentials: { url: process.env.POSTGRES_URL!, }, }); ``` Configure your database connection string in the `.env` file: ```plaintext filename=".env" POSTGRES_URL="postgres://[user]:[password]@[host]-[region].aws.neon.tech:5432/[db-name]?sslmode=[ssl-mode]" ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash copy npx drizzle-kit generate ``` These migrations are stored in the `drizzle` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE IF NOT EXISTS "users_table" ( "id" serial PRIMARY KEY NOT NULL, "name" text NOT NULL, "age" text NOT NULL, "email" text NOT NULL, CONSTRAINT "users_table_email_unique" UNIQUE("email") ); ``` Run migrations: ```bash copy npx drizzle-kit migrate ``` Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. #### Connect Drizzle ORM to your database Create a `index.ts` file in the `src/db` directory and set up your database configuration: ```typescript copy filename="src/db/index.ts" import { drizzle } from 'drizzle-orm/neon-serverless'; export const db = drizzle(process.env.POSTGRES_URL!) ``` #### Create an API route Create `route.ts` file in `src/app/api/hello` directory. To learn more about how to write a function, see the [Functions API Reference](https://vercel.com/docs/functions/functions-api-reference) and [Vercel Functions Quickstart](https://vercel.com/docs/functions/quickstart). ```ts copy filename="src/app/api/hello/route.ts" import { db } from "@/db"; import { usersTable } from "@/db/schema"; import { NextResponse } from "next/server"; export const dynamic = 'force-dynamic'; // static by default, unless reading the request export const runtime = 'edge' // specify the runtime to be edge export async function GET(request: Request) { const users = await db.select().from(usersTable) return NextResponse.json({ users, message: 'success' }); } ``` #### Test your code locally Run the `next dev` command to start your local development server: ```bash copy npx next dev ``` Navigate to the route you created `(e.g. /api/hello)` in your browser: ```plaintext { "users": [], "message": "success" } ``` #### Deploy your project Create a new project in the [dashboard](https://vercel.com/new) or run the `vercel` command to deploy your project: ```bash copy vercel ``` Add `POSTGRES_URL` environment variable: ```bash copy vercel env add POSTGRES_URL ``` Redeploy your project to update your environment variables: ```bash copy vercel ``` Finally, you can use URL of the deployed project and navigate to the route you created `(e.g. /api/hello)` to access your edge function. ### Vercel Postgres You can check quickstart guide for Drizzle with Vercel Postgres client in the [documentation](/docs/get-started-postgresql#vercel-postgres). #### Install the `@vercel/postgres` driver Install the `@vercel/postgres` driver: @vercel/postgres #### Create a table Create a `schema.ts` file in the `src/db` directory and declare a table schema: ```typescript copy filename="src/db/schema.ts" import { pgTable, serial, text } from "drizzle-orm/pg-core"; export const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: text('age').notNull(), email: text('email').notNull().unique(), }) ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { defineConfig } from "drizzle-kit"; export default defineConfig({ schema: "./src/db/schema.ts", dialect: "postgresql", dbCredentials: { url: process.env.POSTGRES_URL!, }, }); ``` Configure your database connection string in the `.env` file: ```plaintext filename=".env" POSTGRES_URL="postgres://[user]:[password]@[host]-[region].aws.neon.tech:5432/[db-name]?sslmode=[ssl-mode]" ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash copy npx drizzle-kit generate ``` These migrations are stored in the `drizzle` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE IF NOT EXISTS "users_table" ( "id" serial PRIMARY KEY NOT NULL, "name" text NOT NULL, "age" text NOT NULL, "email" text NOT NULL, CONSTRAINT "users_table_email_unique" UNIQUE("email") ); ``` Run migrations: ```bash copy npx drizzle-kit migrate ``` Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. #### Connect Drizzle ORM to your database Create a `index.ts` file in the `src/db` directory and set up your database configuration: ```typescript copy filename="src/db/index.ts" import { drizzle } from 'drizzle-orm/vercel-postgres'; export const db = drizzle() ``` #### Create an API route Create `route.ts` in `src/app/api/hello` directory. To learn more about how to write a function, see the [Functions API Reference](https://vercel.com/docs/functions/functions-api-reference) and [Vercel Functions Quickstart](https://vercel.com/docs/functions/quickstart). ```ts copy filename="src/app/api/hello/route.ts" import { db } from "@/db"; import { usersTable } from "@/db/schema"; import { NextResponse } from "next/server"; export const dynamic = 'force-dynamic'; // static by default, unless reading the request export const runtime = 'edge' // specify the runtime to be edge export async function GET(request: Request) { const users = await db.select().from(usersTable) return NextResponse.json({ users, message: 'success' }); } ``` #### Test your code locally Run the `next dev` command to start your local development server: ```bash copy npx next dev ``` Navigate to the route you created `(e.g. /api/hello)` in your browser: ```plaintext { "users": [], "message": "success" } ``` #### Deploy your project Create a new project in the [dashboard](https://vercel.com/new) or run the `vercel` command to deploy your project: ```bash copy vercel ``` Add `POSTGRES_URL` environment variable: ```bash copy vercel env add POSTGRES_URL ``` Redeploy your project to update your environment variables: ```bash copy vercel ``` Finally, you can use URL of the deployed project and navigate to the route you created `(e.g. /api/hello)` to access your edge function. ### PlanetScale In this tutorial we use [PlanetScale MySQL](https://planetscale.com/). #### Install the `@planetscale/database` driver Install the `@planetscale/database` driver: @planetscale/database #### Create a table Create a `schema.ts` file in the `src/db` directory and declare a table schema: ```typescript copy filename="src/db/schema.ts" import { mysqlTable, serial, text } from "drizzle-orm/mysql-core"; export const usersTable = mysqlTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: text('age').notNull(), email: text('email').notNull().unique(), }) ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { defineConfig } from "drizzle-kit"; export default defineConfig({ schema: "./src/db/schema.ts", dialect: "mysql", dbCredentials: { url: process.env.MYSQL_URL!, }, }); ``` Configure your database connection string in the `.env` file: ```plaintext filename=".env" MYSQL_URL="mysql://[user]:[password]@[host].[region].psdb.cloud/[db-name]?ssl={'rejectUnauthorized':[ssl-rejectUnauthorized]}" ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash copy npx drizzle-kit generate ``` These migrations are stored in the `drizzle` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE `users_table` ( `id` serial AUTO_INCREMENT NOT NULL, `name` text NOT NULL, `age` text NOT NULL, `email` text NOT NULL, CONSTRAINT `users_table_id` PRIMARY KEY(`id`), CONSTRAINT `users_table_email_unique` UNIQUE(`email`) ); ``` Run migrations: ```bash copy npx drizzle-kit migrate ``` Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. #### Connect Drizzle ORM to your database Create a `index.ts` file in the `src/db` directory and set up your database configuration: ```typescript copy filename="src/db/index.ts" import { drizzle } from "drizzle-orm/planetscale-serverless"; export const db = drizzle(process.env.MYSQL_URL!) ``` #### Create an API route Create `route.ts` in `src/app/api/hello` directory. To learn more about how to write a function, see the [Functions API Reference](https://vercel.com/docs/functions/functions-api-reference) and [Vercel Functions Quickstart](https://vercel.com/docs/functions/quickstart). ```ts copy filename="src/app/api/hello/route.ts" import { db } from "@/app/db/db"; import { usersTable } from "@/app/db/schema"; import { NextResponse } from "next/server"; export const dynamic = 'force-dynamic'; // static by default, unless reading the request export const runtime = 'edge' // specify the runtime to be edge export async function GET(request: Request) { const users = await db.select().from(usersTable) return NextResponse.json({ users, message: 'success' }); } ``` #### Test your code locally Run the `next dev` command to start your local development server: ```bash copy npx next dev ``` Navigate to the route you created `(e.g. /api/hello)` in your browser: ```plaintext { "users": [], "message": "success" } ``` #### Deploy your project Create a new project in the [dashboard](https://vercel.com/new) or run the `vercel` command to deploy your project: ```bash copy vercel ``` Add `MYSQL_URL` environment variable: ```bash copy vercel env add MYSQL_URL ``` Redeploy your project to update your environment variables: ```bash copy vercel ``` Finally, you can use URL of the deployed project and navigate to the route you created `(e.g. /api/hello)` to access your edge function. ### Turso You can check [quickstart guide](/docs/get-started-sqlite#turso) or [tutorial](/docs/tutorials/drizzle-with-turso) for Drizzle with Turso in the documentation. #### Install the `@libsql/client` driver Install the `@libsql/client` driver: @libsql/client #### Create a table Create a `schema.ts` file in the `src/db` directory and declare a table schema: ```typescript copy filename="src/db/schema.ts" import { integer, sqliteTable, text } from "drizzle-orm/sqlite-core"; export const usersTable = sqliteTable('users_table', { id: integer('id').primaryKey(), name: text('name').notNull(), age: text('age').notNull(), email: text('email').notNull().unique(), }) ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { defineConfig } from "drizzle-kit"; export default defineConfig({ schema: "./src/db/schema.ts", dialect: "turso", dbCredentials: { url: process.env.TURSO_CONNECTION_URL!, authToken: process.env.TURSO_AUTH_TOKEN!, }, }); ``` Configure your database connection string and auth token in the `.env` file: ```plaintext filename=".env" TURSO_CONNECTION_URL="libsql://[db-name].turso.io" TURSO_AUTH_TOKEN="[auth-token]" ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash copy npx drizzle-kit generate ``` These migrations are stored in the `drizzle` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE `users_table` ( `id` integer PRIMARY KEY NOT NULL, `name` text NOT NULL, `age` text NOT NULL, `email` text NOT NULL ); --> statement-breakpoint CREATE UNIQUE INDEX `users_table_email_unique` ON `users_table` (`email`); ``` Run migrations: ```bash copy npx drizzle-kit migrate ``` Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. #### Connect Drizzle ORM to your database Create a `index.ts` file in the `src/db` directory and set up your database configuration: ```typescript copy filename="src/db/index.ts" import { drizzle } from 'drizzle-orm/libsql'; export const db = drizzle({ connection: { url: process.env.TURSO_CONNECTION_URL!, authToken: process.env.TURSO_AUTH_TOKEN!, }}) ``` #### Create an API route Create `route.ts` in `src/app/api/hello` directory. To learn more about how to write a function, see the [Functions API Reference](https://vercel.com/docs/functions/functions-api-reference) and [Vercel Functions Quickstart](https://vercel.com/docs/functions/quickstart). ```ts copy filename="src/app/api/hello/route.ts" import { db } from "@/app/db/db"; import { usersTable } from "@/app/db/schema"; import { NextResponse } from "next/server"; export const dynamic = 'force-dynamic'; // static by default, unless reading the request export const runtime = 'edge' // specify the runtime to be edge export async function GET(request: Request) { const users = await db.select().from(usersTable) return NextResponse.json({ users, message: 'success' }); } ``` #### Test your code locally Run the `next dev` command to start your local development server: ```bash copy npx next dev ``` Navigate to the route you created `(e.g. /api/hello)` in your browser: ```plaintext { "users": [], "message": "success" } ``` #### Deploy your project Create a new project in the [dashboard](https://vercel.com/new) or run the `vercel` command to deploy your project: ```bash copy vercel ``` Add `TURSO_CONNECTION_URL` environment variable: ```bash copy vercel env add TURSO_CONNECTION_URL ``` Add `TURSO_AUTH_TOKEN` environment variable: ```bash copy vercel env add TURSO_AUTH_TOKEN ``` Redeploy your project to update your environment variables: ```bash copy vercel ``` Finally, you can use URL of the deployed project and navigate to the route you created `(e.g. /api/hello)` to access your edge function. Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-neon import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from "@mdx/Npm.astro"; import Steps from "@mdx/Steps.astro"; import Section from "@mdx/Section.astro"; import Callout from "@mdx/Callout.astro"; This tutorial demonstrates how to use Drizzle ORM with [Neon Postgres](https://neon.tech/) database. If you do not have an existing Neon account, sign up [here](https://neon.tech). - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should also install the [Neon serverless driver](https://neon.tech/docs/serverless/serverless-driver). @neondatabase/serverless - You should have installed the `dotenv` package for managing environment variables. dotenv ## Setup Neon and Drizzle ORM #### Create a new Neon project Log in to the [Neon Console](https://console.neon.tech/app/projects) and navigate to the Projects section. Select a project or click the `New Project` button to create a new one. Your Neon projects come with a ready-to-use Postgres database named `neondb`. We'll use it in this tutorial. #### Setup connection string variable Navigate to the **Connection Details** section in the project console to find your database connection string. It should look similar to this: ```bash postgres://username:password@ep-cool-darkness-123456.us-east-2.aws.neon.tech/neondb ``` Add the `DATABASE_URL` environment variable to your `.env` or `.env.local` file, which you'll use to connect to the Neon database. ```text copy DATABASE_URL=NEON_DATABASE_CONNECTION_STRING ``` #### Connect Drizzle ORM to your database Create a `db.ts` file and set up your database configuration: ```typescript copy filename="src/db.ts" import { drizzle } from "drizzle-orm/neon-http"; import { neon } from "@neondatabase/serverless"; import { config } from "dotenv"; config({ path: ".env" }); // or .env.local const sql = neon(process.env.DATABASE_URL!); export const db = drizzle({ client: sql }); ``` #### Create tables Create a `schema.ts` file and declare your tables: ```typescript copy filename="src/schema.ts" import { integer, pgTable, serial, text, timestamp } from 'drizzle-orm/pg-core'; export const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull(), email: text('email').notNull().unique(), }); export const postsTable = pgTable('posts_table', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), userId: integer('user_id') .notNull() .references(() => usersTable.id, { onDelete: 'cascade' }), createdAt: timestamp('created_at').notNull().defaultNow(), updatedAt: timestamp('updated_at') .notNull() .$onUpdate(() => new Date()), }); export type InsertUser = typeof usersTable.$inferInsert; export type SelectUser = typeof usersTable.$inferSelect; export type InsertPost = typeof postsTable.$inferInsert; export type SelectPost = typeof postsTable.$inferSelect; ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { config } from 'dotenv'; import { defineConfig } from "drizzle-kit"; config({ path: '.env' }); export default defineConfig({ schema: "./src/schema.ts", out: "./migrations", dialect: "postgresql", dbCredentials: { url: process.env.DATABASE_URL!, }, }); ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash copy npx drizzle-kit generate ``` These migrations are stored in the `drizzle/migrations` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE IF NOT EXISTS "posts_table" ( "id" serial PRIMARY KEY NOT NULL, "title" text NOT NULL, "content" text NOT NULL, "user_id" integer NOT NULL, "created_at" timestamp DEFAULT now() NOT NULL, "updated_at" timestamp NOT NULL ); --> statement-breakpoint CREATE TABLE IF NOT EXISTS "users_table" ( "id" serial PRIMARY KEY NOT NULL, "name" text NOT NULL, "age" integer NOT NULL, "email" text NOT NULL, CONSTRAINT "users_table_email_unique" UNIQUE("email") ); --> statement-breakpoint DO $$ BEGIN ALTER TABLE "posts_table" ADD CONSTRAINT "posts_table_user_id_users_table_id_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users_table"("id") ON DELETE cascade ON UPDATE no action; EXCEPTION WHEN duplicate_object THEN null; END $$; ``` Run migrations: ```bash copy npx drizzle-kit migrate ``` Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. ### Basic file structure This is the basic file structure of the project. In the `src/db` directory, we have database-related files including connection in `db.ts`, schema definitions in `schema.ts`, and a migration script in `migrate.ts` file which is responsible for applying migrations that stored in the `migrations` directory. ```plaintext 📦 ├ 📂 src │ ├ 📜 db.ts │ └ 📜 schema.ts ├ 📂 migrations │ ├ 📂 meta │ │ ├ 📜 _journal.json │ │ └ 📜 0000_snapshot.json │ └ 📜 0000_dry_richard_fisk.sql ├ 📜 .env ├ 📜 drizzle.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ## Query examples For instance, we create `src/queries` folder and separate files for each operation: insert, select, update, delete. #### Insert data Read more about insert query in the [documentation](/docs/insert). ```typescript copy filename="src/queries/insert.ts" {4, 8} import { db } from '../db'; import { InsertPost, InsertUser, postsTable, usersTable } from '../schema'; export async function createUser(data: InsertUser) { await db.insert(usersTable).values(data); } export async function createPost(data: InsertPost) { await db.insert(postsTable).values(data); } ``` #### Select data Read more about select query in the [documentation](/docs/select). ```typescript copy filename="src/queries/select.ts" {5, 16, 41} import { asc, between, count, eq, getTableColumns, sql } from 'drizzle-orm'; import { db } from '../db'; import { SelectUser, usersTable, postsTable } from '../schema'; export async function getUserById(id: SelectUser['id']): Promise< Array<{ id: number; name: string; age: number; email: string; }> > { return db.select().from(usersTable).where(eq(usersTable.id, id)); } export async function getUsersWithPostsCount( page = 1, pageSize = 5, ): Promise< Array<{ postsCount: number; id: number; name: string; age: number; email: string; }> > { return db .select({ ...getTableColumns(usersTable), postsCount: count(postsTable.id), }) .from(usersTable) .leftJoin(postsTable, eq(usersTable.id, postsTable.userId)) .groupBy(usersTable.id) .orderBy(asc(usersTable.id)) .limit(pageSize) .offset((page - 1) * pageSize); } export async function getPostsForLast24Hours( page = 1, pageSize = 5, ): Promise< Array<{ id: number; title: string; }> > { return db .select({ id: postsTable.id, title: postsTable.title, }) .from(postsTable) .where(between(postsTable.createdAt, sql`now() - interval '1 day'`, sql`now()`)) .orderBy(asc(postsTable.title), asc(postsTable.id)) .limit(pageSize) .offset((page - 1) * pageSize); } ``` Alternatively, you can use [relational query syntax](/docs/rqb). #### Update data Read more about update query in the [documentation](/docs/update). ```typescript copy filename="src/queries/update.ts" {5} import { eq } from 'drizzle-orm'; import { db } from '../db'; import { SelectPost, postsTable } from '../schema'; export async function updatePost(id: SelectPost['id'], data: Partial>) { await db.update(postsTable).set(data).where(eq(postsTable.id, id)); } ``` #### Delete data Read more about delete query in the [documentation](/docs/delete). ```typescript copy filename="src/queries/delete.ts" {5} import { db } from '../db'; import { eq } from 'drizzle-orm'; import { SelectUser, usersTable } from '../schema'; export async function deleteUser(id: SelectUser['id']) { await db.delete(usersTable).where(eq(usersTable.id, id)); } ``` Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-nile import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from '@mdx/Npm.astro'; import Steps from '@mdx/Steps.astro'; import Section from "@mdx/Section.astro"; import Callout from '@mdx/Callout.astro'; import TransferCode from '@mdx/get-started/TransferCode.mdx'; import ApplyChanges from '@mdx/get-started/ApplyChanges.mdx'; import RunFile from '@mdx/get-started/RunFile.mdx'; This tutorial demonstrates how to use Drizzle ORM with [Nile Database](https://thenile.dev). Nile is Postgres, re-engineered for multi-tenant applications. This tutorial will demonstrate how to use Drizzle with Nile's virtual tenant databases to developer a secure, scalable, multi-tenant application. We'll walk through building this example application step-by-step. If you want to peek at the complete example, you can take a look at its [Github repository](https://github.com/niledatabase/niledatabase/tree/main/examples/quickstart/drizzle). - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should have installed `dotenv` package for managing environment variables. Read more about this package [here](https://www.npmjs.com/package/dotenv) dotenv - You should have installed `node-postgres` package for connecting to the Postgres database. Read more about this package [here](https://www.npmjs.com/package/node-postgres) node-postgres - You should have installed `express` package for the web framework. Read more about express [here](https://expressjs.com/) express - This guide uses [AsyncLocalStorage](https://nodejs.org/api/async_context.html) to manage the tenant context. If your framework or runtime does not support `AsyncLocalStorage`, you can refer to [Drizzle\<\>Nile](../connect-nile) doc for alternative options. ## Setup Nile and Drizzle ORM #### Signup to Nile and create a database If you haven't already, sign up to [Nile](https://console.thenile.dev) and follow the app instructions to create a new database. #### Get database connection string On the left side-bar menu, select the "Settings" option, click on the Postgres logo, and click "generate credentials". Copy the connection string and add it to the `.env` file in your project: ```plaintext copy NILEDB_URL=postgres://youruser:yourpassword@us-west-2.db.thenile.dev:5432:5432/your_db_name ``` #### Connect Drizzle ORM to your database Create a `db.ts` file in the `src/db` directory and set up your database configuration: ```typescript copy filename="src/db/db.ts" import { drizzle } from 'drizzle-orm/node-postgres'; import dotenv from "dotenv/config"; import { sql } from "drizzle-orm"; import { AsyncLocalStorage } from "async_hooks"; export const db = drizzle(process.env.NILEDB_URL); export const tenantContext = new AsyncLocalStorage(); export function tenantDB(cb: (tx: any) => T | Promise): Promise { return db.transaction(async (tx) => { const tenantId = tenantContext.getStore(); console.log("executing query with tenant: " + tenantId); // if there's a tenant ID, set it in the transaction context if (tenantId) { await tx.execute(sql`set local nile.tenant_id = '${sql.raw(tenantId)}'`); } return cb(tx); }) as Promise; } ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import 'dotenv/config'; import { defineConfig } from 'drizzle-kit'; export default defineConfig({ out: './drizzle', schema: './src/db/schema.ts', dialect: 'postgresql', dbCredentials: { url: process.env.NILEDB_URL!, }, }); ``` #### Introspect Nile database Nile databases have built-in tables. The most important of these is the `tenants` table, which is used to create and manage tenants. In order to use this table from our application, we'll use Drizzle Kit CLI to generate a schema file that includes this schema. ```bash copy npx drizzle-kit pull ``` The result of introspection will be a `schema.ts` file, `meta` folder with snapshots of your database schema, sql file with the migration and `relations.ts` file for [relational queries](/docs/rqb). Here is an example of the generated `schema.ts` file: ```typescript copy filename="src/db/schema.ts" // table schema generated by introspection import { pgTable, uuid, text, timestamp, varchar, vector, boolean } from "drizzle-orm/pg-core" import { sql } from "drizzle-orm" export const tenants = pgTable("tenants", { id: uuid().default(sql`public.uuid_generate_v7()`).primaryKey().notNull(), name: text(), created: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), updated: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), deleted: timestamp({ mode: 'string' }), }); ``` #### Create additional tables In addition to the built-in tables, our application will need some tables to store its data. We will add them to `src/db/schema.ts` that we previously generated, so this file will look like this: ```typescript copy filename="src/db/schema.ts" // table schema generated by introspection import { pgTable, uuid, text, timestamp, varchar, vector, boolean } from "drizzle-orm/pg-core" import { sql } from "drizzle-orm" export const tenants = pgTable("tenants", { id: uuid().default(sql`public.uuid_generate_v7()`).primaryKey().notNull(), name: text(), created: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), updated: timestamp({ mode: 'string' }).default(sql`LOCALTIMESTAMP`).notNull(), deleted: timestamp({ mode: 'string' }), }); export const todos = pgTable("todos", { id: uuid().defaultRandom(), tenantId: uuid("tenant_id"), title: varchar({ length: 256 }), estimate: varchar({ length: 256 }), embedding: vector({ dimensions: 3 }), complete: boolean(), }); ``` #### Apply changes to the database #### Initialize the webapp Now that we have set up Drizzle to connect to Nile and we have our schema in place, we can use them in a multi-tenant web application. We are using Express as the web framework in this example, although Nile and Drizzle can be used from any web framework. To keep the example simple, we'll implement the webapp in a single file - `src/app.ts`. We'll start by initializing the webapp: ```typescript copy filename="src/app.ts" import express from "express"; import { tenantDB, tenantContext, db } from "./db/db"; import { tenants as tenantSchema, todos as todoSchema, } from "./db/schema"; import { eq } from "drizzle-orm"; const PORT = process.env.PORT || 3001; const app = express(); app.listen(PORT, () => console.log(`Server is running on port ${PORT}`)); app.use(express.json()); ``` #### Initialize the tenant-aware middleware Next, we'll add middleware to the example. This middleware grabs the tenant ID from the path parameters and stores it in the `AsyncLocalStorage`. The `tenantDB` wrapper that we created in `src/db/index.ts` uses this tenant ID to set `nile.tenant_id` when executing queries, which then guarantees that the queries will execute against this tenant's virtual database. ```typescript copy filename="src/app.ts" // set the tenant ID in the context based on the URL parameter app.use('/api/tenants/:tenantId/*', (req, res, next) => { const tenantId = req.params.tenantId; console.log("setting context to tenant: " + tenantId); tenantContext.run(tenantId, next); }); ``` The example gets the tenant ID from path parameter, but it is also common to set the tenant ID in a header such as `x-tenant-id` or in a cookie. #### Add routes Lastly, we need to add some routes for creating and listing tenants and todos. Note how we are using `tenantDB` wrapper to connect to the tenant's virtual database. Also note how in `app.get("/api/tenants/:tenantId/todos"` we did not need to specify `where tenant_id=...` in the query. This is exactly because we are routed to that tenant's database and the query cannot return data for any other tenant. ```typescript copy filename="src/app.ts" {6,20,39,58,62,75,83} // create new tenant app.post("/api/tenants", async (req, res) => { try { const name = req.body.name; var tenants: any = null; tenants = await tenantDB(async (tx) => { return await tx.insert(tenantSchema).values({ name }).returning(); }); res.json(tenants); } catch (error: any) { console.log("error creating tenant: " + error.message); res.status(500).json({message: "Internal Server Error",}); } }); // return list of tenants app.get("/api/tenants", async (req, res) => { let tenants: any = []; try { tenants = await tenantDB(async (tx) => { return await tx.select().from(tenantSchema); }); res.json(tenants); } catch (error: any) { console.log("error listing tenants: " + error.message); res.status(500).json({message: "Internal Server Error",}); } }); // add new task for tenant app.post("/api/tenants/:tenantId/todos", async (req, res) => { try { const { title, complete } = req.body; if (!title) { res.status(400).json({message: "No task title provided",}); } const tenantId = req.params.tenantId; const newTodo = await tenantDB(async (tx) => { return await tx .insert(todoSchema) .values({ tenantId, title, complete }) .returning(); }); // return without the embedding vector, since it is huge and useless res.json(newTodo); } catch (error: any) { console.log("error adding task: " + error.message); res.status(500).json({message: "Internal Server Error",}); } }); // update tasks for tenant // No need for where clause because we have the tenant in the context app.put("/api/tenants/:tenantId/todos", async (req, res) => { try { const { id, complete } = req.body; await tenantDB(async (tx) => { return await tx .update(todoSchema) .set({ complete }) .where(eq(todoSchema.id, id)); }); res.sendStatus(200); } catch (error: any) { console.log("error updating tasks: " + error.message); res.status(500).json({message: "Internal Server Error",}); } }); // get all tasks for tenant app.get("/api/tenants/:tenantId/todos", async (req, res) => { try { // No need for a "where" clause here because we are setting the tenant ID in the context const todos = await tenantDB(async (tx) => { return await tx .select({ id: todoSchema.id, tenant_id: todoSchema.tenantId, title: todoSchema.title, estimate: todoSchema.estimate, }) .from(todoSchema); }); res.json(todos); } catch (error: any) { console.log("error listing tasks: " + error.message); res.status(500).json({message: error.message,}); } }); ``` #### Try it out! You can now run your new web application: ```bash copy npx tsx src/app.ts ``` and use `curl` to try the routes you just created: ```bash # create a tenant curl --location --request POST 'localhost:3001/api/tenants' \ --header 'Content-Type: application/json' \ --data-raw '{"name":"my first customer"}' # get tenants curl -X GET 'http://localhost:3001/api/tenants' # create a todo (don't forget to use a real tenant-id in the URL) curl -X POST \ 'http://localhost:3001/api/tenants/108124a5-2e34-418a-9735-b93082e9fbf2/todos' \ --header 'Content-Type: application/json' \ --data-raw '{"title": "feed the cat", "complete": false}' # list todos for tenant (don't forget to use a real tenant-id in the URL) curl -X GET \ 'http://localhost:3001/api/tenants/108124a5-2e34-418a-9735-b93082e9fbf2/todos' ``` ## Project file structure This is the file structure of the project. In the `src/db` directory, we have database-related files including connection in `db.ts` and schema definitions in `schema.ts`. The files generated by the migrations and introspections are in `./drizzle` ```plaintext 📦 ├ 📂 src │ ├ 📂 db │ │ ├ 📜 db.ts │ │ └ 📜 schema.ts │ └ 📜 app.ts ├ 📂 drizzle │ ├ 📂 meta │ │ ├ 📜 _journal.json │ │ └ 📜 0000_snapshot.json │ ├ 📜 relations.ts │ ├ 📜 schema.ts │ └ 📜 0000_watery_spencer_smythe.sql ├ 📜 .env ├ 📜 drizzle.config.ts └ 📜 package.json ``` Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-supabase import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from '@mdx/Npm.astro'; import Steps from '@mdx/Steps.astro'; import Section from "@mdx/Section.astro"; import Callout from '@mdx/Callout.astro'; This tutorial demonstrates how to use Drizzle ORM with [Supabase Database](https://supabase.com/docs/guides/database/overview). Every Supabase project comes with a full [Postgres](https://www.postgresql.org/) database. - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should have installed `dotenv` package for managing environment variables. Read more about this package [here](https://www.npmjs.com/package/dotenv) dotenv - You should have installed `postgres` package for connecting to the Postgres database. Read more about this package [here](https://www.npmjs.com/package/postgres) postgres - You should have the latest version of [Supabase CLI](https://supabase.com/docs/guides/cli/getting-started#installing-the-supabase-cli) installed (Only if you want to use the Supabase CLI for migrations) Check [Supabase documentation](https://supabase.com/docs/guides/database/connecting-to-postgres#connecting-with-drizzle) to learn how to connect to the database with Drizzle ORM. ## Setup Supabase and Drizzle ORM #### Create a new Supabase project You can create new Supabase project in the [dashboard](https://supabase.com/dashboard) or by following this [link](https://database.new/). #### Setup connection string variable Navigate to [Database Settings](https://supabase.com/dashboard/project/_/settings/database) and copy the URI from the `Connection String` section. Make sure to use `connection pooling`. Remember to replace the password placeholder with your actual database password. Add `DATABASE_URL` variable to your `.env` or `.env.local` file. ```plaintext copy DATABASE_URL= ``` Read more about Connection Pooler and pooling modes in the [documentation](https://supabase.com/docs/guides/database/connecting-to-postgres#connection-pooler). #### Connect Drizzle ORM to your database Create a `index.ts` file in the `src/db` directory and set up your database configuration: ```typescript copy filename="src/db/index.ts" import { config } from 'dotenv'; import { drizzle } from 'drizzle-orm/postgres-js'; import postgres from 'postgres'; config({ path: '.env' }); // or .env.local const client = postgres(process.env.DATABASE_URL!); export const db = drizzle({ client }); ``` #### Create tables Create a `schema.ts` file in the `src/db` directory and declare your tables: ```typescript copy filename="src/db/schema.ts" import { integer, pgTable, serial, text, timestamp } from 'drizzle-orm/pg-core'; export const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull(), email: text('email').notNull().unique(), }); export const postsTable = pgTable('posts_table', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), userId: integer('user_id') .notNull() .references(() => usersTable.id, { onDelete: 'cascade' }), createdAt: timestamp('created_at').notNull().defaultNow(), updatedAt: timestamp('updated_at') .notNull() .$onUpdate(() => new Date()), }); export type InsertUser = typeof usersTable.$inferInsert; export type SelectUser = typeof usersTable.$inferSelect; export type InsertPost = typeof postsTable.$inferInsert; export type SelectPost = typeof postsTable.$inferSelect; ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { config } from 'dotenv'; import { defineConfig } from 'drizzle-kit'; config({ path: '.env' }); export default defineConfig({ schema: './src/db/schema.ts', out: './supabase/migrations', dialect: 'postgresql', dbCredentials: { url: process.env.DATABASE_URL!, }, }); ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash copy npx drizzle-kit generate ``` These migrations are stored in the `supabase/migrations` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE IF NOT EXISTS "posts_table" ( "id" serial PRIMARY KEY NOT NULL, "title" text NOT NULL, "content" text NOT NULL, "user_id" integer NOT NULL, "created_at" timestamp DEFAULT now() NOT NULL, "updated_at" timestamp NOT NULL ); --> statement-breakpoint CREATE TABLE IF NOT EXISTS "users_table" ( "id" serial PRIMARY KEY NOT NULL, "name" text NOT NULL, "age" integer NOT NULL, "email" text NOT NULL, CONSTRAINT "users_table_email_unique" UNIQUE("email") ); --> statement-breakpoint DO $$ BEGIN ALTER TABLE "posts_table" ADD CONSTRAINT "posts_table_user_id_users_table_id_fk" FOREIGN KEY ("user_id") REFERENCES "users_table"("id") ON DELETE cascade ON UPDATE no action; EXCEPTION WHEN duplicate_object THEN null; END $$; ``` Run migrations: ```bash copy npx drizzle-kit migrate ``` Learn more about [migration process](/docs/migrations). You can also apply migrations using [Supabase CLI](https://supabase.com/docs/guides/cli/getting-started): - For tables that already exist, manually review the generated migration files from `npx drizzle-kit generate` and comment out or adjust any unsafe pure create statements (e.g., `CREATE SCHEMA "auth";`) while ensuring safe conditional creates (e.g., `CREATE TABLE IF NOT EXISTS "auth"."users"`) are properly handled. Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. To apply migrations using the Supabase CLI you should follow these steps: Generate migrations using Drizzle Kit: ```bash copy npx drizzle-kit generate ``` Initialize the local Supabase project: ```bash copy supabase init ``` Link it to your remote project: ```bash copy supabase link ``` Push changes to the database: ```bash copy supabase db push ``` ## Basic file structure This is the basic file structure of the project. In the `src/db` directory, we have database-related files including connection in `index.ts` and schema definitions in `schema.ts`. ```plaintext 📦 ├ 📂 src │ ├ 📂 db │ │ ├ 📜 index.ts │ │ └ 📜 schema.ts ├ 📂 supabase │ ├ 📂 migrations │ │ ├ 📂 meta │ │ │ ├ 📜 _journal.json │ │ │ └ 📜 0000_snapshot.json │ │ └ 📜 0000_watery_spencer_smythe.sql │ └ 📜 config.toml ├ 📜 .env ├ 📜 drizzle.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ## Query examples For instance, we create `src/db/queries` folder and separate files for each operation: insert, select, update, delete. #### Insert data Read more about insert query in the [documentation](/docs/insert). ```typescript copy filename="src/db/queries/insert.ts" {4, 8} import { db } from '../index'; import { InsertPost, InsertUser, postsTable, usersTable } from '../schema'; export async function createUser(data: InsertUser) { await db.insert(usersTable).values(data); } export async function createPost(data: InsertPost) { await db.insert(postsTable).values(data); } ``` #### Select data Read more about select query in the [documentation](/docs/select). ```typescript copy filename="src/db/queries/select.ts" {5, 16, 41} import { asc, between, count, eq, getTableColumns, sql } from 'drizzle-orm'; import { db } from '../index'; import { SelectUser, postsTable, usersTable } from '../schema'; export async function getUserById(id: SelectUser['id']): Promise< Array<{ id: number; name: string; age: number; email: string; }> > { return db.select().from(usersTable).where(eq(usersTable.id, id)); } export async function getUsersWithPostsCount( page = 1, pageSize = 5, ): Promise< Array<{ postsCount: number; id: number; name: string; age: number; email: string; }> > { return db .select({ ...getTableColumns(usersTable), postsCount: count(postsTable.id), }) .from(usersTable) .leftJoin(postsTable, eq(usersTable.id, postsTable.userId)) .groupBy(usersTable.id) .orderBy(asc(usersTable.id)) .limit(pageSize) .offset((page - 1) * pageSize); } export async function getPostsForLast24Hours( page = 1, pageSize = 5, ): Promise< Array<{ id: number; title: string; }> > { return db .select({ id: postsTable.id, title: postsTable.title, }) .from(postsTable) .where(between(postsTable.createdAt, sql`now() - interval '1 day'`, sql`now()`)) .orderBy(asc(postsTable.title), asc(postsTable.id)) .limit(pageSize) .offset((page - 1) * pageSize); } ``` Alternatively, you can use [relational query syntax](/docs/rqb). #### Update data Read more about update query in the [documentation](/docs/update). ```typescript copy filename="src/db/queries/update.ts" {5} import { eq } from 'drizzle-orm'; import { db } from '../index'; import { SelectPost, postsTable } from '../schema'; export async function updatePost(id: SelectPost['id'], data: Partial>) { await db.update(postsTable).set(data).where(eq(postsTable.id, id)); } ``` #### Delete data Read more about delete query in the [documentation](/docs/delete). ```typescript copy filename="src/db/queries/delete.ts" {5} import { eq } from 'drizzle-orm'; import { db } from '../index'; import { SelectUser, usersTable } from '../schema'; export async function deleteUser(id: SelectUser['id']) { await db.delete(usersTable).where(eq(usersTable.id, id)); } ``` Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-turso import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from '@mdx/Npm.astro'; import Steps from '@mdx/Steps.astro'; import Section from "@mdx/Section.astro"; import Callout from '@mdx/Callout.astro'; This tutorial demonstrates how to use Drizzle ORM with [Turso](https://docs.turso.tech/introduction). - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should have installed `dotenv` package for managing environment variables. Read more about this package [here](https://www.npmjs.com/package/dotenv) dotenv - You should have installed `@libsql/client` package. Read more about this package [here](https://www.npmjs.com/package/@libsql/client). @libsql/client - You should have installed Turso CLI. Check [documentation](https://docs.turso.tech/cli/introduction) for more information [Turso](https://docs.turso.tech/concepts) is a SQLite-compatible database built on [libSQL](https://docs.turso.tech/libsql), the Open Contribution fork of SQLite. It enables scaling to hundreds of thousands of databases per organization and supports replication to any location, including your own servers, for microsecond-latency access. You can read more about Turso’s concepts [here](https://docs.turso.tech/concepts). Drizzle ORM natively supports libSQL driver, we embrace SQL dialects and dialect specific drivers and syntax and mirror most popular SQLite-like `all`, `get`, `values` and `run` query methods syntax. Check [official documentation](https://docs.turso.tech/quickstart) to setup Turso database. ## Setup Turso and Drizzle ORM #### Signup or login to Turso Signup: ```bash copy turso auth signup ``` Login: ```bash copy turso auth login ``` #### Create new database Create new database by running the `turso db create ` command: ```bash copy turso db create drizzle-turso-db ``` To see information about the database, run the following command: ```bash copy turso db show drizzle-turso-db ``` #### Create an authentication token To create an authentication token for your database, run the following command: ```bash copy turso db tokens create drizzle-turso-db ``` Learn more about this command and its options in the [documentation](https://docs.turso.tech/cli/db/tokens/create). #### Update environment variables Update your `.env` or `.env.local` file with connection url and authentication token. ```text copy TURSO_CONNECTION_URL= TURSO_AUTH_TOKEN= ``` #### Connect Drizzle ORM to your database Create a `index.ts` file in the `src/db` directory and set up your database configuration: ```typescript copy filename="src/db/index.ts" import { config } from 'dotenv'; import { drizzle } from 'drizzle-orm/libsql'; config({ path: '.env' }); // or .env.local export const db = drizzle({ connection: { url: process.env.TURSO_CONNECTION_URL!, authToken: process.env.TURSO_AUTH_TOKEN!, }}); ``` #### Create tables Create a `schema.ts` file in the `src/db` directory and declare your tables: ```typescript copy filename="src/db/schema.ts" import { sql } from 'drizzle-orm'; import { integer, sqliteTable, text } from 'drizzle-orm/sqlite-core'; export const usersTable = sqliteTable('users', { id: integer('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull(), email: text('email').unique().notNull(), }); export const postsTable = sqliteTable('posts', { id: integer('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), userId: integer('user_id') .notNull() .references(() => usersTable.id, { onDelete: 'cascade' }), createdAt: text('created_at') .default(sql`(CURRENT_TIMESTAMP)`) .notNull(), updateAt: integer('updated_at', { mode: 'timestamp' }).$onUpdate(() => new Date()), }); export type InsertUser = typeof usersTable.$inferInsert; export type SelectUser = typeof usersTable.$inferSelect; export type InsertPost = typeof postsTable.$inferInsert; export type SelectPost = typeof postsTable.$inferSelect; ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { config } from 'dotenv'; import { defineConfig } from 'drizzle-kit'; config({ path: '.env' }); export default defineConfig({ schema: './src/db/schema.ts', out: './migrations', dialect: 'turso', dbCredentials: { url: process.env.TURSO_CONNECTION_URL!, authToken: process.env.TURSO_AUTH_TOKEN!, }, }); ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash copy npx drizzle-kit generate ``` These migrations are stored in the `migrations` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE `posts` ( `id` integer PRIMARY KEY NOT NULL, `title` text NOT NULL, `content` text NOT NULL, `user_id` integer NOT NULL, `created_at` text DEFAULT (CURRENT_TIMESTAMP) NOT NULL, `updated_at` integer, FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON UPDATE no action ON DELETE cascade ); --> statement-breakpoint CREATE TABLE `users` ( `id` integer PRIMARY KEY NOT NULL, `name` text NOT NULL, `age` integer NOT NULL, `email` text NOT NULL ); --> statement-breakpoint CREATE UNIQUE INDEX `users_email_unique` ON `users` (`email`); ``` Run migrations: ```bash copy npx drizzle-kit migrate ``` Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. ### Basic file structure This is the basic file structure of the project. In the `src/db` directory, we have database-related files including connection in `index.ts` and schema definitions in `schema.ts`. ```plaintext 📦 ├ 📂 src │ ├ 📂 db │ │ ├ 📜 index.ts │ │ └ 📜 schema.ts ├ 📂 migrations │ ├ 📂 meta │ │ ├ 📜 _journal.json │ │ └ 📜 0000_snapshot.json │ └ 📜 0000_watery_spencer_smythe.sql ├ 📜 .env ├ 📜 drizzle.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ## Query examples For instance, we create `src/db/queries` folder and separate files for each operation: insert, select, update, delete. #### Insert data Read more about insert query in the [documentation](/docs/insert). ```typescript copy filename="src/db/queries/insert.ts" {4, 8} import { db } from '../index'; import { InsertPost, InsertUser, postsTable, usersTable } from '../schema'; export async function createUser(data: InsertUser) { await db.insert(usersTable).values(data); } export async function createPost(data: InsertPost) { await db.insert(postsTable).values(data); } ``` #### Select data Read more about select query in the [documentation](/docs/select). ```typescript copy filename="src/db/queries/select.ts" {5, 16, 41} import { asc, count, eq, getTableColumns, gt, sql } from 'drizzle-orm'; import { db } from '../index'; import { SelectUser, postsTable, usersTable } from '../schema'; export async function getUserById(id: SelectUser['id']): Promise< Array<{ id: number; name: string; age: number; email: string; }> > { return db.select().from(usersTable).where(eq(usersTable.id, id)); } export async function getUsersWithPostsCount( page = 1, pageSize = 5, ): Promise< Array<{ postsCount: number; id: number; name: string; age: number; email: string; }> > { return db .select({ ...getTableColumns(usersTable), postsCount: count(postsTable.id), }) .from(usersTable) .leftJoin(postsTable, eq(usersTable.id, postsTable.userId)) .groupBy(usersTable.id) .orderBy(asc(usersTable.id)) .limit(pageSize) .offset((page - 1) * pageSize); } export async function getPostsForLast24Hours( page = 1, pageSize = 5, ): Promise< Array<{ id: number; title: string; }> > { return db .select({ id: postsTable.id, title: postsTable.title, }) .from(postsTable) .where(gt(postsTable.createdAt, sql`(datetime('now','-24 hour'))`)) .orderBy(asc(postsTable.title), asc(postsTable.id)) .limit(pageSize) .offset((page - 1) * pageSize); } ``` Alternatively, you can use [relational query syntax](/docs/rqb). #### Update data Read more about update query in the [documentation](/docs/update). ```typescript copy filename="src/db/queries/update.ts" {5} import { eq } from 'drizzle-orm'; import { db } from '../index'; import { SelectPost, postsTable } from '../schema'; export async function updatePost(id: SelectPost['id'], data: Partial>) { await db.update(postsTable).set(data).where(eq(postsTable.id, id)); } ``` #### Delete data Read more about delete query in the [documentation](/docs/delete). ```typescript copy filename="src/db/queries/delete.ts" {5} import { eq } from 'drizzle-orm'; import { db } from '../index'; import { SelectUser, usersTable } from '../schema'; export async function deleteUser(id: SelectUser['id']) { await db.delete(usersTable).where(eq(usersTable.id, id)); } ``` Source: https://orm.drizzle.team/docs/tutorials/drizzle-with-vercel import Prerequisites from "@mdx/Prerequisites.astro"; import Npm from '@mdx/Npm.astro'; import Steps from '@mdx/Steps.astro'; import Section from "@mdx/Section.astro"; import Callout from '@mdx/Callout.astro'; This tutorial demonstrates how to use Drizzle ORM with [Vercel Postgres](https://vercel.com/docs/storage/vercel-postgres). Vercel Postgres is a serverless SQL database designed to integrate with Vercel Functions and your frontend framework. - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should have installed `dotenv` package for managing environment variables. Read more about this package [here](https://www.npmjs.com/package/dotenv) dotenv - You should have installed `@vercel/postgres` package. Read more about this package [here](https://www.npmjs.com/package/@vercel/postgres) @vercel/postgres Check [Vercel documentation](https://vercel.com/docs/storage/vercel-postgres/using-an-orm#drizzle) to learn how to connect to the database with Drizzle ORM. ## Setup Vercel Postgres and Drizzle ORM #### Create a new Vercel Postgres database You can create new Vercel Postgres database in the [dashboard](https://vercel.com/dashboard). Read Vercel Postgres [documentation](https://vercel.com/docs/storage/vercel-postgres/quickstart) to learn how to create a new database. #### Setup connection string variable Navigate to your Vercel Postgres database and copy `POSTGRES_URL` from `.env.local` section. Add `POSTGRES_URL` to your `.env.local` or `.env` file. ```plaintext copy POSTGRES_URL= ``` #### Connect Drizzle ORM to your database Create a `index.ts` file in the `src/db` directory and set up your database configuration: ```typescript copy filename="src/db/index.ts" import { drizzle } from 'drizzle-orm/vercel-postgres'; import { config } from 'dotenv'; config({ path: '.env.local' }); // or .env export const db = drizzle(); ``` #### Create tables Create a `schema.ts` file in the `src/db` directory and declare your tables: ```typescript copy filename="src/db/schema.ts" import { integer, pgTable, serial, text, timestamp } from 'drizzle-orm/pg-core'; export const usersTable = pgTable('users_table', { id: serial('id').primaryKey(), name: text('name').notNull(), age: integer('age').notNull(), email: text('email').notNull().unique(), }); export const postsTable = pgTable('posts_table', { id: serial('id').primaryKey(), title: text('title').notNull(), content: text('content').notNull(), userId: integer('user_id') .notNull() .references(() => usersTable.id, { onDelete: 'cascade' }), createdAt: timestamp('created_at').notNull().defaultNow(), updatedAt: timestamp('updated_at') .notNull() .$onUpdate(() => new Date()), }); export type InsertUser = typeof usersTable.$inferInsert; export type SelectUser = typeof usersTable.$inferSelect; export type InsertPost = typeof postsTable.$inferInsert; export type SelectPost = typeof postsTable.$inferSelect; ``` #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { config } from 'dotenv'; import { defineConfig } from 'drizzle-kit'; config({ path: '.env.local' }); export default defineConfig({ schema: './src/db/schema.ts', out: './migrations', dialect: 'postgresql', dbCredentials: { url: process.env.POSTGRES_URL!, }, }); ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash copy npx drizzle-kit generate ``` These migrations are stored in the `drizzle/migrations` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE IF NOT EXISTS "posts_table" ( "id" serial PRIMARY KEY NOT NULL, "title" text NOT NULL, "content" text NOT NULL, "user_id" integer NOT NULL, "created_at" timestamp DEFAULT now() NOT NULL, "updated_at" timestamp NOT NULL ); --> statement-breakpoint CREATE TABLE IF NOT EXISTS "users_table" ( "id" serial PRIMARY KEY NOT NULL, "name" text NOT NULL, "age" integer NOT NULL, "email" text NOT NULL, CONSTRAINT "users_table_email_unique" UNIQUE("email") ); --> statement-breakpoint DO $$ BEGIN ALTER TABLE "posts_table" ADD CONSTRAINT "posts_table_user_id_users_table_id_fk" FOREIGN KEY ("user_id") REFERENCES "users_table"("id") ON DELETE cascade ON UPDATE no action; EXCEPTION WHEN duplicate_object THEN null; END $$; ``` Run migrations: ```bash copy npx drizzle-kit migrate ``` Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash copy npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. ## Basic file structure This is the basic file structure of the project. In the `src/db` directory, we have database-related files including connection in `index.ts` and schema definitions in `schema.ts`. ```plaintext 📦 ├ 📂 src │ ├ 📂 db │ │ ├ 📜 index.ts │ │ └ 📜 schema.ts ├ 📂 migrations │ ├ 📂 meta │ │ ├ 📜 _journal.json │ │ └ 📜 0000_snapshot.json │ └ 📜 0000_watery_spencer_smythe.sql ├ 📜 .env.local ├ 📜 drizzle.config.ts ├ 📜 package.json └ 📜 tsconfig.json ``` ## Query examples For instance, we create `src/db/queries` folder and separate files for each operation: insert, select, update, delete. #### Insert data Read more about insert query in the [documentation](/docs/insert). ```typescript copy filename="src/db/queries/insert.ts" {4, 8} import { db } from '../index'; import { InsertPost, InsertUser, postsTable, usersTable } from '../schema'; export async function createUser(data: InsertUser) { await db.insert(usersTable).values(data); } export async function createPost(data: InsertPost) { await db.insert(postsTable).values(data); } ``` #### Select data Read more about select query in the [documentation](/docs/select). ```typescript copy filename="src/db/queries/select.ts" {5, 16, 41} import { asc, between, count, eq, getTableColumns, sql } from 'drizzle-orm'; import { db } from '../index'; import { SelectUser, postsTable, usersTable } from '../schema'; export async function getUserById(id: SelectUser['id']): Promise< Array<{ id: number; name: string; age: number; email: string; }> > { return db.select().from(usersTable).where(eq(usersTable.id, id)); } export async function getUsersWithPostsCount( page = 1, pageSize = 5, ): Promise< Array<{ postsCount: number; id: number; name: string; age: number; email: string; }> > { return db .select({ ...getTableColumns(usersTable), postsCount: count(postsTable.id), }) .from(usersTable) .leftJoin(postsTable, eq(usersTable.id, postsTable.userId)) .groupBy(usersTable.id) .orderBy(asc(usersTable.id)) .limit(pageSize) .offset((page - 1) * pageSize); } export async function getPostsForLast24Hours( page = 1, pageSize = 5, ): Promise< Array<{ id: number; title: string; }> > { return db .select({ id: postsTable.id, title: postsTable.title, }) .from(postsTable) .where(between(postsTable.createdAt, sql`now() - interval '1 day'`, sql`now()`)) .orderBy(asc(postsTable.title), asc(postsTable.id)) .limit(pageSize) .offset((page - 1) * pageSize); } ``` Alternatively, you can use [relational query syntax](/docs/rqb). #### Update data Read more about update query in the [documentation](/docs/update). ```typescript copy filename="src/db/queries/update.ts" {5} import { eq } from 'drizzle-orm'; import { db } from '../index'; import { SelectPost, postsTable } from '../schema'; export async function updatePost(id: SelectPost['id'], data: Partial>) { await db.update(postsTable).set(data).where(eq(postsTable.id, id)); } ``` #### Delete data Read more about delete query in the [documentation](/docs/delete). ```typescript copy filename="src/db/queries/delete.ts" {5} import { eq } from 'drizzle-orm'; import { db } from '../index'; import { SelectUser, usersTable } from '../schema'; export async function deleteUser(id: SelectUser['id']) { await db.delete(usersTable).where(eq(usersTable.id, id)); } ``` Source: https://orm.drizzle.team/docs/tutorials/drizzle-nextjs-neon import Steps from "@mdx/Steps.astro"; import Npm from "@mdx/Npm.astro"; import CodeTabs from "@mdx/CodeTabs.astro"; import CodeTab from "@mdx/CodeTab.astro"; import Section from "@mdx/Section.astro"; import Tabs from "@mdx/Tabs.astro"; import Tab from "@mdx/Tab.astro"; import Prerequisites from "@mdx/Prerequisites.astro"; import Callout from "@mdx/Callout.astro"; This tutorial demonstrates how to build `Todo app` using **Drizzle ORM** with **Neon database** and **Next.js**. - You should have an existing Next.js project or create a new one using the following command: ```bash npx create-next-app@latest --typescript ``` - You should have installed Drizzle ORM and [Drizzle kit](/docs/kit-overview). You can do this by running the following command: drizzle-orm -D drizzle-kit - You should have installed the [Neon serverless driver](https://neon.tech/docs/serverless/serverless-driver). @neondatabase/serverless - You should have installed the `dotenv` package for managing environment variables. dotenv In case you face the issue with resolving dependencies during installation: If you're not using React Native, forcing the installation with `--force` or `--legacy-peer-deps` should resolve the issue. If you are using React Native, then you need to use the exact version of React which is compatible with your React Native version. ## Setup Neon and Drizzle ORM #### Create a new Neon project Log in to the [Neon Console](https://console.neon.tech/app/projects) and navigate to the Projects section. Select a project or click the `New Project` button to create a new one. Your Neon projects come with a ready-to-use Postgres database named `neondb`. We'll use it in this tutorial. #### Setup connection string variable Navigate to the **Connection Details** section in the project console to find your database connection string. It should look similar to this: ```bash postgres://username:password@ep-cool-darkness-123456.us-east-2.aws.neon.tech/neondb ``` Add the `DATABASE_URL` environment variable to your `.env` or `.env.local` file, which you'll use to connect to the Neon database. ```bash DATABASE_URL=NEON_DATABASE_CONNECTION_STRING ``` #### Connect Drizzle ORM to your database Create a `drizzle.ts` file in your `src/db` folder and set up your database configuration: ```tsx copy filename="src/db/drizzle.ts" import { config } from "dotenv"; import { drizzle } from 'drizzle-orm/neon-http'; config({ path: ".env" }); // or .env.local export const db = drizzle(process.env.DATABASE_URL!); ``` #### Declare todo schema ```tsx copy filename="src/db/schema.ts" import { integer, text, boolean, pgTable } from "drizzle-orm/pg-core"; export const todo = pgTable("todo", { id: integer("id").primaryKey(), text: text("text").notNull(), done: boolean("done").default(false).notNull(), }); ``` Here we define the **`todo`** table with fields **`id`**, **`text`**, and **`done`**, using data types from Drizzle ORM. #### Setup Drizzle config file **Drizzle config** - a configuration file that is used by [Drizzle Kit](/docs/kit-overview) and contains all the information about your database connection, migration folder and schema files. Create a `drizzle.config.ts` file in the root of your project and add the following content: ```typescript copy filename="drizzle.config.ts" import { config } from 'dotenv'; import { defineConfig } from "drizzle-kit"; config({ path: '.env' }); export default defineConfig({ schema: "./src/db/schema.ts", out: "./migrations", dialect: "postgresql", dbCredentials: { url: process.env.DATABASE_URL!, }, }); ``` #### Applying changes to the database You can generate migrations using `drizzle-kit generate` command and then run them using the `drizzle-kit migrate` command. Generate migrations: ```bash npx drizzle-kit generate ``` These migrations are stored in the `drizzle/migrations` directory, as specified in your `drizzle.config.ts`. This directory will contain the SQL files necessary to update your database schema and a `meta` folder for storing snapshots of the schema at different migration stages. Example of a generated migration: ```sql CREATE TABLE IF NOT EXISTS "todo" ( "id" integer PRIMARY KEY NOT NULL, "text" text NOT NULL, "done" boolean DEFAULT false NOT NULL ); ``` Run migrations: ```bash npx drizzle-kit migrate ``` Alternatively, you can push changes directly to the database using [Drizzle kit push command](/docs/kit-overview#prototyping-with-db-push): ```bash npx drizzle-kit push ``` Push command is good for situations where you need to quickly test new schema designs or changes in a local development environment, allowing for fast iterations without the overhead of managing migration files. #### Establish server-side functions In this step, we establish server-side functions in the **src/actions/todoAction.ts** file to handle crucial operations on todo items: 1. **`getData`:** - Fetches all existing todo items from the database. 2. **`addTodo`:** - Adds a new todo item to the database with the provided text. - Initiates revalidation of the home page using **`revalidatePath("/")`**. 3. **`deleteTodo`:** - Removes a todo item from the database based on its unique ID. - Triggers a revalidation of the home page. 4. **`toggleTodo`:** - Toggles the completion status of a todo item, updating the database accordingly. - Revalidates the home page after the operation. 5. **`editTodo`:** - Modifies the text of a todo item identified by its ID in the database. - Initiates a revalidation of the home page. ```tsx collapsable copy filename="src/actions/todoAction.ts" "use server"; import { eq, not } from "drizzle-orm"; import { revalidatePath } from "next/cache"; import { db } from "@/db/drizzle"; import { todo } from "@/db/schema"; export const getData = async () => { const data = await db.select().from(todo); return data; }; export const addTodo = async (id: number, text: string) => { await db.insert(todo).values({ id: id, text: text, }); }; export const deleteTodo = async (id: number) => { await db.delete(todo).where(eq(todo.id, id)); revalidatePath("/"); }; export const toggleTodo = async (id: number) => { await db .update(todo) .set({ done: not(todo.done), }) .where(eq(todo.id, id)); revalidatePath("/"); }; export const editTodo = async (id: number, text: string) => { await db .update(todo) .set({ text: text, }) .where(eq(todo.id, id)); revalidatePath("/"); }; ``` ## Setup home page with Next.js #### Define a TypeScript type Define a TypeScript type for a todo item in `src/types/todoType.ts` with three properties: **`id`** of type **`number`**, **`text`** of type **`string`**, and **`done`** of type **`boolean`**. This type, named **`todoType`**, represents the structure of a typical todo item within your application. ```ts copy filename="src/types/todoType.ts" export type todoType = { id: number; text: string; done: boolean; }; ``` #### Create a home page for a to-do application 1. **`src/components/todo.tsx`:** Create a `Todo` component that represents a single todo item. It includes features for displaying and editing the todo text, marking it as done with a checkbox, and providing actions for editing, saving, canceling, and deleting the todo. 2. **`src/components/addTodo.tsx`:** The `AddTodo` component provides a simple form for adding new todo items to the Todo app. It includes an input field for entering the todo text and a button for triggering the addition of the new todo. 3. **`src/components/todos.tsx`:** Create Todos components that represents the main interface of a Todo app. It manages the state of todo items, provides functions for creating, editing, toggling, and deleting todos, and renders the individual todo items using the `Todo` component. ```tsx collapsable copy "use client"; import { ChangeEvent, FC, useState } from "react"; import { todoType } from "@/types/todoType"; interface Props { todo: todoType; changeTodoText: (id: number, text: string) => void; toggleIsTodoDone: (id: number, done: boolean) => void; deleteTodoItem: (id: number) => void; } const Todo: FC = ({ todo, changeTodoText, toggleIsTodoDone, deleteTodoItem, }) => { // State for handling editing mode const [editing, setEditing] = useState(false); // State for handling text input const [text, setText] = useState(todo.text); // State for handling "done" status const [isDone, setIsDone] = useState(todo.done); // Event handler for text input change const handleTextChange = (e: ChangeEvent) => { setText(e.target.value); }; // Event handler for toggling "done" status const handleIsDone = async () => { toggleIsTodoDone(todo.id, !isDone); setIsDone((prev) => !prev); }; // Event handler for initiating the edit mode const handleEdit = () => { setEditing(true); }; // Event handler for saving the edited text const handleSave = async () => { changeTodoText(todo.id, text); setEditing(false); }; // Event handler for canceling the edit mode const handleCancel = () => { setEditing(false); setText(todo.text); }; // Event handler for deleting a todo item const handleDelete = () => { if (confirm("Are you sure you want to delete this todo?")) { deleteTodoItem(todo.id); } }; // Rendering the Todo component return (
{/* Checkbox for marking the todo as done */} {/* Input field for todo text */} {/* Action buttons for editing, saving, canceling, and deleting */}
{editing ? ( ) : ( )} {editing ? ( ) : ( )}
); }; export default Todo; ``` ```tsx collapsable copy "use client"; import { ChangeEvent, FC, useState } from "react"; interface Props { createTodo: (value: string) => void; } const AddTodo: FC = ({ createTodo }) => { // State for handling input value const [input, setInput] = useState(""); // Event handler for input change const handleInput = (e: ChangeEvent) => { setInput(e.target.value); }; // Event handler for adding a new todo const handleAdd = async () => { createTodo(input); setInput(""); }; // Rendering the AddTodo component return (
{/* Input field for entering new todo text */} {/* Button for adding a new todo */}
); }; export default AddTodo; ``` ```tsx collapsable copy "use client"; import { FC, useState } from "react"; import { todoType } from "@/types/todoType"; import Todo from "./todo"; import AddTodo from "./addTodo"; import { addTodo, deleteTodo, editTodo, toggleTodo } from "@/actions/todoAction"; interface Props { todos: todoType[]; } const Todos: FC = ({ todos }) => { // State to manage the list of todo items const [todoItems, setTodoItems] = useState(todos); // Function to create a new todo item const createTodo = (text: string) => { const id = (todoItems.at(-1)?.id || 0) + 1; addTodo(id, text); setTodoItems((prev) => [...prev, { id: id, text, done: false }]); }; // Function to change the text of a todo item const changeTodoText = (id: number, text: string) => { setTodoItems((prev) => prev.map((todo) => (todo.id === id ? { ...todo, text } : todo)) ); editTodo(id, text); }; // Function to toggle the "done" status of a todo item const toggleIsTodoDone = (id: number) => { setTodoItems((prev) => prev.map((todo) => (todo.id === id ? { ...todo, done: !todo.done } : todo)) ); toggleTodo(id); }; // Function to delete a todo item const deleteTodoItem = (id: number) => { setTodoItems((prev) => prev.filter((todo) => todo.id !== id)); deleteTodo(id); }; // Rendering the Todo List component return (
To-do app
{/* Mapping through todoItems and rendering Todo component for each */} {todoItems.map((todo) => ( ))}
{/* Adding Todo component for creating new todos */}
); }; export default Todos; ```
Update the `page.tsx` file in the `src/app` folder to fetch the todo items from the database and render the `Todos` component: ```tsx copy filename="src/app/page.tsx" import { getData } from "@/actions/todoAction"; import Todos from "@/components/todos"; export default async function Home() { const data = await getData(); return ; } ```
## Basic file structure This guide uses the following file structure: ```text 📦 ├ 📂 migrations │ ├ 📂 meta │ └ 📜 0000_heavy_doctor_doom.sql ├ 📂 public ├ 📂 src │ ├ 📂 actions │ │ └ 📜 todoActions.ts │ ├ 📂 app │ │ ├ 📜 favicon.ico │ │ ├ 📜 globals.css │ │ ├ 📜 layout.tsx │ │ └ 📜 page.tsx │ ├ 📂 components │ │ ├ 📜 addTodo.tsx │ │ ├ 📜 todo.tsx │ │ └ 📜 todos.tsx │ └ 📂 db │ │ ├ 📜 drizzle.ts │ │ └ 📜 schema.ts │ └ 📂 types │ └ 📜 todoType.ts ├ 📜 .env ├ 📜 .eslintrc.json ├ 📜 .gitignore ├ 📜 drizzle.config.ts ├ 📜 next-env.d.ts ├ 📜 next.config.mjs ├ 📜 package-lock.json ├ 📜 package.json ├ 📜 postcss.config.mjs ├ 📜 README.md ├ 📜 tailwind.config.ts └ 📜 tsconfig.json ``` Source: https://orm.drizzle.team/docs/typebox import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; # drizzle-typebox `drizzle-typebox` is a plugin for **[Drizzle ORM](https://github.com/drizzle-team/drizzle-orm)** that allows you to generate **[Typebox](https://github.com/sinclairzx81/typebox)** schemas from Drizzle ORM schemas. ### Install the dependencies drizzle-typebox This documentation is for `drizzle-typebox@0.2.0` and higher You must also have Drizzle ORM v0.36.0 or greater and Typebox v0.34.8 or greater installed. ### Select schema Defines the shape of data queried from the database - can be used to validate API responses. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-typebox'; import { Value } from '@sinclair/typebox/value'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userSelectSchema = createSelectSchema(users); const rows = await db.select({ id: users.id, name: users.name }).from(users).limit(1); const parsed: { id: number; name: string; age: number } = Value.Parse(userSelectSchema, rows[0]); // Error: `age` is not returned in the above query const rows = await db.select().from(users).limit(1); const parsed: { id: number; name: string; age: number } = Value.Parse(userSelectSchema, rows[0]); // Will parse successfully ``` Views and enums are also supported. ```ts copy import { pgEnum } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-typebox'; import { Value } from '@sinclair/typebox/value'; const roles = pgEnum('roles', ['admin', 'basic']); const rolesSchema = createSelectSchema(roles); const parsed: 'admin' | 'basic' = Value.Parse(rolesSchema, ...); const usersView = pgView('users_view').as((qb) => qb.select().from(users).where(gt(users.age, 18))); const usersViewSchema = createSelectSchema(usersView); const parsed: { id: number; name: string; age: number } = Value.Parse(usersViewSchema, ...); ``` ### Insert schema Defines the shape of data to be inserted into the database - can be used to validate API requests. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createInsertSchema } from 'drizzle-typebox'; import { Value } from '@sinclair/typebox/value'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userInsertSchema = createInsertSchema(users); const user = { name: 'John' }; const parsed: { name: string, age: number } = Value.Parse(userInsertSchema, user); // Error: `age` is not defined const user = { name: 'Jane', age: 30 }; const parsed: { name: string, age: number } = Value.Parse(userInsertSchema, user); // Will parse successfully await db.insert(users).values(parsed); ``` ### Update schema Defines the shape of data to be updated in the database - can be used to validate API requests. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createUpdateSchema } from 'drizzle-typebox'; import { Value } from '@sinclair/typebox/value'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userUpdateSchema = createUpdateSchema(users); const user = { id: 5, name: 'John' }; const parsed: { name?: string | undefined, age?: number | undefined } = Value.Parse(userUpdateSchema, user); // Error: `id` is a generated column, it can't be updated const user = { age: 35 }; const parsed: { name?: string | undefined, age?: number | undefined } = Value.Parse(userUpdateSchema, user); // Will parse successfully await db.update(users).set(parsed).where(eq(users.name, 'Jane')); ``` ### Refinements Each create schema function accepts an additional optional parameter that you can used to extend, modify or completely overwite a field's schema. Defining a callback function will extend or modify while providing a Typebox schema will overwrite it. ```ts copy import { pgTable, text, integer, json } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-typebox'; import { Type } from '@sinclair/typebox'; import { Value } from '@sinclair/typebox/value'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), bio: text(), preferences: json() }); const userSelectSchema = createSelectSchema(users, { name: (schema) => Type.String({ ...schema, maxLength: 20 }), // Extends schema bio: (schema) => Type.String({ ...schema, maxLength: 1000 }), // Extends schema before becoming nullable/optional preferences: Type.Object({ theme: Type.String() }) // Overwrites the field, including its nullability }); const parsed: { id: number; name: string, bio?: string | undefined; preferences: { theme: string; }; } = Value.Parse(userSelectSchema, ...); ``` ### Factory functions For more advanced use cases, you can use the `createSchemaFactory` function. **Use case: Using an extended Typebox instance** ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createSchemaFactory } from 'drizzle-typebox'; import { t } from 'elysia'; // Extended Typebox instance const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const { createInsertSchema } = createSchemaFactory({ typeboxInstance: t }); const userInsertSchema = createInsertSchema(users, { // We can now use the extended instance name: (schema) => t.Number({ ...schema }, { error: '`name` must be a string' }) }); ``` ### Data type reference ```ts pg.boolean(); mysql.boolean(); sqlite.integer({ mode: 'boolean' }); // Schema Type.Boolean(); ``` ```ts pg.date({ mode: 'date' }); pg.timestamp({ mode: 'date' }); mysql.date({ mode: 'date' }); mysql.datetime({ mode: 'date' }); mysql.timestamp({ mode: 'date' }); sqlite.integer({ mode: 'timestamp' }); sqlite.integer({ mode: 'timestamp_ms' }); // Schema Type.Date(); ``` ```ts pg.date({ mode: 'string' }); pg.timestamp({ mode: 'string' }); pg.cidr(); pg.inet(); pg.interval(); pg.macaddr(); pg.macaddr8(); pg.numeric(); pg.text(); pg.sparsevec(); pg.time(); mysql.binary(); mysql.date({ mode: 'string' }); mysql.datetime({ mode: 'string' }); mysql.decimal(); mysql.time(); mysql.timestamp({ mode: 'string' }); mysql.varbinary(); sqlite.numeric(); sqlite.text({ mode: 'text' }); // Schema Type.String(); ``` ```ts pg.bit({ dimensions: ... }); // Schema t.RegExp(/^[01]+$/, { maxLength: dimensions }); ``` ```ts pg.uuid(); // Schema Type.String({ format: 'uuid' }); ``` ```ts pg.char({ length: ... }); mysql.char({ length: ... }); // Schema Type.String({ minLength: length, maxLength: length }); ``` ```ts pg.varchar({ length: ... }); mysql.varchar({ length: ... }); sqlite.text({ mode: 'text', length: ... }); // Schema Type.String({ maxLength: length }); ``` ```ts mysql.tinytext(); // Schema Type.String({ maxLength: 255 }); // unsigned 8-bit integer limit ``` ```ts mysql.text(); // Schema Type.String({ maxLength: 65_535 }); // unsigned 16-bit integer limit ``` ```ts mysql.mediumtext(); // Schema Type.String({ maxLength: 16_777_215 }); // unsigned 24-bit integer limit ``` ```ts mysql.longtext(); // Schema Type.String({ maxLength: 4_294_967_295 }); // unsigned 32-bit integer limit ``` ```ts pg.text({ enum: ... }); pg.char({ enum: ... }); pg.varchar({ enum: ... }); mysql.tinytext({ enum: ... }); mysql.mediumtext({ enum: ... }); mysql.text({ enum: ... }); mysql.longtext({ enum: ... }); mysql.char({ enum: ... }); mysql.varchar({ enum: ... }); mysql.mysqlEnum(..., ...); sqlite.text({ mode: 'text', enum: ... }); // Schema Type.Enum(enum); ``` ```ts mysql.tinyint(); // Schema Type.Integer({ minimum: -128, maximum: 127 }); // 8-bit integer lower and upper limit ``` ```ts mysql.tinyint({ unsigned: true }); // Schema Type.Integer({ minimum: 0, maximum: 255 }); // unsigned 8-bit integer lower and upper limit ``` ```ts pg.smallint(); pg.smallserial(); mysql.smallint(); // Schema Type.Integer({ minimum: -32_768, maximum: 32_767 }); // 16-bit integer lower and upper limit ``` ```ts mysql.smallint({ unsigned: true }); // Schema Type.Integer({ minimum: 0, maximum: 65_535 }); // unsigned 16-bit integer lower and upper limit ``` ```ts pg.real(); mysql.float(); // Schema Type.Number().min(-8_388_608).max(8_388_607); // 24-bit integer lower and upper limit ``` ```ts mysql.mediumint(); // Schema Type.Integer({ minimum: -8_388_608, maximum: 8_388_607 }); // 24-bit integer lower and upper limit ``` ```ts mysql.float({ unsigned: true }); // Schema Type.Number({ minimum: 0, maximum: 16_777_215 }); // unsigned 24-bit integer lower and upper limit ``` ```ts mysql.mediumint({ unsigned: true }); // Schema Type.Integer({ minimum: 0, maximum: 16_777_215 }); // unsigned 24-bit integer lower and upper limit ``` ```ts pg.integer(); pg.serial(); mysql.int(); // Schema Type.Integer({ minimum: -2_147_483_648, maximum: 2_147_483_647 }); // 32-bit integer lower and upper limit ``` ```ts mysql.int({ unsigned: true }); // Schema Type.Integer({ minimum: 0, maximum: 4_294_967_295 }); // unsgined 32-bit integer lower and upper limit ``` ```ts pg.doublePrecision(); mysql.double(); mysql.real(); sqlite.real(); // Schema Type.Number({ minimum: -140_737_488_355_328, maximum: 140_737_488_355_327 }); // 48-bit integer lower and upper limit ``` ```ts mysql.double({ unsigned: true }); // Schema Type.Numer({ minimum: 0, maximum: 281_474_976_710_655 }); // unsigned 48-bit integer lower and upper limit ``` ```ts pg.bigint({ mode: 'number' }); pg.bigserial({ mode: 'number' }); mysql.bigint({ mode: 'number' }); mysql.bigserial({ mode: 'number' }); sqlite.integer({ mode: 'number' }); // Schema Type.Integer({ minimum: -9_007_199_254_740_991, maximum: 9_007_199_254_740_991 }); // Javascript min. and max. safe integers ``` ```ts mysql.serial(); Type.Integer({ minimum: 0, maximum: 9_007_199_254_740_991 }); // Javascript max. safe integer ``` ```ts pg.bigint({ mode: 'bigint' }); pg.bigserial({ mode: 'bigint' }); mysql.bigint({ mode: 'bigint' }); sqlite.blob({ mode: 'bigint' }); // Schema Type.BigInt({ minimum: -9_223_372_036_854_775_808n, maximum: 9_223_372_036_854_775_807n }); // 64-bit integer lower and upper limit ``` ```ts mysql.bigint({ mode: 'bigint', unsigned: true }); // Schema Type.BigInt({ minimum: 0, maximum: 18_446_744_073_709_551_615n }); // unsigned 64-bit integer lower and upper limit ``` ```ts mysql.year(); // Schema Type.Integer({ minimum: 1_901, maximum: 2_155 }); ``` ```ts pg.geometry({ type: 'point', mode: 'tuple' }); pg.point({ mode: 'tuple' }); // Schema Type.Tuple([Type.Number(), Type.Number()]); ``` ```ts pg.geometry({ type: 'point', mode: 'xy' }); pg.point({ mode: 'xy' }); // Schema Type.Object({ x: Type.Number(), y: Type.Number() }); ``` ```ts pg.halfvec({ dimensions: ... }); pg.vector({ dimensions: ... }); // Schema Type.Array(Type.Number(), { minItems: dimensions, maxItems: dimensions }); ``` ```ts pg.line({ mode: 'abc' }); // Schema Type.Object({ a: Type.Number(), b: Type.Number(), c: Type.Number() }); ``` ```ts pg.line({ mode: 'tuple' }); // Schema Type.Tuple([Type.Number(), Type.Number(), Type.Number()]); ``` ```ts pg.json(); pg.jsonb(); mysql.json(); sqlite.blob({ mode: 'json' }); sqlite.text({ mode: 'json' }); // Schema Type.Recursive((self) => Type.Union([Type.Union([Type.String(), Type.Number(), Type.Boolean(), Type.Null()]), Type.Array(self), Type.Record(Type.String(), self)])); ``` ```ts sqlite.blob({ mode: 'buffer' }); // Schema TypeRegistry.Set('Buffer', (_, value) => value instanceof Buffer); // drizzle-typebox runs this method to add it to Typebox's type system { [Kind]: 'Buffer', type: 'buffer' }; // The Typebox schema ``` ```ts pg.dataType().array(...); // Schema Type.Array(baseDataTypeSchema, { minItems: size, maxItems: size }); ``` Source: https://orm.drizzle.team/docs/update import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; # SQL Update ```typescript copy await db.update(users) .set({ name: 'Mr. Dan' }) .where(eq(users.name, 'Dan')); ``` The object that you pass to `update` should have keys that match column names in your database schema. Values of `undefined` are ignored in the object: to set a column to `null`, pass `null`. You can pass SQL as a value to be used in the update object, like this: ```typescript copy await db.update(users) .set({ updatedAt: sql`NOW()` }) .where(eq(users.name, 'Dan')); ``` ### Limit Use `.limit()` to add `limit` clause to the query - for example:
```typescript await db.update(usersTable).set({ verified: true }).limit(2); ``` ```sql update "users" set "verified" = $1 limit $2; ```
### Order By Use `.orderBy()` to add `order by` clause to the query, sorting the results by the specified fields:
```typescript import { asc, desc } from 'drizzle-orm'; await db.update(usersTable).set({ verified: true }).orderBy(usersTable.name); await db.update(usersTable).set({ verified: true }).orderBy(desc(usersTable.name)); // order by multiple fields await db.update(usersTable).set({ verified: true }).orderBy(usersTable.name, usersTable.name2); await db.update(usersTable).set({ verified: true }).orderBy(asc(usersTable.name), desc(usersTable.name2)); ``` ```sql update "users" set "verified" = $1 order by "name"; update "users" set "verified" = $1 order by "name" desc; update "users" set "verified" = $1 order by "name", "name2"; update "users" set "verified" = $1 order by "name" asc, "name2" desc; ```
### Update with returning You can update a row and get it back in PostgreSQL and SQLite: ```typescript copy const updatedUserId: { updatedId: number }[] = await db.update(users) .set({ name: 'Mr. Dan' }) .where(eq(users.name, 'Dan')) .returning({ updatedId: users.id }); ``` ## `with update` clause Check how to use WITH statement with [select](/docs/select#with-clause), [insert](/docs/insert#with-insert-clause), [delete](/docs/delete#with-delete-clause) Using the `with` clause can help you simplify complex queries by splitting them into smaller subqueries called common table expressions (CTEs):
```typescript copy const averagePrice = db.$with('average_price').as( db.select({ value: sql`avg(${products.price})`.as('value') }).from(products) ); const result = await db.with(averagePrice) .update(products) .set({ cheap: true }) .where(lt(products.price, sql`(select * from ${averagePrice})`)) .returning({ id: products.id }); ``` ```sql with "average_price" as (select avg("price") as "value" from "products") update "products" set "cheap" = $1 where "products"."price" < (select * from "average_price") returning "id" ```
## Update ... from As the SQLite documentation mentions: > 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: > A table expression allowing columns from other tables to appear in the WHERE condition and update expressions Drizzle also supports this feature starting from version `drizzle-orm@0.36.3`
```ts await db .update(users) .set({ cityId: cities.id }) .from(cities) .where(and(eq(cities.name, 'Seattle'), eq(users.name, 'John'))) ``` ```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).
```ts const c = alias(cities, 'c'); await db .update(users) .set({ cityId: c.id }) .from(c); ``` ```sql update "users" set "city_id" = "c"."id" from "cities" "c" ```
In Postgres, you can also return columns from the joined tables.
```ts const updatedUsers = await db .update(users) .set({ cityId: cities.id }) .from(cities) .returning({ id: users.id, cityName: cities.name }); ``` ```sql update "users" set "city_id" = "cities"."id" from "cities" returning "users"."id", "cities"."name" ```
Source: https://orm.drizzle.team/docs/upgrade-21 import Callout from '@mdx/Callout.astro'; ## How to migrate to `0.21.0` #### 1. Remove all `:dialect` prefixes from your drizzle-kit commands. Example: Change `drizzle-kit push:mysql` to `drizzle-kit push`. #### 2. Update your `drizzle.config.ts` file: - Add `dialect` to `drizzle.config.ts`. It is now mandatory and can be `postgresql`, `mysql`, or `sqlite`. - Add `driver` to `drizzle.config.ts` ONLY if you are using `aws-data-api`, `turso`, `d1-http`(WIP), or `expo`. Otherwise, you can remove the `driver` from `drizzle.config.ts`. - If you were using `connectionString` or `uri` in `dbCredentials`, you should now use `url`. ```ts import { defineConfig } from "drizzle-kit" export default defineConfig({ dialect: "sqlite", // "postgresql" | "mysql" driver: "turso", // optional and used only if `aws-data-api`, `turso`, `d1-http`(WIP) or `expo` are used dbCredentials: { url: "" } }) ``` #### 3. If you are using PostgreSQL or SQLite and had migrations generated in your project, please run `drizzle-kit up` so Drizzle can upgrade all the snapshots to version 6. You can check everything that was changed in `0.21.0` in details here ## Changelog **❗ Snapshots Upgrade** All PostgreSQL and SQLite-generated snapshots will be upgraded to version 6. You will be prompted to upgrade them by running `drizzle-kit up` **❗ Removing :dialect from `drizzle-kit` cli commands** You can now just use commands, like: - `drizzle-kit generate` - `drizzle-kit push` - etc. without specifying dialect. This param is moved to `drizzle.config.ts` **❗ `drizzle.config` update** - `dialect` is now mandatory; specify which database dialect you are connecting to. Options include `mysql`, `postgresql`, or `sqlite`. - `driver` has become optional and will have a specific driver, each with a different configuration of `dbCredentials`. Available drivers are: - `aws-data-api` - `turso` - `d1-http` - currently WIP - `expo` - `url` - a unified parameter for the previously existing `connectionString` and `uri`. - `migrations` - a new object parameter to specify a custom table and schema for the migrate command: - `table` - the custom table where drizzle will store migrations. - `schema` - the custom schema where drizzle will store migrations (Postgres only). Usage examples for all new and updated commands ```ts import { defineConfig } from "drizzle-kit" export default defineConfig({ dialect: "sqlite", // "postgresql" | "mysql" driver: "turso" dbCredentials: { url: "" }, migration: { table: "migrations", schema: "public" } }) ``` Drizzle driver selection follows the current strategy: If a `driver` is specified, use this driver for querying. If no driver is specified: - For `postgresql` dialect, Drizzle will: - Check if the `pg` driver is installed and use it. - If not, try to find the `postgres` driver and use it. - If still not found, try to find `@vercel/postgres`. - Then try `@neondatabase/serverless`. - If nothing is found, an error will be thrown. - For `mysql` dialect, Drizzle will: - Check if the `mysql2` driver is installed and use it. - If not, try to find `@planetscale/database` and use it. - If nothing is found, an error will be thrown. - For `sqlite` dialect, Drizzle will: - Check if the `@libsql/client` driver is installed and use it. - If not, try to find `better-sqlite3` and use it. - If nothing is found, an error will be thrown **❗ MySQL schemas/database are no longer supported by drizzle-kit** Drizzle Kit won't handle any schema changes for additional schemas/databases in your drizzle schema file # New Features **🎉 Pull relations** Drizzle will now pull `relations` from the database by extracting foreign key information and translating it into a `relations` object. You can view the `relations.ts` file in the `out` folder after introspection is complete For more info about relations, please check [the docs](/docs/rqb#declaring-relations) **🎉 Custom name for generated migrations** To specify a name for your migration you should use `--name ` Usage ``` drizzle-kit generate --name init_db ``` **🎉 New command `migrate`** You can now apply generated migrations to your database directly from `drizzle-kit` Usage ``` drizzle-kit migrate ``` By default, drizzle-kit will store migration data entries in the `__drizzle_migrations` table and, in the case of PostgreSQL, in a `drizzle` schema. If you want to change this, you will need to specify the modifications in `drizzle.config.ts`. ```ts import { defineConfig } from "drizzle-kit" export default defineConfig({ migrations: { table: "migrations", schema: "public" } }) ``` Source: https://orm.drizzle.team/docs/valibot import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; # drizzle-valibot `drizzle-valibot` is a plugin for **[Drizzle ORM](https://github.com/drizzle-team/drizzle-orm)** that allows you to generate **[Valibot](https://valibot.dev/)** schemas from Drizzle ORM schemas. ### Install the dependencies drizzle-valibot This documentation is for `drizzle-valibot@0.3.0` and higher You must also have Drizzle ORM v0.36.0 or greater and Valibot v1.0.0-beta.7 or greater installed. ### Select schema Defines the shape of data queried from the database - can be used to validate API responses. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-valibot'; import { parse } from 'valibot'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userSelectSchema = createSelectSchema(users); const rows = await db.select({ id: users.id, name: users.name }).from(users).limit(1); const parsed: { id: number; name: string; age: number } = parse(userSelectSchema, rows[0]); // Error: `age` is not returned in the above query const rows = await db.select().from(users).limit(1); const parsed: { id: number; name: string; age: number } = parse(userSelectSchema, rows[0]); // Will parse successfully ``` Views and enums are also supported. ```ts copy import { pgEnum } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-valibot'; import { parse } from 'valibot'; const roles = pgEnum('roles', ['admin', 'basic']); const rolesSchema = createSelectSchema(roles); const parsed: 'admin' | 'basic' = parse(rolesSchema, ...); const usersView = pgView('users_view').as((qb) => qb.select().from(users).where(gt(users.age, 18))); const usersViewSchema = createSelectSchema(usersView); const parsed: { id: number; name: string; age: number } = parse(usersViewSchema, ...); ``` ### Insert schema Defines the shape of data to be inserted into the database - can be used to validate API requests. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createInsertSchema } from 'drizzle-valibot'; import { parse } from 'valibot'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userInsertSchema = createInsertSchema(users); const user = { name: 'John' }; const parsed: { name: string, age: number } = parse(userInsertSchema, user); // Error: `age` is not defined const user = { name: 'Jane', age: 30 }; const parsed: { name: string, age: number } = parse(userInsertSchema, user); // Will parse successfully await db.insert(users).values(parsed); ``` ### Update schema Defines the shape of data to be updated in the database - can be used to validate API requests. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createUpdateSchema } from 'drizzle-valibot'; import { parse } from 'valibot'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userUpdateSchema = createUpdateSchema(users); const user = { id: 5, name: 'John' }; const parsed: { name?: string | undefined, age?: number | undefined } = parse(userUpdateSchema, user); // Error: `id` is a generated column, it can't be updated const user = { age: 35 }; const parsed: { name?: string | undefined, age?: number | undefined } = parse(userUpdateSchema, user); // Will parse successfully await db.update(users).set(parsed).where(eq(users.name, 'Jane')); ``` ### Refinements Each create schema function accepts an additional optional parameter that you can used to extend, modify or completely overwite a field's schema. Defining a callback function will extend or modify while providing a Valibot schema will overwrite it. ```ts copy import { pgTable, text, integer, json } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-valibot'; import { parse, pipe, maxLength, object, string } from 'valibot'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), bio: text(), preferences: json() }); const userSelectSchema = createSelectSchema(users, { name: (schema) => pipe(schema, maxLength(20)), // Extends schema bio: (schema) => pipe(schema, maxLength(1000)), // Extends schema before becoming nullable/optional preferences: object({ theme: string() }) // Overwrites the field, including its nullability }); const parsed: { id: number; name: string, bio?: string | undefined; preferences: { theme: string; }; } = parse(userSelectSchema, ...); ``` ### Data type reference ```ts pg.boolean(); mysql.boolean(); sqlite.integer({ mode: 'boolean' }); // Schema boolean(); ``` ```ts pg.date({ mode: 'date' }); pg.timestamp({ mode: 'date' }); mysql.date({ mode: 'date' }); mysql.datetime({ mode: 'date' }); mysql.timestamp({ mode: 'date' }); sqlite.integer({ mode: 'timestamp' }); sqlite.integer({ mode: 'timestamp_ms' }); // Schema date(); ``` ```ts pg.date({ mode: 'string' }); pg.timestamp({ mode: 'string' }); pg.cidr(); pg.inet(); pg.interval(); pg.macaddr(); pg.macaddr8(); pg.numeric(); pg.text(); pg.sparsevec(); pg.time(); mysql.binary(); mysql.date({ mode: 'string' }); mysql.datetime({ mode: 'string' }); mysql.decimal(); mysql.time(); mysql.timestamp({ mode: 'string' }); mysql.varbinary(); sqlite.numeric(); sqlite.text({ mode: 'text' }); // Schema string(); ``` ```ts pg.bit({ dimensions: ... }); // Schema pipe(string(), regex(/^[01]+$/), maxLength(dimensions)); ``` ```ts pg.uuid(); // Schema pipe(string(), uuid()); ``` ```ts pg.char({ length: ... }); mysql.char({ length: ... }); // Schema pipe(string(), length(length)); ``` ```ts pg.varchar({ length: ... }); mysql.varchar({ length: ... }); sqlite.text({ mode: 'text', length: ... }); // Schema pipe(string(), maxLength(length)); ``` ```ts mysql.tinytext(); // Schema pipe(string(), maxLength(255)); // unsigned 8-bit integer limit ``` ```ts mysql.text(); // Schema pipe(string(), maxLength(65_535)); // unsigned 16-bit integer limit ``` ```ts mysql.mediumtext(); // Schema pipe(string(), maxLength(16_777_215)); // unsigned 24-bit integer limit ``` ```ts mysql.longtext(); // Schema pipe(string(), maxLength(4_294_967_295)); // unsigned 32-bit integer limit ``` ```ts pg.text({ enum: ... }); pg.char({ enum: ... }); pg.varchar({ enum: ... }); mysql.tinytext({ enum: ... }); mysql.mediumtext({ enum: ... }); mysql.text({ enum: ... }); mysql.longtext({ enum: ... }); mysql.char({ enum: ... }); mysql.varchar({ enum: ... }); mysql.mysqlEnum(..., ...); sqlite.text({ mode: 'text', enum: ... }); // Schema enum(enum); ``` ```ts mysql.tinyint(); // Schema pipe(number(), minValue(-128), maxValue(127), integer()); // 8-bit integer lower and upper limit ``` ```ts mysql.tinyint({ unsigned: true }); // Schema pipe(number(), minValue(0), maxValue(255), integer()); // unsigned 8-bit integer lower and upper limit ``` ```ts pg.smallint(); pg.smallserial(); mysql.smallint(); // Schema pipe(number(), minValue(-32_768), maxValue(32_767), integer()); // 16-bit integer lower and upper limit ``` ```ts mysql.smallint({ unsigned: true }); // Schema pipe(number(), minValue(0), maxValue(65_535), integer()); // unsigned 16-bit integer lower and upper limit ``` ```ts pg.real(); mysql.float(); // Schema pipe(number(), minValue(-8_388_608), maxValue(8_388_607)); // 24-bit integer lower and upper limit ``` ```ts mysql.mediumint(); // Schema pipe(number(), minValue(-8_388_608), maxValue(8_388_607), integer()); // 24-bit integer lower and upper limit ``` ```ts mysql.float({ unsigned: true }); // Schema pipe(number(), minValue(0), maxValue(16_777_215)); // unsigned 24-bit integer lower and upper limit ``` ```ts mysql.mediumint({ unsigned: true }); // Schema pipe(number(), minValue(0), maxValue(16_777_215), integer()); // unsigned 24-bit integer lower and upper limit ``` ```ts pg.integer(); pg.serial(); mysql.int(); // Schema pipe(number(), minValue(-2_147_483_648), maxValue(2_147_483_647), integer()); // 32-bit integer lower and upper limit ``` ```ts mysql.int({ unsigned: true }); // Schema pipe(number(), minValue(0), maxValue(4_294_967_295), integer()); // unsgined 32-bit integer lower and upper limit ``` ```ts pg.doublePrecision(); mysql.double(); mysql.real(); sqlite.real(); // Schema pipe(number(), minValue(-140_737_488_355_328), maxValue(140_737_488_355_327)); // 48-bit integer lower and upper limit ``` ```ts mysql.double({ unsigned: true }); // Schema pipe(number(), minValue(0), maxValue(281_474_976_710_655)); // unsigned 48-bit integer lower and upper limit ``` ```ts pg.bigint({ mode: 'number' }); pg.bigserial({ mode: 'number' }); mysql.bigint({ mode: 'number' }); mysql.bigserial({ mode: 'number' }); sqlite.integer({ mode: 'number' }); // Schema pipe(number(), minValue(-9_007_199_254_740_991), maxValue(9_007_199_254_740_991), integer()); // Javascript min. and max. safe integers ``` ```ts mysql.serial(); // Schema pipe(number(), minValue(0), maxValue(9_007_199_254_740_991), integer()); // Javascript max. safe integer ``` ```ts pg.bigint({ mode: 'bigint' }); pg.bigserial({ mode: 'bigint' }); mysql.bigint({ mode: 'bigint' }); sqlite.blob({ mode: 'bigint' }); // Schema pipe(bigint(), minValue(-9_223_372_036_854_775_808n), maxValue(9_223_372_036_854_775_807n)); // 64-bit integer lower and upper limit ``` ```ts mysql.bigint({ mode: 'bigint', unsigned: true }); // Schema pipe(bigint(), minValue(0), maxValue(18_446_744_073_709_551_615n)); // unsigned 64-bit integer lower and upper limit ``` ```ts mysql.year(); // Schema pipe(number(), minValue(1_901), maxValue(2_155), integer()); ``` ```ts pg.geometry({ type: 'point', mode: 'tuple' }); pg.point({ mode: 'tuple' }); // Schema tuple([number(), number()]); ``` ```ts pg.geometry({ type: 'point', mode: 'xy' }); pg.point({ mode: 'xy' }); // Schema object({ x: number(), y: number() }); ``` ```ts pg.halfvec({ dimensions: ... }); pg.vector({ dimensions: ... }); // Schema pipe(array(number()), length(dimensions)); ``` ```ts pg.line({ mode: 'abc' }); // Schema object({ a: number(), b: number(), c: number() }); ``` ```ts pg.line({ mode: 'tuple' }); // Schema tuple([number(), number(), number()]); ``` ```ts pg.json(); pg.jsonb(); mysql.json(); sqlite.blob({ mode: 'json' }); sqlite.text({ mode: 'json' }); // Schema const self = union([union([string(), number(), boolean(), null()]), array(lazy(() => self)), record(string(), lazy(() => self))]); ``` ```ts sqlite.blob({ mode: 'buffer' }); // Schema custom((v) => v instanceof Buffer); ``` ```ts pg.dataType().array(...); // Schema pipe(array(baseDataTypeSchema), length(size)); ``` Source: https://orm.drizzle.team/docs/views import Tab from '@mdx/Tab.astro'; import Tabs from '@mdx/Tabs.astro'; import IsSupportedChipGroup from '@mdx/IsSupportedChipGroup.astro'; import Callout from '@mdx/Callout.astro'; import Section from '@mdx/Section.astro'; # Views There're several ways you can declare views with Drizzle ORM. You can declare views that have to be created or you can declare views that already exist in the database. You can declare views statements with an inline `query builder` syntax, with `standalone query builder` and with raw `sql` operators. When views are created with either inlined or standalone query builders, view columns schema will be automatically inferred, yet when you use `sql` you have to explicitly declare view columns schema. ### Declaring views
```ts filename="schema.ts" copy {13-14} import { pgTable, pgView, serial, text, timestamp } from "drizzle-orm/pg-core"; export const user = pgTable("user", { id: serial(), name: text(), email: text(), password: text(), role: text().$type<"admin" | "customer">(), createdAt: timestamp("created_at"), updatedAt: timestamp("updated_at"), }); export const userView = pgView("user_view").as((qb) => qb.select().from(user)); export const customersView = pgView("customers_view").as((qb) => qb.select().from(user).where(eq(user.role, "customer"))); ``` ```sql CREATE VIEW "user_view" AS SELECT * FROM "user"; CREATE VIEW "customers_view" AS SELECT * FROM "user" WHERE "role" = 'customer'; ```
```ts filename="schema.ts" copy {13-14} import { text, mysqlTable, mysqlView, int, timestamp } from "drizzle-orm/mysql-core"; export const user = mysqlTable("user", { id: int().primaryKey().autoincrement(), name: text(), email: text(), password: text(), role: text().$type<"admin" | "customer">(), createdAt: timestamp("created_at"), updatedAt: timestamp("updated_at"), }); export const userView = mysqlView("user_view").as((qb) => qb.select().from(user)); export const customersView = mysqlView("customers_view").as((qb) => qb.select().from(user).where(eq(user.role, "customer"))); ``` ```sql CREATE VIEW "user_view" AS SELECT * FROM "user"; CREATE VIEW "customers_view" AS SELECT * FROM "user" WHERE "role" = 'customer'; ```
```ts filename="schema.ts" copy {13-14} import { integer, text, sqliteView, sqliteTable } from "drizzle-orm/sqlite-core"; export const user = sqliteTable("user", { id: integer().primaryKey({ autoIncrement: true }), name: text(), email: text(), password: text(), role: text().$type<"admin" | "customer">(), createdAt: integer("created_at"), updatedAt: integer("updated_at"), }); export const userView = sqliteView("user_view").as((qb) => qb.select().from(user)); export const customersView = sqliteView("customers_view").as((qb) => qb.select().from(user).where(eq(user.role, "customer"))); ``` ```sql CREATE VIEW "user_view" AS SELECT * FROM "user"; CREATE VIEW "customers_view" AS SELECT * FROM "user" WHERE "role" = 'customer'; ```
If you need a subset of columns you can use `.select({ ... })` method in query builder, like this:
```ts {4-6} export const customersView = pgView("customers_view").as((qb) => { return qb .select({ id: user.id, name: user.name, email: user.email, }) .from(user); }); ``` ```sql CREATE VIEW "customers_view" AS SELECT "id", "name", "email" FROM "user" WHERE "role" = 'customer'; ```
You can also declare views using `standalone query builder`, it works exactly the same way:
```ts filename="schema.ts" copy {3, 15-16} import { pgTable, pgView, serial, text, timestamp, QueryBuilder} from "drizzle-orm/pg-core"; const qb = new QueryBuilder(); export const user = pgTable("user", { id: serial(), name: text(), email: text(), password: text(), role: text().$type<"admin" | "customer">(), createdAt: timestamp("created_at"), updatedAt: timestamp("updated_at"), }); export const userView = pgView("user_view").as(qb.select().from(user)); export const customersView = pgView("customers_view").as(qb.select().from(user).where(eq(user.role, "customer"))); ``` ```sql CREATE VIEW "user_view" AS SELECT * FROM "user"; CREATE VIEW "customers_view" AS SELECT * FROM "user" WHERE "role" = 'customer'; ```
```ts filename="schema.ts" copy {3, 15-16} import { text, mysqlTable, mysqlView, int, timestamp, QueryBuilder } from "drizzle-orm/mysql-core"; const qb = new QueryBuilder(); export const user = mysqlTable("user", { id: int().primaryKey().autoincrement(), name: text(), email: text(), password: text(), role: text().$type<"admin" | "customer">(), createdAt: timestamp("created_at"), updatedAt: timestamp("updated_at"), }); export const userView = mysqlView("user_view").as(qb.select().from(user)); export const customersView = mysqlView("customers_view").as(qb.select().from(user).where(eq(user.role, "customer"))); ``` ```sql CREATE VIEW "user_view" AS SELECT * FROM "user"; CREATE VIEW "customers_view" AS SELECT * FROM "user" WHERE "role" = 'customer'; ```
```ts filename="schema.ts" copy {3, 15-16} import { integer, text, sqliteView, sqliteTable, QueryBuilder } from "drizzle-orm/sqlite-core"; const qb = new QueryBuilder(); export const user = sqliteTable("user", { id: integer().primaryKey({ autoIncrement: true }), name: text(), email: text(), password: text(), role: text().$type<"admin" | "customer">(), createdAt: integer("created_at"), updatedAt: integer("updated_at"), }); export const userView = sqliteView("user_view").as((qb) => qb.select().from(user)); export const customerView = sqliteView("customers_view").as((qb) => qb.select().from(user).where(eq(user.role, "customer"))); ``` ```sql CREATE VIEW "user_view" AS SELECT * FROM "user"; CREATE VIEW "customers_view" AS SELECT * FROM "user" WHERE "role" = 'customer'; ```
### Declaring views with raw SQL Whenever you need to declare view using a syntax that is not supported by the query builder, you can directly use `sql` operator and explicitly specify view columns schema. ```ts copy // regular view const newYorkers = pgView('new_yorkers', { id: serial('id').primaryKey(), name: text('name').notNull(), cityId: integer('city_id').notNull(), }).as(sql`select * from ${users} where ${eq(users.cityId, 1)}`); // materialized view const newYorkers = pgMaterializedView('new_yorkers', { id: serial('id').primaryKey(), name: text('name').notNull(), cityId: integer('city_id').notNull(), }).as(sql`select * from ${users} where ${eq(users.cityId, 1)}`); ``` ### Declaring existing views When you're provided with a read only access to an existing view in the database you should use `.existing()` view configuration, `drizzle-kit` will ignore and will not generate a `create view` statement in the generated migration. ```ts export const user = pgTable("user", { id: serial(), name: text(), email: text(), password: text(), role: text().$type<"admin" | "customer">(), createdAt: timestamp("created_at"), updatedAt: timestamp("updated_at"), }); // regular view export const trimmedUser = pgView("trimmed_user", { id: serial("id"), name: text("name"), email: text("email"), }).existing(); // materialized view won't make any difference, yet you can use it for consistency export const trimmedUser = pgMaterializedView("trimmed_user", { id: serial("id"), name: text("name"), email: text("email"), }).existing(); ``` ### Materialized views According to the official docs, PostgreSQL has both **[`regular`](https://www.postgresql.org/docs/current/sql-createview.html)** and **[`materialized`](https://www.postgresql.org/docs/current/sql-creatematerializedview.html)** views. Materialized views in PostgreSQL use the rule system like views do, but persist the results in a table-like form. {/* This means that when a query is executed against a materialized view, the results are returned directly from the materialized view, like from a table, rather than being reconstructed by executing the query against the underlying base tables that make up the view. */} Drizzle ORM natively supports PostgreSQL materialized views:
```ts filename="schema.ts" copy const newYorkers = pgMaterializedView('new_yorkers').as((qb) => qb.select().from(users).where(eq(users.cityId, 1))); ``` ```sql CREATE MATERIALIZED VIEW "new_yorkers" AS SELECT * FROM "users"; ```
You can then refresh materialized views in the application runtime: ```ts copy await db.refreshMaterializedView(newYorkers); await db.refreshMaterializedView(newYorkers).concurrently(); await db.refreshMaterializedView(newYorkers).withNoData(); ``` ### Extended example All the parameters inside the query will be inlined, instead of replaced by `$1`, `$2`, etc. ```ts copy // regular view const newYorkers = pgView('new_yorkers') .with({ checkOption: 'cascaded', securityBarrier: true, securityInvoker: true, }) .as((qb) => { const sq = qb .$with('sq') .as( qb.select({ userId: users.id, cityId: cities.id }) .from(users) .leftJoin(cities, eq(cities.id, users.homeCity)) .where(sql`${users.age1} > 18`), ); return qb.with(sq).select().from(sq).where(sql`${users.homeCity} = 1`); }); // materialized view const newYorkers2 = pgMaterializedView('new_yorkers') .using('btree') .with({ fillfactor: 90, toast_tuple_target: 0.5, autovacuum_enabled: true, ... }) .tablespace('custom_tablespace') .withNoData() .as((qb) => { const sq = qb .$with('sq') .as( qb.select({ userId: users.id, cityId: cities.id }) .from(users) .leftJoin(cities, eq(cities.id, users.homeCity)) .where(sql`${users.age1} > 18`), ); return qb.with(sq).select().from(sq).where(sql`${users.homeCity} = 1`); }); ``` Source: https://orm.drizzle.team/docs/why-drizzle import Callout from '@mdx/Callout.astro'; import CodeTabs from '@mdx/CodeTabs.astro'; import YoutubeCards from '@mdx/YoutubeCards.astro'; # Drizzle ORM > Drizzle is a good friend who's there for you when necessary and doesn't bother when you need some space. Drizzle ORM is a headless TypeScript ORM with a head. 🐲 It looks and feels simple, performs on day _1000_ of your project, lets you do things your way, and is there when you need it. **It's the only ORM with both [relational](/docs/rqb) and [SQL-like](/docs/select) query APIs**, providing you the best of both worlds when it comes to accessing your relational data. Drizzle is lightweight, performant, typesafe, non-lactose, gluten-free, sober, flexible and **serverless-ready by design**. Drizzle is not just a library, it's an experience. 🤩 [![Drizzle bestofjs](@/assets/images/bestofjs.jpg)](https://bestofjs.org/projects/drizzle-orm) ## Headless ORM? First and foremost, Drizzle is a library and a collection of complementary opt-in tools. **ORM** stands for _object relational mapping_, and developers tend to call Django-like or Spring-like tools an ORM. We truly believe it's a misconception based on legacy nomenclature, and we call them **data frameworks**. With data frameworks you have to build projects **around them** and not **with them**. **Drizzle** lets you build your project the way you want, without interfering with your project or structure. Using Drizzle you can define and manage database schemas in TypeScript, access your data in a SQL-like or relational way, and take advantage of opt-in tools to push your developer experience _through the roof_. 🤯 ## Why SQL-like? **If you know SQL, you know Drizzle.** Other ORMs and data frameworks tend to deviate/abstract you away from SQL, which leads to a double learning curve: needing to know both SQL and the framework's API. Drizzle is the opposite. We embrace SQL and built Drizzle to be SQL-like at its core, so you can have zero to no learning curve and access to the full power of SQL. We bring all the familiar **[SQL schema](/docs/sql-schema-declaration)**, **[queries](/docs/select)**, **[automatic migrations](/docs/migrations)** and **[one more thing](/docs/rqb)**. ✨ ```typescript copy // Access your data await db .select() .from(countries) .leftJoin(cities, eq(cities.countryId, countries.id)) .where(eq(countries.id, 10)) ``` ```typescript copy // manage your schema export const countries = pgTable('countries', { id: serial('id').primaryKey(), name: varchar('name', { length: 256 }), }); export const cities = pgTable('cities', { id: serial('id').primaryKey(), name: varchar('name', { length: 256 }), countryId: integer('country_id').references(() => countries.id), }); ``` ```sql -- generate migrations CREATE TABLE IF NOT EXISTS "countries" ( "id" serial PRIMARY KEY NOT NULL, "name" varchar(256) ); CREATE TABLE IF NOT EXISTS "cities" ( "id" serial PRIMARY KEY NOT NULL, "name" varchar(256), "country_id" integer ); ALTER TABLE "cities" ADD CONSTRAINT "cities_country_id_countries_id_fk" FOREIGN KEY ("country_id") REFERENCES "countries"("id") ON DELETE no action ON UPDATE no action; ``` ## Why not SQL-like? We're always striving for a perfectly balanced solution, and while SQL-like does cover 100% of the needs, there are certain common scenarios where you can query data in a better way. We've built the **[Queries API](/docs/rqb)** for you, so you can fetch relational nested data from the database in the most convenient and performant way, and never think about joins and data mapping. **Drizzle always outputs exactly 1 SQL query.** Feel free to use it with serverless databases and never worry about performance or roundtrip costs! ```ts const result = await db.query.users.findMany({ with: { posts: true }, }); ``` ## Serverless? The best part is no part. **Drizzle has exactly 0 dependencies!** ![Drizzle is slim an Serverless ready](@/assets/images/drizzle31kb.jpg) Drizzle ORM is dialect-specific, slim, performant and serverless-ready **by design**. We've spent a lot of time to make sure you have best-in-class SQL dialect support, including Postgres, MySQL, and others. Drizzle operates natively through industry-standard database drivers. We support all major **[PostgreSQL](/docs/get-started-postgresql)**, **[MySQL](/docs/get-started-mysql)** or **[SQLite](/docs/get-started-sqlite)** drivers out there, and we're adding new ones **[really fast](https://twitter.com/DrizzleORM/status/1653082492742647811?s=20)**. ## Welcome on board! More and more companies are adopting Drizzle in production, experiencing immense benefits in both DX and performance. **We're always there to help, so don't hesitate to reach out. We'll gladly assist you in your Drizzle journey!** We have an outstanding **[Discord community](https://driz.link/discord)** and welcome all builders to our **[Twitter](https://twitter.com/drizzleorm)**. Now go build something awesome with Drizzle and your **[PostgreSQL](/docs/get-started-postgresql)**, **[MySQL](/docs/get-started-mysql)** or **[SQLite](/docs/get-started-sqlite)** database. 🚀 ### Video Showcase {/* tRPC + NextJS App Router = Simple Typesafe APIs Jack Herrington 19:17 https://www.youtube.com/watch?v=qCLV0Iaq9zU */} {/* https://www.youtube.com/watch?v=qDunJ0wVIec */} {/* https://www.youtube.com/watch?v=NZpPMlSAez0 */} {/* https://www.youtube.com/watch?v=-A0kMiJqQRY */} Source: https://orm.drizzle.team/docs/zod import Npm from '@mdx/Npm.astro'; import Callout from '@mdx/Callout.astro'; # drizzle-zod `drizzle-zod` is a plugin for **[Drizzle ORM](https://github.com/drizzle-team/drizzle-orm)** that allows you to generate **[Zod](https://github.com/colinhacks/zod)** schemas from Drizzle ORM schemas. ### Install the dependencies drizzle-zod This documentation is for `drizzle-zod@0.6.0` and higher You must also have Drizzle ORM v0.36.0 or greater and Zod v3.0.0 or greater installed. ### Select schema Defines the shape of data queried from the database - can be used to validate API responses. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-zod'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userSelectSchema = createSelectSchema(users); const rows = await db.select({ id: users.id, name: users.name }).from(users).limit(1); const parsed: { id: number; name: string; age: number } = userSelectSchema.parse(rows[0]); // Error: `age` is not returned in the above query const rows = await db.select().from(users).limit(1); const parsed: { id: number; name: string; age: number } = userSelectSchema.parse(rows[0]); // Will parse successfully ``` Views and enums are also supported. ```ts copy import { pgEnum } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-zod'; const roles = pgEnum('roles', ['admin', 'basic']); const rolesSchema = createSelectSchema(roles); const parsed: 'admin' | 'basic' = rolesSchema.parse(...); const usersView = pgView('users_view').as((qb) => qb.select().from(users).where(gt(users.age, 18))); const usersViewSchema = createSelectSchema(usersView); const parsed: { id: number; name: string; age: number } = usersViewSchema.parse(...); ``` ### Insert schema Defines the shape of data to be inserted into the database - can be used to validate API requests. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createInsertSchema } from 'drizzle-zod'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userInsertSchema = createInsertSchema(users); const user = { name: 'John' }; const parsed: { name: string, age: number } = userInsertSchema.parse(user); // Error: `age` is not defined const user = { name: 'Jane', age: 30 }; const parsed: { name: string, age: number } = userInsertSchema.parse(user); // Will parse successfully await db.insert(users).values(parsed); ``` ### Update schema Defines the shape of data to be updated in the database - can be used to validate API requests. ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createUpdateSchema } from 'drizzle-zod'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const userUpdateSchema = createUpdateSchema(users); const user = { id: 5, name: 'John' }; const parsed: { name?: string | undefined, age?: number | undefined } = userUpdateSchema.parse(user); // Error: `id` is a generated column, it can't be updated const user = { age: 35 }; const parsed: { name?: string | undefined, age?: number | undefined } = userUpdateSchema.parse(user); // Will parse successfully await db.update(users).set(parsed).where(eq(users.name, 'Jane')); ``` ### Refinements Each create schema function accepts an additional optional parameter that you can used to extend, modify or completely overwite a field's schema. Defining a callback function will extend or modify while providing a Zod schema will overwrite it. ```ts copy import { pgTable, text, integer, json } from 'drizzle-orm/pg-core'; import { createSelectSchema } from 'drizzle-zod'; import { z } from 'zod'; const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), bio: text(), preferences: json() }); const userSelectSchema = createSelectSchema(users, { name: (schema) => schema.max(20), // Extends schema bio: (schema) => schema.max(1000), // Extends schema before becoming nullable/optional preferences: z.object({ theme: z.string() }) // Overwrites the field, including its nullability }); const parsed: { id: number; name: string, bio?: string | undefined; preferences: { theme: string; }; } = userSelectSchema.parse(...); ``` ### Factory functions For more advanced use cases, you can use the `createSchemaFactory` function. **Use case: Using an extended Zod instance** ```ts copy import { pgTable, text, integer } from 'drizzle-orm/pg-core'; import { createSchemaFactory } from 'drizzle-zod'; import { z } from '@hono/zod-openapi'; // Extended Zod instance const users = pgTable('users', { id: integer().generatedAlwaysAsIdentity().primaryKey(), name: text().notNull(), age: integer().notNull() }); const { createInsertSchema } = createSchemaFactory({ zodInstance: z }); const userInsertSchema = createInsertSchema(users, { // We can now use the extended instance name: (schema) => schema.openapi({ example: 'John' }) }); ``` **Use case: Type coercion** ```ts copy import { pgTable, timestamp } from 'drizzle-orm/pg-core'; import { createSchemaFactory } from 'drizzle-zod'; import { z } from 'zod'; const users = pgTable('users', { ..., createdAt: timestamp().notNull() }); const { createInsertSchema } = createSchemaFactory({ // This configuration will only coerce dates. Set `coerce` to `true` to coerce all data types or specify others coerce: { date: true } }); const userInsertSchema = createInsertSchema(users); // The above is the same as this: const userInsertSchema = z.object({ ..., createdAt: z.coerce.date() }); ``` ### Data type reference ```ts pg.boolean(); mysql.boolean(); sqlite.integer({ mode: 'boolean' }); // Schema z.boolean(); ``` ```ts pg.date({ mode: 'date' }); pg.timestamp({ mode: 'date' }); mysql.date({ mode: 'date' }); mysql.datetime({ mode: 'date' }); mysql.timestamp({ mode: 'date' }); sqlite.integer({ mode: 'timestamp' }); sqlite.integer({ mode: 'timestamp_ms' }); // Schema z.date(); ``` ```ts pg.date({ mode: 'string' }); pg.timestamp({ mode: 'string' }); pg.cidr(); pg.inet(); pg.interval(); pg.macaddr(); pg.macaddr8(); pg.numeric(); pg.text(); pg.sparsevec(); pg.time(); mysql.binary(); mysql.date({ mode: 'string' }); mysql.datetime({ mode: 'string' }); mysql.decimal(); mysql.time(); mysql.timestamp({ mode: 'string' }); mysql.varbinary(); sqlite.numeric(); sqlite.text({ mode: 'text' }); // Schema z.string(); ``` ```ts pg.bit({ dimensions: ... }); // Schema z.string().regex(/^[01]+$/).max(dimensions); ``` ```ts pg.uuid(); // Schema z.string().uuid(); ``` ```ts pg.char({ length: ... }); mysql.char({ length: ... }); // Schema z.string().length(length); ``` ```ts pg.varchar({ length: ... }); mysql.varchar({ length: ... }); sqlite.text({ mode: 'text', length: ... }); // Schema z.string().max(length); ``` ```ts mysql.tinytext(); // Schema z.string().max(255); // unsigned 8-bit integer limit ``` ```ts mysql.text(); // Schema z.string().max(65_535); // unsigned 16-bit integer limit ``` ```ts mysql.mediumtext(); // Schema z.string().max(16_777_215); // unsigned 24-bit integer limit ``` ```ts mysql.longtext(); // Schema z.string().max(4_294_967_295); // unsigned 32-bit integer limit ``` ```ts pg.text({ enum: ... }); pg.char({ enum: ... }); pg.varchar({ enum: ... }); mysql.tinytext({ enum: ... }); mysql.mediumtext({ enum: ... }); mysql.text({ enum: ... }); mysql.longtext({ enum: ... }); mysql.char({ enum: ... }); mysql.varchar({ enum: ... }); mysql.mysqlEnum(..., ...); sqlite.text({ mode: 'text', enum: ... }); // Schema z.enum(enum); ``` ```ts mysql.tinyint(); // Schema z.number().min(-128).max(127).int(); // 8-bit integer lower and upper limit ``` ```ts mysql.tinyint({ unsigned: true }); // Schema z.number().min(0).max(255).int(); // unsigned 8-bit integer lower and upper limit ``` ```ts pg.smallint(); pg.smallserial(); mysql.smallint(); // Schema z.number().min(-32_768).max(32_767).int(); // 16-bit integer lower and upper limit ``` ```ts mysql.smallint({ unsigned: true }); // Schema z.number().min(0).max(65_535).int(); // unsigned 16-bit integer lower and upper limit ``` ```ts pg.real(); mysql.float(); // Schema z.number().min(-8_388_608).max(8_388_607); // 24-bit integer lower and upper limit ``` ```ts mysql.mediumint(); // Schema z.number().min(-8_388_608).max(8_388_607).int(); // 24-bit integer lower and upper limit ``` ```ts mysql.float({ unsigned: true }); // Schema z.number().min(0).max(16_777_215); // unsigned 24-bit integer lower and upper limit ``` ```ts mysql.mediumint({ unsigned: true }); // Schema z.number().min(0).max(16_777_215).int(); // unsigned 24-bit integer lower and upper limit ``` ```ts pg.integer(); pg.serial(); mysql.int(); // Schema z.number().min(-2_147_483_648).max(2_147_483_647).int(); // 32-bit integer lower and upper limit ``` ```ts mysql.int({ unsigned: true }); // Schema z.number().min(0).max(4_294_967_295).int(); // unsgined 32-bit integer lower and upper limit ``` ```ts pg.doublePrecision(); mysql.double(); mysql.real(); sqlite.real(); // Schema z.number().min(-140_737_488_355_328).max(140_737_488_355_327); // 48-bit integer lower and upper limit ``` ```ts mysql.double({ unsigned: true }); // Schema z.number().min(0).max(281_474_976_710_655); // unsigned 48-bit integer lower and upper limit ``` ```ts pg.bigint({ mode: 'number' }); pg.bigserial({ mode: 'number' }); mysql.bigint({ mode: 'number' }); mysql.bigserial({ mode: 'number' }); sqlite.integer({ mode: 'number' }); // Schema z.number().min(-9_007_199_254_740_991).max(9_007_199_254_740_991).int(); // Javascript min. and max. safe integers ``` ```ts mysql.serial(); // Schema z.number().min(0).max(9_007_199_254_740_991).int(); // Javascript max. safe integer ``` ```ts pg.bigint({ mode: 'bigint' }); pg.bigserial({ mode: 'bigint' }); mysql.bigint({ mode: 'bigint' }); sqlite.blob({ mode: 'bigint' }); // Schema z.bigint().min(-9_223_372_036_854_775_808n).max(9_223_372_036_854_775_807n); // 64-bit integer lower and upper limit ``` ```ts mysql.bigint({ mode: 'bigint', unsigned: true }); // Schema z.bigint().min(0).max(18_446_744_073_709_551_615n); // unsigned 64-bit integer lower and upper limit ``` ```ts mysql.year(); // Schema z.number().min(1_901).max(2_155).int(); ``` ```ts pg.geometry({ type: 'point', mode: 'tuple' }); pg.point({ mode: 'tuple' }); // Schema z.tuple([z.number(), z.number()]); ``` ```ts pg.geometry({ type: 'point', mode: 'xy' }); pg.point({ mode: 'xy' }); // Schema z.object({ x: z.number(), y: z.number() }); ``` ```ts pg.halfvec({ dimensions: ... }); pg.vector({ dimensions: ... }); // Schema z.array(z.number()).length(dimensions); ``` ```ts pg.line({ mode: 'abc' }); // Schema z.object({ a: z.number(), b: z.number(), c: z.number() }); ``` ```ts pg.line({ mode: 'tuple' }); // Schema z.tuple([z.number(), z.number(), z.number()]); ``` ```ts pg.json(); pg.jsonb(); mysql.json(); sqlite.blob({ mode: 'json' }); sqlite.text({ mode: 'json' }); // Schema const self = z.lazy(() => z.union([z.union([z.string(), z.number(), z.boolean(), z.null()]), z.array(self), z.record(self)])); ``` ```ts sqlite.blob({ mode: 'buffer' }); // Schema z.custom((v) => v instanceof Buffer); ``` ```ts pg.dataType().array(...); // Schema z.array(baseDataTypeSchema).length(size); ```