Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Support Joins and Using syntax for PostgreSQL Delete Statement (#4591) #4800

Merged
Merged
Show file tree
Hide file tree
Changes from 1 commit
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
39 changes: 37 additions & 2 deletions lib/dialects/postgres/query/pg-querycompiler.js
Expand Up @@ -57,9 +57,44 @@ class QueryCompiler_PG extends QueryCompiler {
};
}

// Compiles an `update` query, allowing for a return value.
using() {
const usingTables = this.single.using;
if (!usingTables) return;
let sql = 'using ';
if (Array.isArray(usingTables)) {
sql += usingTables
.map((table) => {
return this.formatter.wrap(table);
})
.join(',');
} else {
sql += this.formatter.wrap(usingTables);
}
return sql;
}

// Compiles an `delete` query, allowing for a return value.
del() {
const sql = super.del(...arguments);
// Make sure tableName is processed by the formatter first.
const { tableName } = this;
const withSQL = this.with();
const wheres = this.where();
// Joins in PG with delete it's not valid, we throw an error and ask to use 'using'
if (this.join().length > 0) {
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

converting joins to using transparently is not feasible?

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

You mean use the joins logic by add 'using' joins types with the 'using()' syntax ?
I think about that but with that implementation I cant throw an error here.
Also we have a join with using syntax inside and I quite afraid about some misunderstand.

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I'm still on the fence about this, TBH. Considering that many multi-db systems use knex specifically to abstract away db differences, transforming joins to using here would allow them to avoid having some conditional logic. Is it possible to always transform join into using, or you see certain case where that would fail and user would be forced to use using explicitly anyway?

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I see the argument. I start on 'using' function because of an argument in the original PR about avoid silent converting operations. But in fact, we always do "silent" operations in Knex, especially with oracle, when converting limit/offset functions...
I will rework it.

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I wonder if we should also keep using syntax for those who want to be explicit.

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I push with implicit joins to 'using' + 'where's syntax and I also keep the actual using syntax too.

throw new Error(
"Joins with delete query isn't valid in PostgreSQL, use 'using' with 'where' functions instead."
);
}
const using = this.using();
// When using the clause 'using' we delete the "from" table name (like joins)
const deleteSelector = using ? tableName + ' ' : '';
const sql =
withSQL +
`delete ${deleteSelector}from ${
this.single.only ? 'only ' : ''
}${tableName}` +
(using ? ` ${using}` : '') +
(wheres ? ` ${wheres}` : '');
const { returning } = this.single;
return {
sql: sql + this._returning(returning),
Expand Down
5 changes: 5 additions & 0 deletions lib/query/querybuilder.js
Expand Up @@ -269,6 +269,11 @@ class Builder extends EventEmitter {
return this;
}

using(tables) {
OlivierCavadenti marked this conversation as resolved.
Show resolved Hide resolved
this._single.using = tables;
return this;
}

// JOIN blocks:
innerJoin(...args) {
return this._joinType('inner').join(...args);
Expand Down
51 changes: 47 additions & 4 deletions test/unit/query/builder.js
Expand Up @@ -10161,6 +10161,53 @@ describe('QueryBuilder', () => {
});

it('should include join when deleting', () => {
// We except error in PG because delete with joins is not possible.
expect(() => {
testquery(
qb()
.del()
.from('users')
.join('photos', 'photos.id', 'users.id')
.where({ 'user.email': 'mock@example.com' }),
{
pg: '',
}
);
}).to.throw(Error);

testsql(
qb()
.del()
.from('users')
.using('photos')
.where({ 'user.email': 'mock@example.com', 'photos.id': 'users.id' }),
{
pg: {
sql: 'delete "users" from "users" using "photos" where "user"."email" = ? and "photos"."id" = ?',
bindings: ['mock@example.com', 'users.id'],
},
}
);

// Test with multiple tables 'using'
testsql(
qb()
.del()
.from('users')
.using(['photos', 'docs'])
.where({
'user.email': 'mock@example.com',
'photos.id': 'users.id',
'docs.id': 'users.id',
}),
{
pg: {
sql: 'delete "users" from "users" using "photos","docs" where "user"."email" = ? and "photos"."id" = ? and "docs"."id" = ?',
bindings: ['mock@example.com', 'users.id', 'users.id'],
},
}
);

testsql(
qb()
.del()
Expand All @@ -10180,10 +10227,6 @@ describe('QueryBuilder', () => {
sql: 'delete "users" from "users" inner join "photos" on "photos"."id" = "users"."id" where "user"."email" = ?',
bindings: ['mock@example.com'],
},
pg: {
sql: 'delete "users" from "users" inner join "photos" on "photos"."id" = "users"."id" where "user"."email" = ?',
bindings: ['mock@example.com'],
},
'pg-redshift': {
sql: 'delete "users" from "users" inner join "photos" on "photos"."id" = "users"."id" where "user"."email" = ?',
bindings: ['mock@example.com'],
Expand Down
9 changes: 8 additions & 1 deletion types/index.d.ts
Expand Up @@ -482,7 +482,7 @@ export declare namespace Knex {
//
// QueryInterface
//
type ClearStatements = "with" | "select" | "columns" | "hintComments" | "where" | "union" | "join" | "group" | "order" | "having" | "limit" | "offset" | "counter" | "counters";
type ClearStatements = "with" | "select" | "columns" | "hintComments" | "where" | "union" | "using" | "join" | "group" | "order" | "having" | "limit" | "offset" | "counter" | "counters";

interface QueryInterface<TRecord extends {} = any, TResult = any> {
select: Select<TRecord, TResult>;
Expand All @@ -509,6 +509,9 @@ export declare namespace Knex {
fullOuterJoin: Join<TRecord, TResult>;
crossJoin: Join<TRecord, TResult>;

// Using
using: Using<TRecord, TResult>;

// Withs
with: With<TRecord, TResult>;
withRecursive: With<TRecord, TResult>;
Expand Down Expand Up @@ -1338,6 +1341,10 @@ export declare namespace Knex {
>;
}

interface Using<TRecord = any, TResult = unknown[]> {
(tables: string[]): QueryBuilder<TRecord, TResult>;
}

interface With<TRecord = any, TResult = unknown[]>
extends WithRaw<TRecord, TResult>,
WithWrapped<TRecord, TResult> {}
Expand Down