From 30f1f72f6090d39d8f61d2e7e09d3d2dadef6454 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Sami=20Koskim=C3=A4ki?= Date: Sun, 14 Jul 2024 12:26:04 +0300 Subject: [PATCH] Support update table1, table2, ... query support. Closes #192 --- .../docs/examples/update/0030-my-sql-joins.js | 9 ++ .../examples/update/0030-my-sql-joins.mdx | 40 ++++++++ site/package-lock.json | 2 +- src/operation-node/update-query-node.ts | 10 +- src/parser/select-parser.ts | 7 +- src/parser/update-set-parser.ts | 17 +++- .../with-schema/with-schema-transformer.ts | 17 ++-- src/query-builder/update-query-builder.ts | 41 +++++++- src/query-compiler/default-query-compiler.ts | 4 + src/query-creator.ts | 50 ++++++---- test/node/src/update.test.ts | 93 +++++++++++++++---- 11 files changed, 236 insertions(+), 54 deletions(-) create mode 100644 site/docs/examples/update/0030-my-sql-joins.js create mode 100644 site/docs/examples/update/0030-my-sql-joins.mdx diff --git a/site/docs/examples/update/0030-my-sql-joins.js b/site/docs/examples/update/0030-my-sql-joins.js new file mode 100644 index 000000000..2d487c80b --- /dev/null +++ b/site/docs/examples/update/0030-my-sql-joins.js @@ -0,0 +1,9 @@ +export const mySqlJoins = `const result = await db + .updateTable(['person', 'pet']) + .set('person.first_name', 'Updated person') + .set('pet.name', 'Updated doggo') + .whereRef('person.id', '=', 'pet.owner_id') + .where('person.id', '=', '1') + .executeTakeFirst() + +console.log(result.numUpdatedRows)` \ No newline at end of file diff --git a/site/docs/examples/update/0030-my-sql-joins.mdx b/site/docs/examples/update/0030-my-sql-joins.mdx new file mode 100644 index 000000000..2258a0f8e --- /dev/null +++ b/site/docs/examples/update/0030-my-sql-joins.mdx @@ -0,0 +1,40 @@ +--- +title: 'MySQL joins' +--- + +# MySQL joins + +MySQL allows you to join tables directly to the "main" table and update +rows of all joined tables. This is possible by passing all tables to the +`updateTable` method as a list and adding the `ON` conditions as `WHERE` +statements. You can then use the `set(column, value)` variant to update +columns using table qualified names. + +The `UpdateQueryBuilder` also has `innerJoin` etc. join methods, but those +can only be used as a part of PostgreSQL a `update set from join` query. +Due to type complexity issues, we unfortunately can't make the same +methods work in both cases. + +import { + Playground, + exampleSetup, +} from '../../../src/components/Playground' + +import { + mySqlJoins +} from './0030-my-sql-joins' + +
+ +
+ +:::info[More examples] +The API documentation is packed with examples. The API docs are hosted [here](https://kysely-org.github.io/kysely-apidoc/), +but you can access the same documentation by hovering over functions/methods/classes in your IDE. The examples are always +just one hover away! + +For example, check out these sections: + - [set method](https://kysely-org.github.io/kysely-apidoc/classes/UpdateQueryBuilder.html#set) + - [returning method](https://kysely-org.github.io/kysely-apidoc/classes/UpdateQueryBuilder.html#returning) + - [updateTable method](https://kysely-org.github.io/kysely-apidoc/classes/Kysely.html#updateTable) +::: diff --git a/site/package-lock.json b/site/package-lock.json index 530031d2e..c6e6ab2ee 100644 --- a/site/package-lock.json +++ b/site/package-lock.json @@ -6,7 +6,7 @@ "packages": { "": { "name": "kysely", - "version": "0.27.0", + "version": "0.27.3", "dependencies": { "@docusaurus/core": "^3.4.0", "@docusaurus/preset-classic": "^3.4.0", diff --git a/src/operation-node/update-query-node.ts b/src/operation-node/update-query-node.ts index c4188205a..a815a45c9 100644 --- a/src/operation-node/update-query-node.ts +++ b/src/operation-node/update-query-node.ts @@ -12,6 +12,7 @@ import { ExplainNode } from './explain-node.js' import { LimitNode } from './limit-node.js' import { TopNode } from './top-node.js' import { OutputNode } from './output-node.js' +import { ListNode } from './list-node.js' export type UpdateValuesNode = ValueListNode | PrimitiveValueListNode @@ -39,10 +40,15 @@ export const UpdateQueryNode = freeze({ return node.kind === 'UpdateQueryNode' }, - create(table: OperationNode, withNode?: WithNode): UpdateQueryNode { + create( + tables: ReadonlyArray, + withNode?: WithNode, + ): UpdateQueryNode { return freeze({ kind: 'UpdateQueryNode', - table, + // For backwards compatibility, use the raw table node when there's only one table + // and don't rename the property to something like `tables`. + table: tables.length === 1 ? tables[0] : ListNode.create(tables), ...(withNode && { with: withNode }), }) }, diff --git a/src/parser/select-parser.ts b/src/parser/select-parser.ts index f39fbbc44..8bfd43480 100644 --- a/src/parser/select-parser.ts +++ b/src/parser/select-parser.ts @@ -73,9 +73,10 @@ export type SelectArg< | ReadonlyArray | ((eb: ExpressionBuilder) => ReadonlyArray) -type FlattenSelectExpression = SE extends DynamicReferenceBuilder - ? { [R in RA]: DynamicReferenceBuilder }[RA] - : SE +type FlattenSelectExpression = + SE extends DynamicReferenceBuilder + ? { [R in RA]: DynamicReferenceBuilder }[RA] + : SE type ExtractAliasFromSelectExpression = SE extends string ? ExtractAliasFromStringSelectExpression diff --git a/src/parser/update-set-parser.ts b/src/parser/update-set-parser.ts index c3ce3fe4c..248491956 100644 --- a/src/parser/update-set-parser.ts +++ b/src/parser/update-set-parser.ts @@ -12,12 +12,19 @@ import { parseReferenceExpression, ReferenceExpression, } from './reference-parser.js' +import { AnyColumn, DrainOuterGeneric } from '../util/type-utils.js' -export type UpdateObject = { - [C in UpdateKeys]?: - | ValueExpression> - | undefined -} +export type UpdateObject< + DB, + TB extends keyof DB, + UT extends keyof DB = TB, +> = DrainOuterGeneric<{ + [C in AnyColumn]?: { + [T in UT]: C extends keyof DB[T] + ? ValueExpression> | undefined + : never + }[UT] +}> export type UpdateObjectFactory< DB, diff --git a/src/plugin/with-schema/with-schema-transformer.ts b/src/plugin/with-schema/with-schema-transformer.ts index af14b0b3d..2e2bcb96e 100644 --- a/src/plugin/with-schema/with-schema-transformer.ts +++ b/src/plugin/with-schema/with-schema-transformer.ts @@ -1,5 +1,6 @@ import { AliasNode } from '../../operation-node/alias-node.js' import { IdentifierNode } from '../../operation-node/identifier-node.js' +import { ListNode } from '../../operation-node/list-node.js' import { OperationNodeTransformer } from '../../operation-node/operation-node-transformer.js' import { OperationNode } from '../../operation-node/operation-node.js' import { ReferencesNode } from '../../operation-node/references-node.js' @@ -157,14 +158,14 @@ export class WithSchemaTransformer extends OperationNodeTransformer { node: OperationNode, schemableIds: Set, ): void { - const table = TableNode.is(node) - ? node - : AliasNode.is(node) && TableNode.is(node.node) - ? node.node - : null - - if (table) { - this.#collectSchemableId(table.table, schemableIds) + if (ListNode.is(node)) { + for (const table of node.items) { + this.#collectSchemableIdsFromTableExpr(table, schemableIds) + } + } else if (TableNode.is(node)) { + this.#collectSchemableId(node.table, schemableIds) + } else if (AliasNode.is(node) && TableNode.is(node.node)) { + this.#collectSchemableId(node.node.table, schemableIds) } } diff --git a/src/query-builder/update-query-builder.ts b/src/query-builder/update-query-builder.ts index 4c6323737..39ca783d4 100644 --- a/src/query-builder/update-query-builder.ts +++ b/src/query-builder/update-query-builder.ts @@ -630,6 +630,45 @@ export class UpdateQueryBuilder * "last_name" = $3 || $4 * where "id" = $5 * ``` + * + * + * + * MySQL allows you to join tables directly to the "main" table and update + * rows of all joined tables. This is possible by passing all tables to the + * `updateTable` method as a list and adding the `ON` conditions as `WHERE` + * statements. You can then use the `set(column, value)` variant to update + * columns using table qualified names. + * + * The `UpdateQueryBuilder` also has `innerJoin` etc. join methods, but those + * can only be used as a part of PostgreSQL a `update set from join` query. + * Due to type complexity issues, we unfortunately can't make the same + * methods work in both cases. + * + * ```ts + * const result = await db + * .updateTable(['person', 'pet']) + * .set('person.first_name', 'Updated person') + * .set('pet.name', 'Updated doggo') + * .whereRef('person.id', '=', 'pet.owner_id') + * .where('person.id', '=', '1') + * .executeTakeFirst() + * + * console.log(result.numUpdatedRows) + * ``` + * + * The generated SQL (MySQL): + * + * ```sql + * update + * `person`, + * `pet` + * set + * `person`.`first_name` = ?, + * `pet`.`name` = ? + * where + * `person`.`id` = `pet`.`owner_id` + * and `person`.`id` = ? + * ``` */ set( update: UpdateObjectExpression, @@ -756,7 +795,7 @@ export class UpdateQueryBuilder * * ### Examples * - * ```ts + * ```ts * await db.updateTable('person') * .set({ age: 39 }) * .where('first_name', '=', 'John') diff --git a/src/query-compiler/default-query-compiler.ts b/src/query-compiler/default-query-compiler.ts index 836bdc72c..591424e7d 100644 --- a/src/query-compiler/default-query-compiler.ts +++ b/src/query-compiler/default-query-compiler.ts @@ -808,6 +808,10 @@ export class DefaultQueryCompiler } if (node.joins) { + if (!node.from) { + throw new Error("Joins in an update query are only supported as a part of a PostgreSQL 'update set from join' query. If you want to create a MySQL 'update join set' query, see https://kysely.dev/docs/examples/update/my-sql-joins") + } + this.append(' ') this.compileList(node.joins, ' ') } diff --git a/src/query-creator.ts b/src/query-creator.ts index d3c2caf6a..c10642766 100644 --- a/src/query-creator.ts +++ b/src/query-creator.ts @@ -464,39 +464,57 @@ export class QueryCreator { * console.log(result.numUpdatedRows) * ``` */ - updateTable( - table: TR, + updateTable( + from: TE[], ): UpdateQueryBuilder< DB, - ExtractTableAlias, - ExtractTableAlias, + ExtractTableAlias, + ExtractTableAlias, UpdateResult > - updateTable>( - table: TR, + updateTable>( + from: TE[], ): UpdateQueryBuilder< - DB & PickTableWithAlias, - ExtractTableAlias, TR>, - ExtractTableAlias, TR>, + From, + FromTables, + FromTables, UpdateResult > - updateTable>( - table: TR, + updateTable( + from: TE, + ): UpdateQueryBuilder< + DB, + ExtractTableAlias, + ExtractTableAlias, + UpdateResult + > + + updateTable>( + from: TE, + ): UpdateQueryBuilder< + DB & PickTableWithAlias, + ExtractTableAlias, TE>, + ExtractTableAlias, TE>, + UpdateResult + > + + updateTable>( + from: TE, ): UpdateQueryBuilder< - From, - FromTables, - FromTables, + From, + FromTables, + FromTables, UpdateResult > - updateTable>(table: TR): any { + updateTable(tables: TableExpressionOrList): any { return new UpdateQueryBuilder({ queryId: createQueryId(), executor: this.#props.executor, queryNode: UpdateQueryNode.create( - parseTableExpression(table), + parseTableExpressionOrList(tables), this.#props.withNode, ), }) diff --git a/test/node/src/update.test.ts b/test/node/src/update.test.ts index 1c1ffed41..a498fc8fb 100644 --- a/test/node/src/update.test.ts +++ b/test/node/src/update.test.ts @@ -577,6 +577,63 @@ for (const dialect of DIALECTS) { expect(people).to.have.length(2) }) + + it('should update joined table using set(name, value) function', async () => { + const query = ctx.db + .updateTable(['person', 'pet']) + .set('person.first_name', 'Jennifer 2') + .set('pet.name', 'Doggo 2') + .where('person.first_name', '=', 'Jennifer') + .whereRef('person.id', '=', 'pet.owner_id') + + testSql(query, dialect, { + postgres: NOT_SUPPORTED, + mysql: { + sql: 'update `person`, `pet` set `person`.`first_name` = ?, `pet`.`name` = ? where `person`.`first_name` = ? and `person`.`id` = `pet`.`owner_id`', + parameters: ['Jennifer 2', 'Doggo 2', 'Jennifer'], + }, + mssql: NOT_SUPPORTED, + sqlite: NOT_SUPPORTED, + }) + + await query.execute() + + const jennifer = await ctx.db + .selectFrom('person') + .select(['id', 'first_name']) + .where('first_name', '=', 'Jennifer 2') + .execute() + + const doggo = await ctx.db + .selectFrom('pet') + .select(['name', 'owner_id']) + .where('name', '=', 'Doggo 2') + .execute() + + expect(jennifer).to.have.length(1) + expect(doggo).to.have.length(1) + expect(doggo[0].owner_id).to.equal(jennifer[0].id) + }) + + it('should update joined table using set(object) function', async () => { + const query = ctx.db + .updateTable(['person', 'pet']) + .set({ name: 'Doggo 2' }) + .where('person.first_name', '=', 'Jennifer') + .whereRef('person.id', '=', 'pet.owner_id') + + testSql(query, dialect, { + postgres: NOT_SUPPORTED, + mysql: { + sql: 'update `person`, `pet` set `name` = ? where `person`.`first_name` = ? and `person`.`id` = `pet`.`owner_id`', + parameters: ['Doggo 2', 'Jennifer'], + }, + mssql: NOT_SUPPORTED, + sqlite: NOT_SUPPORTED, + }) + + await query.execute() + }) } it('should create an update query that uses a CTE', async () => { @@ -668,25 +725,25 @@ for (const dialect of DIALECTS) { if (dialect === 'postgres' || dialect === 'mysql') { it('modifyEnd should add arbitrary SQL to the end of the query', async () => { const query = ctx.db - .updateTable('person') - .set({ - gender: 'other' - }) - .where('first_name', '=', 'Jennifer') - .modifyEnd(sql.raw('-- this is a comment')) + .updateTable('person') + .set({ + gender: 'other', + }) + .where('first_name', '=', 'Jennifer') + .modifyEnd(sql.raw('-- this is a comment')) - testSql(query, dialect, { - postgres: { - sql: 'update "person" set "gender" = $1 where "first_name" = $2 -- this is a comment', - parameters: ['other', 'Jennifer'], - }, - mysql: { - sql: 'update `person` set `gender` = ? where `first_name` = ? -- this is a comment', - parameters: ['other', 'Jennifer'], - }, - mssql: NOT_SUPPORTED, - sqlite: NOT_SUPPORTED, - }) + testSql(query, dialect, { + postgres: { + sql: 'update "person" set "gender" = $1 where "first_name" = $2 -- this is a comment', + parameters: ['other', 'Jennifer'], + }, + mysql: { + sql: 'update `person` set `gender` = ? where `first_name` = ? -- this is a comment', + parameters: ['other', 'Jennifer'], + }, + mssql: NOT_SUPPORTED, + sqlite: NOT_SUPPORTED, + }) const result = await query.execute()