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 all commits
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
5 changes: 5 additions & 0 deletions lib/dialects/postgres/index.js
Expand Up @@ -7,6 +7,7 @@ const Client = require('../../client');

const Transaction = require('./execution/pg-transaction');
const QueryCompiler = require('./query/pg-querycompiler');
const QueryBuilder = require('./query/pg-querybuilder');
const ColumnCompiler = require('./schema/pg-columncompiler');
const TableCompiler = require('./schema/pg-tablecompiler');
const ViewCompiler = require('./schema/pg-viewcompiler');
Expand All @@ -30,6 +31,10 @@ class Client_PG extends Client {
return new Transaction(this, ...arguments);
}

queryBuilder() {
return new QueryBuilder(this);
}

queryCompiler(builder, formatter) {
return new QueryCompiler(this, builder, formatter);
}
Expand Down
8 changes: 8 additions & 0 deletions lib/dialects/postgres/query/pg-querybuilder.js
@@ -0,0 +1,8 @@
const QueryBuilder = require('../../../query/querybuilder.js');

module.exports = class QueryBuilder_PostgreSQL extends QueryBuilder {
using(tables) {
this._single.using = tables;
return this;
}
};
70 changes: 67 additions & 3 deletions lib/dialects/postgres/query/pg-querycompiler.js
Expand Up @@ -4,7 +4,10 @@ const identity = require('lodash/identity');
const reduce = require('lodash/reduce');

const QueryCompiler = require('../../../query/querycompiler');
const { wrapString } = require('../../../formatter/wrappingFormatter');
const {
wrapString,
wrap: wrap_,
} = require('../../../formatter/wrappingFormatter');

class QueryCompiler_PG extends QueryCompiler {
constructor(client, builder, formatter) {
Expand Down Expand Up @@ -57,9 +60,70 @@ 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();
let wheres = this.where() || '';
let using = this.using() || '';
const joins = this.grouped.join;

const tableJoins = [];
if (Array.isArray(joins)) {
for (const join of joins) {
tableJoins.push(
wrap_(
this._joinTable(join),
undefined,
this.builder,
this.client,
this.bindingsHolder
)
);

const joinWheres = [];
for (const clause of join.clauses) {
joinWheres.push(
this.whereBasic({
column: clause.column,
operator: '=',
value: clause.value,
asColumn: true,
})
);
}
if (joinWheres.length > 0) {
wheres += (wheres ? ' and ' : '') + joinWheres.join(' ');
}
}
if (tableJoins.length > 0) {
using += (using ? ',' : 'using ') + tableJoins.join(',');
}
}

// With 'using' syntax, no tablename between DELETE and FROM.
const sql =
withSQL +
`delete from ${this.single.only ? 'only ' : ''}${tableName}` +
(using ? ` ${using}` : '') +
(wheres ? ` ${wheres}` : '');
const { returning } = this.single;
return {
sql: sql + this._returning(returning),
Expand Down
6 changes: 6 additions & 0 deletions lib/query/querybuilder.js
Expand Up @@ -269,6 +269,12 @@ class Builder extends EventEmitter {
return this;
}

using(tables) {
OlivierCavadenti marked this conversation as resolved.
Show resolved Hide resolved
throw new Error(
"'using' function is only available in PostgreSQL dialect with Delete statements."
);
}

// JOIN blocks:
innerJoin(...args) {
return this._joinType('inner').join(...args);
Expand Down
11 changes: 7 additions & 4 deletions lib/query/querycompiler.js
Expand Up @@ -333,6 +333,12 @@ class QueryCompiler {
})`;
}

_joinTable(join) {
return join.schema && !(join.table instanceof Raw)
? `${join.schema}.${join.table}`
: join.table;
}

// Compiles all each of the `join` clauses on the query,
// including any nested join queries.
join() {
Expand All @@ -342,10 +348,7 @@ class QueryCompiler {
if (!joins) return '';
while (++i < joins.length) {
const join = joins[i];
const table =
join.schema && !(join.table instanceof Raw)
? `${join.schema}.${join.table}`
: join.table;
const table = this._joinTable(join);
if (i > 0) sql += ' ';
if (join.joinType === 'raw') {
sql += unwrapRaw_(
Expand Down
79 changes: 61 additions & 18 deletions test/integration/query/deletes.js
Expand Up @@ -2,12 +2,8 @@

const { expect } = require('chai');
const { TEST_TIMESTAMP } = require('../../util/constants');
const {
isSQLite,
isPostgreSQL,
isOracle,
isCockroachDB,
} = require('../../util/db-helpers');
const { isSQLite, isOracle, isCockroachDB } = require('../../util/db-helpers');
const { isPostgreSQL } = require('../../util/db-helpers.js');

module.exports = function (knex) {
describe('Deletes', function () {
Expand Down Expand Up @@ -96,12 +92,7 @@ module.exports = function (knex) {
.join('accounts', 'accounts.id', 'test_table_two.account_id')
.where({ 'accounts.email': 'test3@example.com' })
.del();
if (
isSQLite(knex) ||
isPostgreSQL(knex) ||
isCockroachDB(knex) ||
isOracle(knex)
) {
if (isSQLite(knex) || isCockroachDB(knex) || isOracle(knex)) {
await expect(query).to.be.rejected;
return;
}
Expand All @@ -112,6 +103,12 @@ module.exports = function (knex) {
['test3@example.com'],
1
);
tester(
'pg',
'delete from "test_table_two" using "accounts" where "accounts"."email" = ? and "accounts"."id" = "test_table_two"."account_id"',
['test3@example.com'],
1
);
tester(
'mssql',
'delete [test_table_two] from [test_table_two] inner join [accounts] on [accounts].[id] = [test_table_two].[account_id] where [accounts].[email] = ?;select @@rowcount',
Expand All @@ -120,6 +117,35 @@ module.exports = function (knex) {
);
});
});

it('should handle basic delete with join and "using" syntax in PostgreSQL', async function () {
if (!isPostgreSQL(knex)) {
this.skip();
}
await knex('test_table_two').insert({
account_id: 4,
details: '',
status: 1,
});
const query = knex('test_table_two')
.using('accounts')
.where({ 'accounts.email': 'test4@example.com' })
.whereRaw('"accounts"."id" = "test_table_two"."account_id"')
.del();
if (!isPostgreSQL(knex)) {
await expect(query).to.be.rejected;
return;
}
return query.testSql(function (tester) {
tester(
'pg',
'delete from "test_table_two" using "accounts" where "accounts"."email" = ? and "accounts"."id" = "test_table_two"."account_id"',
['test4@example.com'],
1
);
});
});

it('should handle returning', async function () {
await knex('test_table_two').insert({
account_id: 4,
Expand All @@ -130,12 +156,7 @@ module.exports = function (knex) {
.join('accounts', 'accounts.id', 'test_table_two.account_id')
.where({ 'accounts.email': 'test4@example.com' })
.del('*');
if (
isSQLite(knex) ||
isPostgreSQL(knex) ||
isCockroachDB(knex) ||
isOracle(knex)
) {
if (isSQLite(knex) || isCockroachDB(knex) || isOracle(knex)) {
await expect(query).to.be.rejected;
return;
}
Expand All @@ -146,6 +167,28 @@ module.exports = function (knex) {
['test4@example.com'],
1
);
tester(
'pg',
'delete from "test_table_two" using "accounts" where "accounts"."email" = ? and "accounts"."id" = "test_table_two"."account_id" returning *',
['test4@example.com'],
[
{
about: 'Lorem ipsum Dolore labore incididunt enim.',
balance: 0,
id: '4',
account_id: 4,
details: '',
status: 1,
phone: null,
logins: 2,
email: 'test4@example.com',
first_name: 'Test',
last_name: 'User',
created_at: TEST_TIMESTAMP,
updated_at: TEST_TIMESTAMP,
},
]
);
tester(
'mssql',
'delete [test_table_two] output deleted.* from [test_table_two] inner join [accounts] on [accounts].[id] = [test_table_two].[account_id] where [accounts].[email] = ?',
Expand Down