From ee7c40930b9929eedd7b4945489146c50a149145 Mon Sep 17 00:00:00 2001 From: Mario564 Date: Sat, 4 Nov 2023 11:27:26 -0600 Subject: [PATCH 1/7] [PG] Add mising select functions in with clause --- drizzle-orm/src/pg-core/db.ts | 32 +++++++++++++++++++++++++++++++- 1 file changed, 31 insertions(+), 1 deletion(-) diff --git a/drizzle-orm/src/pg-core/db.ts b/drizzle-orm/src/pg-core/db.ts index 6e66e8ca7..27513283f 100644 --- a/drizzle-orm/src/pg-core/db.ts +++ b/drizzle-orm/src/pg-core/db.ts @@ -103,7 +103,37 @@ export class PgDatabase< }); } - return { select }; + function selectDistinct(): PgSelectBuilder; + function selectDistinct(fields: TSelection): PgSelectBuilder; + function selectDistinct(fields?: SelectedFields): PgSelectBuilder { + return new PgSelectBuilder({ + fields: fields ?? undefined, + session: self.session, + dialect: self.dialect, + withList: queries, + distinct: true, + }); + } + + function selectDistinctOn(on: (PgColumn | SQLWrapper)[]): PgSelectBuilder; + function selectDistinctOn( + on: (PgColumn | SQLWrapper)[], + fields: TSelection, + ): PgSelectBuilder; + function selectDistinctOn( + on: (PgColumn | SQLWrapper)[], + fields?: SelectedFields, + ): PgSelectBuilder { + return new PgSelectBuilder({ + fields: fields ?? undefined, + session: self.session, + dialect: self.dialect, + withList: queries, + distinct: { on }, + }); + } + + return { select, selectDistinct, selectDistinctOn }; } select(): PgSelectBuilder; From bc757ba78c470b17bc9c276639d5c28c98ac109e Mon Sep 17 00:00:00 2001 From: Mario564 Date: Mon, 13 Nov 2023 22:05:15 -0600 Subject: [PATCH 2/7] Update `with ... select` test for PG --- integration-tests/tests/pg.test.ts | 40 ++++++++++++++++++++++++++++-- 1 file changed, 38 insertions(+), 2 deletions(-) diff --git a/integration-tests/tests/pg.test.ts b/integration-tests/tests/pg.test.ts index 38fd1a8a3..893ad9730 100644 --- a/integration-tests/tests/pg.test.ts +++ b/integration-tests/tests/pg.test.ts @@ -1515,7 +1515,7 @@ test.serial('with ... select', async (t) => { ), ); - const result = await db + const result1 = await db .with(regionalSales, topRegions) .select({ region: orders.region, @@ -1527,8 +1527,31 @@ test.serial('with ... select', async (t) => { .where(inArray(orders.region, db.select({ region: topRegions.region }).from(topRegions))) .groupBy(orders.region, orders.product) .orderBy(orders.region, orders.product); + const result2 = await db + .with(regionalSales, topRegions) + .selectDistinct({ + region: orders.region, + product: orders.product, + productUnits: sql`sum(${orders.quantity})::int`, + productSales: sql`sum(${orders.amount})::int`, + }) + .from(orders) + .where(inArray(orders.region, db.select({ region: topRegions.region }).from(topRegions))) + .groupBy(orders.region, orders.product) + .orderBy(orders.region, orders.product); + const result3 = await db + .with(regionalSales, topRegions) + .selectDistinctOn([orders.region], { + region: orders.region, + productUnits: sql`sum(${orders.quantity})::int`, + productSales: sql`sum(${orders.amount})::int`, + }) + .from(orders) + .where(inArray(orders.region, db.select({ region: topRegions.region }).from(topRegions))) + .groupBy(orders.region) + .orderBy(orders.region); - t.deepEqual(result, [ + t.deepEqual(result1, [ { region: 'Europe', product: 'A', @@ -1554,6 +1577,19 @@ test.serial('with ... select', async (t) => { productSales: 90, }, ]); + t.deepEqual(result2, result1); + t.deepEqual(result3, [ + { + region: 'Europe', + productUnits: 8, + productSales: 80, + }, + { + region: 'US', + productUnits: 16, + productSales: 160, + }, + ]) }); test.serial('select from subquery sql', async (t) => { From eeef2de67146a6a0b997da07d75d95a3cc24c004 Mon Sep 17 00:00:00 2001 From: Mario564 Date: Wed, 29 Nov 2023 12:17:32 -0600 Subject: [PATCH 3/7] [PG] Add insert, delete and update after with --- drizzle-orm/src/pg-core/db.ts | 176 +++++++++++++++++- drizzle-orm/src/pg-core/dialect.ts | 45 +++-- .../src/pg-core/query-builders/delete.ts | 5 +- .../src/pg-core/query-builders/insert.ts | 8 +- .../src/pg-core/query-builders/update.ts | 7 +- drizzle-typebox/scripts/build.ts | 0 6 files changed, 217 insertions(+), 24 deletions(-) mode change 100755 => 100644 drizzle-typebox/scripts/build.ts diff --git a/drizzle-orm/src/pg-core/db.ts b/drizzle-orm/src/pg-core/db.ts index d5996c3e1..dc03ef012 100644 --- a/drizzle-orm/src/pg-core/db.ts +++ b/drizzle-orm/src/pg-core/db.ts @@ -143,6 +143,42 @@ export class PgDatabase< with(...queries: WithSubquery[]) { const self = this; + /** + * Creates a select query. + * + * Calling this method with no arguments will select all columns from the table. Pass a selection object to specify the columns you want to select. + * + * Use `.from()` method to specify which table to select from. + * + * See docs: {@link https://orm.drizzle.team/docs/select} + * + * @param fields The selection object. + * + * @example + * + * ```ts + * // Select all columns and all rows from the 'cars' table + * const allCars: Car[] = await db.select().from(cars); + * + * // Select specific columns and all rows from the 'cars' table + * const carsIdsAndBrands: { id: number; brand: string }[] = await db.select({ + * id: cars.id, + * brand: cars.brand + * }) + * .from(cars); + * ``` + * + * Like in SQL, you can use arbitrary expressions as selection fields, not just table columns: + * + * ```ts + * // Select specific columns along with expression and all rows from the 'cars' table + * const carsIdsAndLowerNames: { id: number; lowerBrand: string }[] = await db.select({ + * id: cars.id, + * lowerBrand: sql`lower(${cars.brand})`, + * }) + * .from(cars); + * ``` + */ function select(): PgSelectBuilder; function select(fields: TSelection): PgSelectBuilder; function select(fields?: SelectedFields): PgSelectBuilder { @@ -154,6 +190,30 @@ export class PgDatabase< }); } + /** + * Adds `distinct` expression to the select query. + * + * Calling this method will return only unique values. When multiple columns are selected, it returns rows with unique combinations of values in these columns. + * + * Use `.from()` method to specify which table to select from. + * + * See docs: {@link https://orm.drizzle.team/docs/select#distinct} + * + * @param fields The selection object. + * + * @example + * ```ts + * // Select all unique rows from the 'cars' table + * await db.selectDistinct() + * .from(cars) + * .orderBy(cars.id, cars.brand, cars.color); + * + * // Select all unique brands from the 'cars' table + * await db.selectDistinct({ brand: cars.brand }) + * .from(cars) + * .orderBy(cars.brand); + * ``` + */ function selectDistinct(): PgSelectBuilder; function selectDistinct(fields: TSelection): PgSelectBuilder; function selectDistinct(fields?: SelectedFields): PgSelectBuilder { @@ -166,6 +226,31 @@ export class PgDatabase< }); } + /** + * Adds `distinct on` expression to the select query. + * + * Calling this method will specify how the unique rows are determined. + * + * Use `.from()` method to specify which table to select from. + * + * See docs: {@link https://orm.drizzle.team/docs/select#distinct} + * + * @param on The expression defining uniqueness. + * @param fields The selection object. + * + * @example + * ```ts + * // Select the first row for each unique brand from the 'cars' table + * await db.selectDistinctOn([cars.brand]) + * .from(cars) + * .orderBy(cars.brand); + * + * // Selects the first occurrence of each unique car brand along with its color from the 'cars' table + * await db.selectDistinctOn([cars.brand], { brand: cars.brand, color: cars.color }) + * .from(cars) + * .orderBy(cars.brand, cars.color); + * ``` + */ function selectDistinctOn(on: (PgColumn | SQLWrapper)[]): PgSelectBuilder; function selectDistinctOn( on: (PgColumn | SQLWrapper)[], @@ -184,8 +269,95 @@ export class PgDatabase< }); } - return { select, selectDistinct, selectDistinctOn }; - } + /** + * Creates an update query. + * + * Calling this method without `.where()` clause will update all rows in a table. The `.where()` clause specifies which rows should be updated. + * + * Use `.set()` method to specify which values to update. + * + * See docs: {@link https://orm.drizzle.team/docs/update} + * + * @param table The table to update. + * + * @example + * + * ```ts + * // Update all rows in the 'cars' table + * await db.update(cars).set({ color: 'red' }); + * + * // Update rows with filters and conditions + * await db.update(cars).set({ color: 'red' }).where(eq(cars.brand, 'BMW')); + * + * // Update with returning clause + * const updatedCar: Car[] = await db.update(cars) + * .set({ color: 'red' }) + * .where(eq(cars.id, 1)) + * .returning(); + * ``` + */ + function update(table: TTable): PgUpdateBuilder { + return new PgUpdateBuilder(table, self.session, self.dialect, queries); + } + + /** + * Creates an insert query. + * + * Calling this method will create new rows in a table. Use `.values()` method to specify which values to insert. + * + * See docs: {@link https://orm.drizzle.team/docs/insert} + * + * @param table The table to insert into. + * + * @example + * + * ```ts + * // Insert one row + * await db.insert(cars).values({ brand: 'BMW' }); + * + * // Insert multiple rows + * await db.insert(cars).values([{ brand: 'BMW' }, { brand: 'Porsche' }]); + * + * // Insert with returning clause + * const insertedCar: Car[] = await db.insert(cars) + * .values({ brand: 'BMW' }) + * .returning(); + * ``` + */ + function insert(table: TTable): PgInsertBuilder { + return new PgInsertBuilder(table, self.session, self.dialect, queries); + } + + /** + * Creates a delete query. + * + * Calling this method without `.where()` clause will delete all rows in a table. The `.where()` clause specifies which rows should be deleted. + * + * See docs: {@link https://orm.drizzle.team/docs/delete} + * + * @param table The table to delete from. + * + * @example + * + * ```ts + * // Delete all rows in the 'cars' table + * await db.delete(cars); + * + * // Delete rows with filters and conditions + * await db.delete(cars).where(eq(cars.color, 'green')); + * + * // Delete with returning clause + * const deletedCar: Car[] = await db.delete(cars) + * .where(eq(cars.id, 1)) + * .returning(); + * ``` + */ + function delete_(table: TTable): PgDeleteBase { + return new PgDeleteBase(table, self.session, self.dialect, queries); + } + + return { select, selectDistinct, selectDistinctOn, update, insert, delete: delete_ }; + } /** * Creates a select query. diff --git a/drizzle-orm/src/pg-core/dialect.ts b/drizzle-orm/src/pg-core/dialect.ts index cf47d1e11..6c189b933 100644 --- a/drizzle-orm/src/pg-core/dialect.ts +++ b/drizzle-orm/src/pg-core/dialect.ts @@ -91,14 +91,30 @@ export class PgDialect { return `'${str.replace(/'/g, "''")}'`; } - buildDeleteQuery({ table, where, returning }: PgDeleteConfig): SQL { + private buildWithCTE(queries: Subquery[] | undefined): SQL | undefined { + if (!queries?.length) return undefined; + + const withSqlChunks = [sql`with `]; + for (const [i, w] of queries.entries()) { + withSqlChunks.push(sql`${sql.identifier(w[SubqueryConfig].alias)} as (${w[SubqueryConfig].sql})`); + if (i < queries.length - 1) { + withSqlChunks.push(sql`, `); + } + } + withSqlChunks.push(sql` `); + return sql.join(withSqlChunks); + } + + buildDeleteQuery({ table, where, returning, withList }: PgDeleteConfig): SQL { + const withSql = this.buildWithCTE(withList); + const returningSql = returning ? sql` returning ${this.buildSelection(returning, { isSingleTable: true })}` : undefined; const whereSql = where ? sql` where ${where}` : undefined; - return sql`delete from ${table}${whereSql}${returningSql}`; + return sql`${withSql}delete from ${table}${whereSql}${returningSql}`; } buildUpdateSet(table: PgTable, set: UpdateSet): SQL { @@ -118,7 +134,9 @@ export class PgDialect { ); } - buildUpdateQuery({ table, set, where, returning }: PgUpdateConfig): SQL { + buildUpdateQuery({ table, set, where, returning, withList }: PgUpdateConfig): SQL { + const withSql = this.buildWithCTE(withList); + const setSql = this.buildUpdateSet(table, set); const returningSql = returning @@ -127,7 +145,7 @@ export class PgDialect { const whereSql = where ? sql` where ${where}` : undefined; - return sql`update ${table} set ${setSql}${whereSql}${returningSql}`; + return sql`${withSql}update ${table} set ${setSql}${whereSql}${returningSql}`; } /** @@ -238,18 +256,7 @@ export class PgDialect { const isSingleTable = !joins || joins.length === 0; - let withSql: SQL | undefined; - if (withList?.length) { - const withSqlChunks = [sql`with `]; - for (const [i, w] of withList.entries()) { - withSqlChunks.push(sql`${sql.identifier(w[SubqueryConfig].alias)} as (${w[SubqueryConfig].sql})`); - if (i < withList.length - 1) { - withSqlChunks.push(sql`, `); - } - } - withSqlChunks.push(sql` `); - withSql = sql.join(withSqlChunks); - } + const withSql = this.buildWithCTE(withList); let distinctSql: SQL | undefined; if (distinct) { @@ -422,7 +429,7 @@ export class PgDialect { return sql`${leftChunk}${operatorChunk}${rightChunk}${orderBySql}${limitSql}${offsetSql}`; } - buildInsertQuery({ table, values, onConflict, returning }: PgInsertConfig): SQL { + buildInsertQuery({ table, values, onConflict, returning, withList }: PgInsertConfig): SQL { const valuesSqlList: ((SQLChunk | SQL)[] | SQL)[] = []; const columns: Record = table[Table.Symbol.Columns]; @@ -454,6 +461,8 @@ export class PgDialect { } } + const withSql = this.buildWithCTE(withList); + const valuesSql = sql.join(valuesSqlList); const returningSql = returning @@ -462,7 +471,7 @@ export class PgDialect { const onConflictSql = onConflict ? sql` on conflict ${onConflict}` : undefined; - return sql`insert into ${table} ${insertOrder} values ${valuesSql}${onConflictSql}${returningSql}`; + return sql`${withSql}insert into ${table} ${insertOrder} values ${valuesSql}${onConflictSql}${returningSql}`; } buildRefreshMaterializedViewQuery( diff --git a/drizzle-orm/src/pg-core/query-builders/delete.ts b/drizzle-orm/src/pg-core/query-builders/delete.ts index df22a110e..f439f0f57 100644 --- a/drizzle-orm/src/pg-core/query-builders/delete.ts +++ b/drizzle-orm/src/pg-core/query-builders/delete.ts @@ -16,6 +16,7 @@ import { tracer } from '~/tracing.ts'; import { orderSelectedFields } from '~/utils.ts'; import type { SelectedFieldsFlat, SelectedFieldsOrdered } from './select.types.ts'; import type { PgColumn } from '../columns/common.ts'; +import type { Subquery } from '~/subquery.ts'; export type PgDeleteWithout< T extends AnyPgDeleteBase, @@ -43,6 +44,7 @@ export interface PgDeleteConfig { where?: SQL | undefined; table: PgTable; returning?: SelectedFieldsOrdered; + withList?: Subquery[]; } export type PgDeleteReturningAll< @@ -125,9 +127,10 @@ export class PgDeleteBase< table: TTable, private session: PgSession, private dialect: PgDialect, + withList?: Subquery[], ) { super(); - this.config = { table }; + this.config = { table, withList }; } /** diff --git a/drizzle-orm/src/pg-core/query-builders/insert.ts b/drizzle-orm/src/pg-core/query-builders/insert.ts index b4ec31a93..c4443e561 100644 --- a/drizzle-orm/src/pg-core/query-builders/insert.ts +++ b/drizzle-orm/src/pg-core/query-builders/insert.ts @@ -19,10 +19,12 @@ import { mapUpdateSet, orderSelectedFields } from '~/utils.ts'; import type { SelectedFieldsFlat, SelectedFieldsOrdered } from './select.types.ts'; import type { PgUpdateSetSource } from './update.ts'; import type { PgColumn } from '../columns/common.ts'; +import type { Subquery } from '~/subquery.ts'; export interface PgInsertConfig { table: TTable; values: Record[]; + withList?: Subquery[]; onConflict?: SQL; returning?: SelectedFieldsOrdered; } @@ -40,6 +42,7 @@ export class PgInsertBuilder): PgInsertBase; @@ -59,7 +62,7 @@ export class PgInsertBuilder = @@ -43,6 +45,7 @@ export class PgUpdateBuilder): PgUpdateBase { @@ -51,6 +54,7 @@ export class PgUpdateBuilder Date: Wed, 29 Nov 2023 17:26:34 -0600 Subject: [PATCH 4/7] [MySQL | SQLite] Extend with clause Add update, insert and delete methods to with clause for MySQL and SQLite --- drizzle-orm/src/mysql-core/db.ts | 110 ++++++++++++- drizzle-orm/src/mysql-core/dialect.ts | 39 +++-- .../src/mysql-core/query-builders/delete.ts | 5 +- .../src/mysql-core/query-builders/update.ts | 8 +- drizzle-orm/src/pg-core/db.ts | 4 +- drizzle-orm/src/sqlite-core/db.ts | 150 +++++++++++++++++- drizzle-orm/src/sqlite-core/dialect.ts | 45 +++--- .../src/sqlite-core/query-builders/delete.ts | 5 +- .../src/sqlite-core/query-builders/insert.ts | 8 +- .../src/sqlite-core/query-builders/update.ts | 8 +- 10 files changed, 336 insertions(+), 46 deletions(-) diff --git a/drizzle-orm/src/mysql-core/db.ts b/drizzle-orm/src/mysql-core/db.ts index dc0b9bb31..b9c0e7b17 100644 --- a/drizzle-orm/src/mysql-core/db.ts +++ b/drizzle-orm/src/mysql-core/db.ts @@ -147,6 +147,42 @@ export class MySqlDatabase< with(...queries: WithSubquery[]) { const self = this; + /** + * Creates a select query. + * + * Calling this method with no arguments will select all columns from the table. Pass a selection object to specify the columns you want to select. + * + * Use `.from()` method to specify which table to select from. + * + * See docs: {@link https://orm.drizzle.team/docs/select} + * + * @param fields The selection object. + * + * @example + * + * ```ts + * // Select all columns and all rows from the 'cars' table + * const allCars: Car[] = await db.select().from(cars); + * + * // Select specific columns and all rows from the 'cars' table + * const carsIdsAndBrands: { id: number; brand: string }[] = await db.select({ + * id: cars.id, + * brand: cars.brand + * }) + * .from(cars); + * ``` + * + * Like in SQL, you can use arbitrary expressions as selection fields, not just table columns: + * + * ```ts + * // Select specific columns along with expression and all rows from the 'cars' table + * const carsIdsAndLowerNames: { id: number; lowerBrand: string }[] = await db.select({ + * id: cars.id, + * lowerBrand: sql`lower(${cars.brand})`, + * }) + * .from(cars); + * ``` + */ function select(): MySqlSelectBuilder; function select( fields: TSelection, @@ -160,6 +196,30 @@ export class MySqlDatabase< }); } + /** + * Adds `distinct` expression to the select query. + * + * Calling this method will return only unique values. When multiple columns are selected, it returns rows with unique combinations of values in these columns. + * + * Use `.from()` method to specify which table to select from. + * + * See docs: {@link https://orm.drizzle.team/docs/select#distinct} + * + * @param fields The selection object. + * + * @example + * ```ts + * // Select all unique rows from the 'cars' table + * await db.selectDistinct() + * .from(cars) + * .orderBy(cars.id, cars.brand, cars.color); + * + * // Select all unique brands from the 'cars' table + * await db.selectDistinct({ brand: cars.brand }) + * .from(cars) + * .orderBy(cars.brand); + * ``` + */ function selectDistinct(): MySqlSelectBuilder; function selectDistinct( fields: TSelection, @@ -176,7 +236,55 @@ export class MySqlDatabase< }); } - return { select, selectDistinct }; + /** + * Creates an update query. + * + * Calling this method without `.where()` clause will update all rows in a table. The `.where()` clause specifies which rows should be updated. + * + * Use `.set()` method to specify which values to update. + * + * See docs: {@link https://orm.drizzle.team/docs/update} + * + * @param table The table to update. + * + * @example + * + * ```ts + * // Update all rows in the 'cars' table + * await db.update(cars).set({ color: 'red' }); + * + * // Update rows with filters and conditions + * await db.update(cars).set({ color: 'red' }).where(eq(cars.brand, 'BMW')); + * ``` + */ + function update(table: TTable): MySqlUpdateBuilder { + return new MySqlUpdateBuilder(table, self.session, self.dialect, queries); + } + + /** + * Creates a delete query. + * + * Calling this method without `.where()` clause will delete all rows in a table. The `.where()` clause specifies which rows should be deleted. + * + * See docs: {@link https://orm.drizzle.team/docs/delete} + * + * @param table The table to delete from. + * + * @example + * + * ```ts + * // Delete all rows in the 'cars' table + * await db.delete(cars); + * + * // Delete rows with filters and conditions + * await db.delete(cars).where(eq(cars.color, 'green')); + * ``` + */ + function delete_(table: TTable): MySqlDeleteBase { + return new MySqlDeleteBase(table, self.session, self.dialect, queries); + } + + return { select, selectDistinct, update, delete: delete_ }; } /** diff --git a/drizzle-orm/src/mysql-core/dialect.ts b/drizzle-orm/src/mysql-core/dialect.ts index 34d5bf907..69bcef9c4 100644 --- a/drizzle-orm/src/mysql-core/dialect.ts +++ b/drizzle-orm/src/mysql-core/dialect.ts @@ -79,14 +79,30 @@ export class MySqlDialect { return `'${str.replace(/'/g, "''")}'`; } - buildDeleteQuery({ table, where, returning }: MySqlDeleteConfig): SQL { + private buildWithCTE(queries: Subquery[] | undefined): SQL | undefined { + if (!queries?.length) return undefined; + + const withSqlChunks = [sql`with `]; + for (const [i, w] of queries.entries()) { + withSqlChunks.push(sql`${sql.identifier(w[SubqueryConfig].alias)} as (${w[SubqueryConfig].sql})`); + if (i < queries.length - 1) { + withSqlChunks.push(sql`, `); + } + } + withSqlChunks.push(sql` `); + return sql.join(withSqlChunks); + } + + buildDeleteQuery({ table, where, returning, withList }: MySqlDeleteConfig): SQL { + const withSql = this.buildWithCTE(withList); + const returningSql = returning ? sql` returning ${this.buildSelection(returning, { isSingleTable: true })}` : undefined; const whereSql = where ? sql` where ${where}` : undefined; - return sql`delete from ${table}${whereSql}${returningSql}`; + return sql`${withSql}delete from ${table}${whereSql}${returningSql}`; } buildUpdateSet(table: MySqlTable, set: UpdateSet): SQL { @@ -106,7 +122,9 @@ export class MySqlDialect { ); } - buildUpdateQuery({ table, set, where, returning }: MySqlUpdateConfig): SQL { + buildUpdateQuery({ table, set, where, returning, withList }: MySqlUpdateConfig): SQL { + const withSql = this.buildWithCTE(withList); + const setSql = this.buildUpdateSet(table, set); const returningSql = returning @@ -115,7 +133,7 @@ export class MySqlDialect { const whereSql = where ? sql` where ${where}` : undefined; - return sql`update ${table} set ${setSql}${whereSql}${returningSql}`; + return sql`${withSql}update ${table} set ${setSql}${whereSql}${returningSql}`; } /** @@ -226,18 +244,7 @@ export class MySqlDialect { const isSingleTable = !joins || joins.length === 0; - let withSql: SQL | undefined; - if (withList?.length) { - const withSqlChunks = [sql`with `]; - for (const [i, w] of withList.entries()) { - withSqlChunks.push(sql`${sql.identifier(w[SubqueryConfig].alias)} as (${w[SubqueryConfig].sql})`); - if (i < withList.length - 1) { - withSqlChunks.push(sql`, `); - } - } - withSqlChunks.push(sql` `); - withSql = sql.join(withSqlChunks); - } + const withSql = this.buildWithCTE(withList); const distinctSql = distinct ? sql` distinct` : undefined; diff --git a/drizzle-orm/src/mysql-core/query-builders/delete.ts b/drizzle-orm/src/mysql-core/query-builders/delete.ts index ab615c603..a2c8c451c 100644 --- a/drizzle-orm/src/mysql-core/query-builders/delete.ts +++ b/drizzle-orm/src/mysql-core/query-builders/delete.ts @@ -13,6 +13,7 @@ import type { MySqlTable } from '~/mysql-core/table.ts'; import { QueryPromise } from '~/query-promise.ts'; import type { Query, SQL, SQLWrapper } from '~/sql/sql.ts'; import type { SelectedFieldsOrdered } from './select.types.ts'; +import type { Subquery } from '~/subquery.ts'; export type MySqlDeleteWithout< T extends AnyMySqlDeleteBase, @@ -40,6 +41,7 @@ export interface MySqlDeleteConfig { where?: SQL | undefined; table: MySqlTable; returning?: SelectedFieldsOrdered; + withList?: Subquery[]; } export type MySqlDeletePrepare = PreparedQueryKind< @@ -92,9 +94,10 @@ export class MySqlDeleteBase< private table: TTable, private session: MySqlSession, private dialect: MySqlDialect, + withList?: Subquery[], ) { super(); - this.config = { table }; + this.config = { table, withList }; } /** diff --git a/drizzle-orm/src/mysql-core/query-builders/update.ts b/drizzle-orm/src/mysql-core/query-builders/update.ts index ce83e9b4b..099b30d71 100644 --- a/drizzle-orm/src/mysql-core/query-builders/update.ts +++ b/drizzle-orm/src/mysql-core/query-builders/update.ts @@ -15,12 +15,14 @@ import { QueryPromise } from '~/query-promise.ts'; import type { Query, SQL, SQLWrapper } from '~/sql/sql.ts'; import { mapUpdateSet, type UpdateSet } from '~/utils.ts'; import type { SelectedFieldsOrdered } from './select.types.ts'; +import type { Subquery } from '~/subquery.ts'; export interface MySqlUpdateConfig { where?: SQL | undefined; set: UpdateSet; table: MySqlTable; returning?: SelectedFieldsOrdered; + withList?: Subquery[]; } export type MySqlUpdateSetSource = @@ -46,10 +48,11 @@ export class MySqlUpdateBuilder< private table: TTable, private session: MySqlSession, private dialect: MySqlDialect, + private withList?: Subquery[], ) {} set(values: MySqlUpdateSetSource): MySqlUpdateBase { - return new MySqlUpdateBase(this.table, mapUpdateSet(this.table, values), this.session, this.dialect); + return new MySqlUpdateBase(this.table, mapUpdateSet(this.table, values), this.session, this.dialect, this.withList); } } @@ -126,9 +129,10 @@ export class MySqlUpdateBase< set: UpdateSet, private session: MySqlSession, private dialect: MySqlDialect, + withList?: Subquery[], ) { super(); - this.config = { set, table }; + this.config = { set, table, withList }; } /** diff --git a/drizzle-orm/src/pg-core/db.ts b/drizzle-orm/src/pg-core/db.ts index dc03ef012..5627de810 100644 --- a/drizzle-orm/src/pg-core/db.ts +++ b/drizzle-orm/src/pg-core/db.ts @@ -356,8 +356,8 @@ export class PgDatabase< return new PgDeleteBase(table, self.session, self.dialect, queries); } - return { select, selectDistinct, selectDistinctOn, update, insert, delete: delete_ }; - } + return { select, selectDistinct, selectDistinctOn, update, insert, delete: delete_ }; + } /** * Creates a select query. diff --git a/drizzle-orm/src/sqlite-core/db.ts b/drizzle-orm/src/sqlite-core/db.ts index f98fea324..97ae5de3d 100644 --- a/drizzle-orm/src/sqlite-core/db.ts +++ b/drizzle-orm/src/sqlite-core/db.ts @@ -144,6 +144,42 @@ export class BaseSQLiteDatabase< with(...queries: WithSubquery[]) { const self = this; + /** + * Creates a select query. + * + * Calling this method with no arguments will select all columns from the table. Pass a selection object to specify the columns you want to select. + * + * Use `.from()` method to specify which table to select from. + * + * See docs: {@link https://orm.drizzle.team/docs/select} + * + * @param fields The selection object. + * + * @example + * + * ```ts + * // Select all columns and all rows from the 'cars' table + * const allCars: Car[] = await db.select().from(cars); + * + * // Select specific columns and all rows from the 'cars' table + * const carsIdsAndBrands: { id: number; brand: string }[] = await db.select({ + * id: cars.id, + * brand: cars.brand + * }) + * .from(cars); + * ``` + * + * Like in SQL, you can use arbitrary expressions as selection fields, not just table columns: + * + * ```ts + * // Select specific columns along with expression and all rows from the 'cars' table + * const carsIdsAndLowerNames: { id: number; lowerBrand: string }[] = await db.select({ + * id: cars.id, + * lowerBrand: sql`lower(${cars.brand})`, + * }) + * .from(cars); + * ``` + */ function select(): SQLiteSelectBuilder; function select( fields: TSelection, @@ -159,6 +195,31 @@ export class BaseSQLiteDatabase< }); } + /** + * Adds `distinct` expression to the select query. + * + * Calling this method will return only unique values. When multiple columns are selected, it returns rows with unique combinations of values in these columns. + * + * Use `.from()` method to specify which table to select from. + * + * See docs: {@link https://orm.drizzle.team/docs/select#distinct} + * + * @param fields The selection object. + * + * @example + * + * ```ts + * // Select all unique rows from the 'cars' table + * await db.selectDistinct() + * .from(cars) + * .orderBy(cars.id, cars.brand, cars.color); + * + * // Select all unique brands from the 'cars' table + * await db.selectDistinct({ brand: cars.brand }) + * .from(cars) + * .orderBy(cars.brand); + * ``` + */ function selectDistinct(): SQLiteSelectBuilder; function selectDistinct( fields: TSelection, @@ -175,7 +236,94 @@ export class BaseSQLiteDatabase< }); } - return { select, selectDistinct }; + /** + * Creates an update query. + * + * Calling this method without `.where()` clause will update all rows in a table. The `.where()` clause specifies which rows should be updated. + * + * Use `.set()` method to specify which values to update. + * + * See docs: {@link https://orm.drizzle.team/docs/update} + * + * @param table The table to update. + * + * @example + * + * ```ts + * // Update all rows in the 'cars' table + * await db.update(cars).set({ color: 'red' }); + * + * // Update rows with filters and conditions + * await db.update(cars).set({ color: 'red' }).where(eq(cars.brand, 'BMW')); + * + * // Update with returning clause + * const updatedCar: Car[] = await db.update(cars) + * .set({ color: 'red' }) + * .where(eq(cars.id, 1)) + * .returning(); + * ``` + */ + function update(table: TTable): SQLiteUpdateBuilder { + return new SQLiteUpdateBuilder(table, self.session, self.dialect, queries); + } + + /** + * Creates an insert query. + * + * Calling this method will create new rows in a table. Use `.values()` method to specify which values to insert. + * + * See docs: {@link https://orm.drizzle.team/docs/insert} + * + * @param table The table to insert into. + * + * @example + * + * ```ts + * // Insert one row + * await db.insert(cars).values({ brand: 'BMW' }); + * + * // Insert multiple rows + * await db.insert(cars).values([{ brand: 'BMW' }, { brand: 'Porsche' }]); + * + * // Insert with returning clause + * const insertedCar: Car[] = await db.insert(cars) + * .values({ brand: 'BMW' }) + * .returning(); + * ``` + */ + function insert(into: TTable): SQLiteInsertBuilder { + return new SQLiteInsertBuilder(into, self.session, self.dialect, queries); + } + + /** + * Creates a delete query. + * + * Calling this method without `.where()` clause will delete all rows in a table. The `.where()` clause specifies which rows should be deleted. + * + * See docs: {@link https://orm.drizzle.team/docs/delete} + * + * @param table The table to delete from. + * + * @example + * + * ```ts + * // Delete all rows in the 'cars' table + * await db.delete(cars); + * + * // Delete rows with filters and conditions + * await db.delete(cars).where(eq(cars.color, 'green')); + * + * // Delete with returning clause + * const deletedCar: Car[] = await db.delete(cars) + * .where(eq(cars.id, 1)) + * .returning(); + * ``` + */ + function delete_(from: TTable): SQLiteDeleteBase { + return new SQLiteDeleteBase(from, self.session, self.dialect, queries); + } + + return { select, selectDistinct, update, insert, delete: delete_ }; } /** diff --git a/drizzle-orm/src/sqlite-core/dialect.ts b/drizzle-orm/src/sqlite-core/dialect.ts index d58ef419e..2ab760f06 100644 --- a/drizzle-orm/src/sqlite-core/dialect.ts +++ b/drizzle-orm/src/sqlite-core/dialect.ts @@ -49,14 +49,30 @@ export abstract class SQLiteDialect { return `'${str.replace(/'/g, "''")}'`; } - buildDeleteQuery({ table, where, returning }: SQLiteDeleteConfig): SQL { + private buildWithCTE(queries: Subquery[] | undefined): SQL | undefined { + if (!queries?.length) return undefined; + + const withSqlChunks = [sql`with `]; + for (const [i, w] of queries.entries()) { + withSqlChunks.push(sql`${sql.identifier(w[SubqueryConfig].alias)} as (${w[SubqueryConfig].sql})`); + if (i < queries.length - 1) { + withSqlChunks.push(sql`, `); + } + } + withSqlChunks.push(sql` `); + return sql.join(withSqlChunks); + } + + buildDeleteQuery({ table, where, returning, withList }: SQLiteDeleteConfig): SQL { + const withSql = this.buildWithCTE(withList); + const returningSql = returning ? sql` returning ${this.buildSelection(returning, { isSingleTable: true })}` : undefined; const whereSql = where ? sql` where ${where}` : undefined; - return sql`delete from ${table}${whereSql}${returningSql}`; + return sql`${withSql}delete from ${table}${whereSql}${returningSql}`; } buildUpdateSet(table: SQLiteTable, set: UpdateSet): SQL { @@ -76,7 +92,9 @@ export abstract class SQLiteDialect { ); } - buildUpdateQuery({ table, set, where, returning }: SQLiteUpdateConfig): SQL { + buildUpdateQuery({ table, set, where, returning, withList }: SQLiteUpdateConfig): SQL { + const withSql = this.buildWithCTE(withList); + const setSql = this.buildUpdateSet(table, set); const returningSql = returning @@ -85,7 +103,7 @@ export abstract class SQLiteDialect { const whereSql = where ? sql` where ${where}` : undefined; - return sql`update ${table} set ${setSql}${whereSql}${returningSql}`; + return sql`${withSql}update ${table} set ${setSql}${whereSql}${returningSql}`; } /** @@ -197,18 +215,7 @@ export abstract class SQLiteDialect { const isSingleTable = !joins || joins.length === 0; - let withSql: SQL | undefined; - if (withList?.length) { - const withSqlChunks = [sql`with `]; - for (const [i, w] of withList.entries()) { - withSqlChunks.push(sql`${sql.identifier(w[SubqueryConfig].alias)} as (${w[SubqueryConfig].sql})`); - if (i < withList.length - 1) { - withSqlChunks.push(sql`, `); - } - } - withSqlChunks.push(sql` `); - withSql = sql.join(withSqlChunks); - } + const withSql = this.buildWithCTE(withList); const distinctSql = distinct ? sql` distinct` : undefined; @@ -360,7 +367,7 @@ export abstract class SQLiteDialect { return sql`${leftChunk}${operatorChunk}${rightChunk}${orderBySql}${limitSql}${offsetSql}`; } - buildInsertQuery({ table, values, onConflict, returning }: SQLiteInsertConfig): SQL { + buildInsertQuery({ table, values, onConflict, returning, withList }: SQLiteInsertConfig): SQL { // const isSingleValue = values.length === 1; const valuesSqlList: ((SQLChunk | SQL)[] | SQL)[] = []; const columns: Record = table[Table.Symbol.Columns]; @@ -394,6 +401,8 @@ export abstract class SQLiteDialect { } } + const withSql = this.buildWithCTE(withList); + const valuesSql = sql.join(valuesSqlList); const returningSql = returning @@ -406,7 +415,7 @@ export abstract class SQLiteDialect { // return sql`insert into ${table} default values ${onConflictSql}${returningSql}`; // } - return sql`insert into ${table} ${insertOrder} values ${valuesSql}${onConflictSql}${returningSql}`; + return sql`${withSql}insert into ${table} ${insertOrder} values ${valuesSql}${onConflictSql}${returningSql}`; } sqlToQuery(sql: SQL): QueryWithTypings { diff --git a/drizzle-orm/src/sqlite-core/query-builders/delete.ts b/drizzle-orm/src/sqlite-core/query-builders/delete.ts index 2fa983c12..23801b95c 100644 --- a/drizzle-orm/src/sqlite-core/query-builders/delete.ts +++ b/drizzle-orm/src/sqlite-core/query-builders/delete.ts @@ -9,6 +9,7 @@ import { SQLiteTable } from '~/sqlite-core/table.ts'; import { type DrizzleTypeError, orderSelectedFields } from '~/utils.ts'; import type { SelectedFieldsFlat, SelectedFieldsOrdered } from './select.types.ts'; import type { SQLiteColumn } from '../columns/common.ts'; +import type { Subquery } from '~/subquery.ts'; export type SQLiteDeleteWithout< T extends AnySQLiteDeleteBase, @@ -38,6 +39,7 @@ export interface SQLiteDeleteConfig { where?: SQL | undefined; table: SQLiteTable; returning?: SelectedFieldsOrdered; + withList?: Subquery[]; } export type SQLiteDeleteReturningAll< @@ -139,9 +141,10 @@ export class SQLiteDeleteBase< private table: TTable, private session: SQLiteSession, private dialect: SQLiteDialect, + withList?: Subquery[], ) { super(); - this.config = { table }; + this.config = { table, withList }; } /** diff --git a/drizzle-orm/src/sqlite-core/query-builders/insert.ts b/drizzle-orm/src/sqlite-core/query-builders/insert.ts index 4f2e23320..f14b34881 100644 --- a/drizzle-orm/src/sqlite-core/query-builders/insert.ts +++ b/drizzle-orm/src/sqlite-core/query-builders/insert.ts @@ -13,10 +13,12 @@ import { type DrizzleTypeError, mapUpdateSet, orderSelectedFields, type Simplify import type { SelectedFieldsFlat, SelectedFieldsOrdered } from './select.types.ts'; import type { SQLiteUpdateSetSource } from './update.ts'; import type { SQLiteColumn } from '../columns/common.ts'; +import type { Subquery } from '~/subquery.ts'; export interface SQLiteInsertConfig { table: TTable; values: Record[]; + withList?: Subquery[]; onConflict?: SQL; returning?: SelectedFieldsOrdered; } @@ -38,6 +40,7 @@ export class SQLiteInsertBuilder< protected table: TTable, protected session: SQLiteSession, protected dialect: SQLiteDialect, + private withList?: Subquery[], ) {} values(value: SQLiteInsertValue): SQLiteInsertBase; @@ -65,7 +68,7 @@ export class SQLiteInsertBuilder< // ); // } - return new SQLiteInsertBase(this.table, mappedValues, this.session, this.dialect); + return new SQLiteInsertBase(this.table, mappedValues, this.session, this.dialect, this.withList); } } @@ -202,9 +205,10 @@ export class SQLiteInsertBase< values: SQLiteInsertConfig['values'], private session: SQLiteSession, private dialect: SQLiteDialect, + withList?: Subquery[], ) { super(); - this.config = { table, values }; + this.config = { table, values, withList }; } /** diff --git a/drizzle-orm/src/sqlite-core/query-builders/update.ts b/drizzle-orm/src/sqlite-core/query-builders/update.ts index f07a1cac6..895a421b3 100644 --- a/drizzle-orm/src/sqlite-core/query-builders/update.ts +++ b/drizzle-orm/src/sqlite-core/query-builders/update.ts @@ -10,12 +10,14 @@ import { SQLiteTable } from '~/sqlite-core/table.ts'; import { type DrizzleTypeError, mapUpdateSet, orderSelectedFields, type UpdateSet } from '~/utils.ts'; import type { SelectedFields, SelectedFieldsOrdered } from './select.types.ts'; import type { SQLiteColumn } from '../columns/common.ts'; +import type { Subquery } from '~/subquery.ts'; export interface SQLiteUpdateConfig { where?: SQL | undefined; set: UpdateSet; table: SQLiteTable; returning?: SelectedFieldsOrdered; + withList?: Subquery[]; } export type SQLiteUpdateSetSource = @@ -41,10 +43,11 @@ export class SQLiteUpdateBuilder< protected table: TTable, protected session: SQLiteSession, protected dialect: SQLiteDialect, + private withList?: Subquery[], ) {} set(values: SQLiteUpdateSetSource): SQLiteUpdateBase { - return new SQLiteUpdateBase(this.table, mapUpdateSet(this.table, values), this.session, this.dialect); + return new SQLiteUpdateBase(this.table, mapUpdateSet(this.table, values), this.session, this.dialect, this.withList); } } @@ -170,9 +173,10 @@ export class SQLiteUpdateBase< set: UpdateSet, private session: SQLiteSession, private dialect: SQLiteDialect, + withList?: Subquery[], ) { super(); - this.config = { set, table }; + this.config = { set, table, withList }; } /** From 217369a1911fb1ac7f0b0904422a9a4f408bf631 Mon Sep 17 00:00:00 2001 From: Mario564 Date: Wed, 29 Nov 2023 17:28:47 -0600 Subject: [PATCH 5/7] Add with clause tests Add tests for `db.with().insert()`, `db.with().delete()` and `db.with().update()` for all dialects --- integration-tests/tests/libsql.test.ts | 129 ++++++++++++++++++++++++- integration-tests/tests/mysql.test.ts | 118 ++++++++++++++++++++++ integration-tests/tests/pg.test.ts | 126 ++++++++++++++++++++++++ 3 files changed, 372 insertions(+), 1 deletion(-) diff --git a/integration-tests/tests/libsql.test.ts b/integration-tests/tests/libsql.test.ts index 762f9ed5b..a4aec3c5b 100644 --- a/integration-tests/tests/libsql.test.ts +++ b/integration-tests/tests/libsql.test.ts @@ -22,7 +22,8 @@ import { sum, sumDistinct, max, - min + min, + lt } from 'drizzle-orm'; import { drizzle, type LibSQLDatabase } from 'drizzle-orm/libsql'; import { migrate } from 'drizzle-orm/libsql/migrator'; @@ -36,6 +37,7 @@ import { int, integer, intersect, + numeric, primaryKey, sqliteTable, sqliteTableCreator, @@ -1243,6 +1245,131 @@ test.serial('with ... select', async (t) => { ]); }); +test.serial('with ... update', async (t) => { + const { db } = t.context; + + const products = sqliteTable('products', { + id: integer('id').primaryKey(), + price: numeric('price').notNull(), + cheap: integer('cheap', { mode: 'boolean' }).notNull().default(false) + }); + + await db.run(sql`drop table if exists ${products}`); + await db.run(sql`create table ${products} ( + id integer primary key, + price numeric not null, + cheap integer not null default 0 + )`); + + await db.insert(products).values([ + { price: '10.99' }, + { price: '25.85' }, + { price: '32.99' }, + { price: '2.50' }, + { price: '4.59' }, + ]); + + 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 + }); + + t.deepEqual(result, [ + { id: 1 }, + { id: 4 }, + { id: 5 } + ]); +}); + +test.serial('with ... insert', async (t) => { + const { db } = t.context; + + const users = sqliteTable('users', { + username: text('username').notNull(), + admin: integer('admin', { mode: 'boolean' }).notNull() + }); + + await db.run(sql`drop table if exists ${users}`); + await db.run(sql`create table ${users} (username text not null, admin integer not null default 0)`); + + 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 + }); + + t.deepEqual(result, [{ admin: true }]) +}); + +test.serial('with ... delete', async (t) => { + const { db } = t.context; + + await db.insert(orders).values([ + { region: 'Europe', product: 'A', amount: 10, quantity: 1 }, + { region: 'Europe', product: 'A', amount: 20, quantity: 2 }, + { region: 'Europe', product: 'B', amount: 20, quantity: 2 }, + { region: 'Europe', product: 'B', amount: 30, quantity: 3 }, + { region: 'US', product: 'A', amount: 30, quantity: 3 }, + { region: 'US', product: 'A', amount: 40, quantity: 4 }, + { region: 'US', product: 'B', amount: 40, quantity: 4 }, + { region: 'US', product: 'B', amount: 50, quantity: 5 }, + ]); + + 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 + }); + + t.deepEqual(result, [ + { id: 6 }, + { id: 7 }, + { id: 8 } + ]); +}); + test.serial('select from subquery sql', async (t) => { const { db } = t.context; diff --git a/integration-tests/tests/mysql.test.ts b/integration-tests/tests/mysql.test.ts index d916cc22d..5e3d620ab 100644 --- a/integration-tests/tests/mysql.test.ts +++ b/integration-tests/tests/mysql.test.ts @@ -23,6 +23,7 @@ import { avgDistinct, max, min, + lt, } from 'drizzle-orm'; import { alias, @@ -30,6 +31,7 @@ import { boolean, date, datetime, + decimal, except, exceptAll, foreignKey, @@ -1483,6 +1485,122 @@ test.serial('with ... select', async (t) => { ]); }); +test.serial('with ... update', async (t) => { + const { db } = t.context; + + const products = mysqlTable('products', { + id: serial('id').primaryKey(), + price: decimal('price', { + precision: 15, + scale: 2 + }).notNull(), + cheap: boolean('cheap').notNull().default(false) + }); + + await db.execute(sql`drop table if exists ${products}`); + await db.execute(sql`create table ${products} ( + id serial primary key, + price decimal(15, 2) not null, + cheap boolean not null default false + )`); + + await db.insert(products).values([ + { price: '10.99' }, + { price: '25.85' }, + { price: '32.99' }, + { price: '2.50' }, + { price: '4.59' }, + ]); + + const averagePrice = db + .$with('average_price') + .as( + db + .select({ + value: sql`avg(${products.price})`.as('value') + }) + .from(products) + ); + + await db + .with(averagePrice) + .update(products) + .set({ + cheap: true + }) + .where(lt(products.price, sql`(select * from ${averagePrice})`)); + + const result = await db + .select({ + id: products.id + }) + .from(products) + .where(eq(products.cheap, true)) + + t.deepEqual(result, [ + { id: 1 }, + { id: 4 }, + { id: 5 } + ]); +}); + +test.serial('with ... delete', async (t) => { + const { db } = t.context; + + await db.execute(sql`drop table if exists \`orders\``); + await db.execute( + sql` + create table \`orders\` ( + \`id\` serial primary key, + \`region\` text not null, + \`product\` text not null, + \`amount\` int not null, + \`quantity\` int not null + ) + `, + ); + + await db.insert(orders).values([ + { region: 'Europe', product: 'A', amount: 10, quantity: 1 }, + { region: 'Europe', product: 'A', amount: 20, quantity: 2 }, + { region: 'Europe', product: 'B', amount: 20, quantity: 2 }, + { region: 'Europe', product: 'B', amount: 30, quantity: 3 }, + { region: 'US', product: 'A', amount: 30, quantity: 3 }, + { region: 'US', product: 'A', amount: 40, quantity: 4 }, + { region: 'US', product: 'B', amount: 40, quantity: 4 }, + { region: 'US', product: 'B', amount: 50, quantity: 5 }, + ]); + + const averageAmount = db + .$with('average_amount') + .as( + db + .select({ + value: sql`avg(${orders.amount})`.as('value') + }) + .from(orders) + ); + + await db + .with(averageAmount) + .delete(orders) + .where(gt(orders.amount, sql`(select * from ${averageAmount})`)); + + const result = await db + .select({ + id: orders.id + }) + .from(orders); + + t.deepEqual(result, [ + { id: 1 }, + { id: 2 }, + { id: 3 }, + { id: 4 }, + { id: 5 } + ]); +}); + test.serial('select from subquery sql', async (t) => { const { db } = t.context; diff --git a/integration-tests/tests/pg.test.ts b/integration-tests/tests/pg.test.ts index 89a077d7b..34d90a926 100644 --- a/integration-tests/tests/pg.test.ts +++ b/integration-tests/tests/pg.test.ts @@ -65,6 +65,7 @@ import { uuid as pgUuid, varchar, pgEnum, + numeric, } from 'drizzle-orm/pg-core'; import getPort from 'get-port'; import pg from 'pg'; @@ -1651,6 +1652,131 @@ test.serial('with ... select', async (t) => { ]) }); +test.serial('with ... update', async (t) => { + const { db } = t.context; + + const products = pgTable('products', { + id: serial('id').primaryKey(), + price: numeric('price').notNull(), + cheap: boolean('cheap').notNull().default(false) + }); + + await db.execute(sql`drop table if exists ${products}`); + await db.execute(sql`create table ${products} ( + id serial primary key, + price numeric not null, + cheap boolean not null default false + )`); + + await db.insert(products).values([ + { price: '10.99' }, + { price: '25.85' }, + { price: '32.99' }, + { price: '2.50' }, + { price: '4.59' }, + ]); + + 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 + }); + + t.deepEqual(result, [ + { id: 1 }, + { id: 4 }, + { id: 5 } + ]); +}); + +test.serial('with ... insert', async (t) => { + const { db } = t.context; + + const users = pgTable('users', { + username: text('username').notNull(), + admin: boolean('admin').notNull() + }); + + await db.execute(sql`drop table if exists ${users}`); + await db.execute(sql`create table ${users} (username text not null, admin boolean not null default false)`); + + 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 + }); + + t.deepEqual(result, [{ admin: true }]) +}); + +test.serial('with ... delete', async (t) => { + const { db } = t.context; + + await db.insert(orders).values([ + { region: 'Europe', product: 'A', amount: 10, quantity: 1 }, + { region: 'Europe', product: 'A', amount: 20, quantity: 2 }, + { region: 'Europe', product: 'B', amount: 20, quantity: 2 }, + { region: 'Europe', product: 'B', amount: 30, quantity: 3 }, + { region: 'US', product: 'A', amount: 30, quantity: 3 }, + { region: 'US', product: 'A', amount: 40, quantity: 4 }, + { region: 'US', product: 'B', amount: 40, quantity: 4 }, + { region: 'US', product: 'B', amount: 50, quantity: 5 }, + ]); + + 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 + }); + + t.deepEqual(result, [ + { id: 6 }, + { id: 7 }, + { id: 8 } + ]); +}); + test.serial('select from subquery sql', async (t) => { const { db } = t.context; From 6132c3b8f5fd9957244df645e9d947110fa68105 Mon Sep 17 00:00:00 2001 From: Mario564 Date: Wed, 29 Nov 2023 19:13:31 -0600 Subject: [PATCH 6/7] Fix indentation --- integration-tests/tests/libsql.test.ts | 12 +++++++----- integration-tests/tests/mysql.test.ts | 12 +++++++----- integration-tests/tests/pg.test.ts | 12 +++++++----- 3 files changed, 21 insertions(+), 15 deletions(-) diff --git a/integration-tests/tests/libsql.test.ts b/integration-tests/tests/libsql.test.ts index a4aec3c5b..aa852e9d6 100644 --- a/integration-tests/tests/libsql.test.ts +++ b/integration-tests/tests/libsql.test.ts @@ -1255,11 +1255,13 @@ test.serial('with ... update', async (t) => { }); await db.run(sql`drop table if exists ${products}`); - await db.run(sql`create table ${products} ( - id integer primary key, - price numeric not null, - cheap integer not null default 0 - )`); + await db.run(sql` + create table ${products} ( + id integer primary key, + price numeric not null, + cheap integer not null default 0 + ) + `); await db.insert(products).values([ { price: '10.99' }, diff --git a/integration-tests/tests/mysql.test.ts b/integration-tests/tests/mysql.test.ts index 5e3d620ab..b6ba9fc01 100644 --- a/integration-tests/tests/mysql.test.ts +++ b/integration-tests/tests/mysql.test.ts @@ -1498,11 +1498,13 @@ test.serial('with ... update', async (t) => { }); await db.execute(sql`drop table if exists ${products}`); - await db.execute(sql`create table ${products} ( - id serial primary key, - price decimal(15, 2) not null, - cheap boolean not null default false - )`); + await db.execute(sql` + create table ${products} ( + id serial primary key, + price decimal(15, 2) not null, + cheap boolean not null default false + ) + `); await db.insert(products).values([ { price: '10.99' }, diff --git a/integration-tests/tests/pg.test.ts b/integration-tests/tests/pg.test.ts index 34d90a926..d326ac54e 100644 --- a/integration-tests/tests/pg.test.ts +++ b/integration-tests/tests/pg.test.ts @@ -1662,11 +1662,13 @@ test.serial('with ... update', async (t) => { }); await db.execute(sql`drop table if exists ${products}`); - await db.execute(sql`create table ${products} ( - id serial primary key, - price numeric not null, - cheap boolean not null default false - )`); + await db.execute(sql` + create table ${products} ( + id serial primary key, + price numeric not null, + cheap boolean not null default false + ) + `); await db.insert(products).values([ { price: '10.99' }, From 846df6f9bb17be53bc4e9cf6e9a52fe927440b97 Mon Sep 17 00:00:00 2001 From: Mario564 Date: Tue, 26 Dec 2023 09:50:10 -0600 Subject: [PATCH 7/7] Fix formatting --- drizzle-orm/src/pg-core/db.ts | 52 +++++++++++++++++------------------ 1 file changed, 26 insertions(+), 26 deletions(-) diff --git a/drizzle-orm/src/pg-core/db.ts b/drizzle-orm/src/pg-core/db.ts index 5627de810..44b499d75 100644 --- a/drizzle-orm/src/pg-core/db.ts +++ b/drizzle-orm/src/pg-core/db.ts @@ -270,32 +270,32 @@ export class PgDatabase< } /** - * Creates an update query. - * - * Calling this method without `.where()` clause will update all rows in a table. The `.where()` clause specifies which rows should be updated. - * - * Use `.set()` method to specify which values to update. - * - * See docs: {@link https://orm.drizzle.team/docs/update} - * - * @param table The table to update. - * - * @example - * - * ```ts - * // Update all rows in the 'cars' table - * await db.update(cars).set({ color: 'red' }); - * - * // Update rows with filters and conditions - * await db.update(cars).set({ color: 'red' }).where(eq(cars.brand, 'BMW')); - * - * // Update with returning clause - * const updatedCar: Car[] = await db.update(cars) - * .set({ color: 'red' }) - * .where(eq(cars.id, 1)) - * .returning(); - * ``` - */ + * Creates an update query. + * + * Calling this method without `.where()` clause will update all rows in a table. The `.where()` clause specifies which rows should be updated. + * + * Use `.set()` method to specify which values to update. + * + * See docs: {@link https://orm.drizzle.team/docs/update} + * + * @param table The table to update. + * + * @example + * + * ```ts + * // Update all rows in the 'cars' table + * await db.update(cars).set({ color: 'red' }); + * + * // Update rows with filters and conditions + * await db.update(cars).set({ color: 'red' }).where(eq(cars.brand, 'BMW')); + * + * // Update with returning clause + * const updatedCar: Car[] = await db.update(cars) + * .set({ color: 'red' }) + * .where(eq(cars.id, 1)) + * .returning(); + * ``` + */ function update(table: TTable): PgUpdateBuilder { return new PgUpdateBuilder(table, self.session, self.dialect, queries); }