Skip to content

Commit

Permalink
feat(sql): allow delete queries with auto-joining via sub-queries (#538)
Browse files Browse the repository at this point in the history
```typescript
qb.delete({ books: { author: 123 } });`
```

will result in following query:

```sql
delete from `publisher2` where `id` in (select `e0`.`id` from (
  select distinct `e0`.`id` from `publisher2` as `e0` left join `book2` as `e1` on `e0`.`id` = `e1`.`publisher_id` where `e1`.`author_id` = ?
) as `e0`)
```

Closes #492
  • Loading branch information
B4nan committed Aug 9, 2020
1 parent cff9a3a commit e44bc56
Show file tree
Hide file tree
Showing 4 changed files with 35 additions and 6 deletions.
2 changes: 1 addition & 1 deletion ROADMAP.md
Expand Up @@ -27,7 +27,7 @@ discuss specifics.
- [x] Use `jsonb` as default for object columns in postgres
- [x] Support subqueries in QB
- [x] Nested conditions in `qb.update()` queries via subqueries (#319)
- [ ] Nested conditions in `em.remove()` via subqueries (#492)
- [x] Nested conditions in `em.remove()` via subqueries (#492)
- [ ] Association scopes/filters ([hibernate docs](https://docs.jboss.org/hibernate/orm/3.6/reference/en-US/html/filters.html))
- [ ] Support external hooks when using EntitySchema (hooks outside of entity)
- [ ] Cache metadata only with ts-morph provider
Expand Down
11 changes: 6 additions & 5 deletions packages/knex/src/query/QueryBuilder.ts
Expand Up @@ -115,10 +115,10 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
const topLevel = !op || Object.keys(this._cond).length === 0;
const criteriaNode = CriteriaNode.create(this.metadata, this.entityName, cond);

if (this.type === QueryType.UPDATE && criteriaNode.willAutoJoin(this)) {
if ([QueryType.UPDATE, QueryType.DELETE].includes(this.type) && criteriaNode.willAutoJoin(this)) {
// use sub-query to support joining
this.setFlag(this.type === QueryType.UPDATE ? QueryFlag.UPDATE_SUB_QUERY : QueryFlag.DELETE_SUB_QUERY);
this.select(this.metadata.get(this.entityName).primaryKeys, true);
this.setFlag(QueryFlag.UPDATE_SUB_QUERY);
}

if (topLevel) {
Expand Down Expand Up @@ -388,7 +388,7 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
}

if (cond) {
this._cond = CriteriaNode.create(this.metadata, this.entityName, cond).process(this);
this.where(cond);
}

return this;
Expand Down Expand Up @@ -461,15 +461,16 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
SmartQueryHelper.processParams([this._data, this._cond, this._having]);
this.finalized = true;

if (this.flags.has(QueryFlag.UPDATE_SUB_QUERY)) {
if (this.flags.has(QueryFlag.UPDATE_SUB_QUERY) || this.flags.has(QueryFlag.DELETE_SUB_QUERY)) {
const subQuery = this.clone();
subQuery.finalized = true;

// wrap one more time to get around MySQL limitations
// https://stackoverflow.com/questions/45494/mysql-error-1093-cant-specify-target-table-for-update-in-from-clause
const subSubQuery = this.getKnex().select(this.prepareFields(meta.primaryKeys)).from(subQuery.as(this.alias));
const method = this.flags.has(QueryFlag.UPDATE_SUB_QUERY) ? 'update' : 'delete';

this.update(this._data).where({
this[method](this._data).where({
[Utils.getPrimaryKeyHash(meta.primaryKeys)]: { $in: subSubQuery },
});
}
Expand Down
1 change: 1 addition & 0 deletions packages/knex/src/query/enums.ts
Expand Up @@ -10,4 +10,5 @@ export enum QueryType {
export enum QueryFlag {
DISTINCT = 'DISTINCT',
UPDATE_SUB_QUERY = 'UPDATE_SUB_QUERY',
DELETE_SUB_QUERY = 'DELETE_SUB_QUERY',
}
27 changes: 27 additions & 0 deletions tests/QueryBuilder.test.ts
Expand Up @@ -1094,6 +1094,33 @@ describe('QueryBuilder', () => {
expect(qb.getParams()).toEqual(['test 123', PublisherType.GLOBAL, 123, 'book']);
});

test('delete query with auto-joining', async () => {
const qb = orm.em.createQueryBuilder(Publisher2);
qb.delete({ books: { author: 123 } });
expect(qb.getQuery()).toEqual('delete from `publisher2` where `id` in (select `e0`.`id` from (' +
'select distinct `e0`.`id` from `publisher2` as `e0` left join `book2` as `e1` on `e0`.`id` = `e1`.`publisher_id` where `e1`.`author_id` = ?' +
') as `e0`)');
expect(qb.getParams()).toEqual([123]);
});

test('delete query with composite keys and auto-joining', async () => {
const qb = orm.em.createQueryBuilder(FooParam2);
qb.delete({ bar: { baz: 123 } });
expect(qb.getQuery()).toEqual('delete from `foo_param2` where (`bar_id`, `baz_id`) in (select `e0`.`bar_id`, `e0`.`baz_id` from (' +
'select distinct `e0`.`bar_id`, `e0`.`baz_id` from `foo_param2` as `e0` left join `foo_bar2` as `e1` on `e0`.`bar_id` = `e1`.`id` where `e1`.`baz_id` = ?' +
') as `e0`)');
expect(qb.getParams()).toEqual([123]);
});

test('delete query with or condition and auto-joining', async () => {
const qb = orm.em.createQueryBuilder(Publisher2);
qb.delete({ $or: [{ books: { author: 123 } }, { books: { title: 'book' } }] });
expect(qb.getQuery()).toEqual('delete from `publisher2` where `id` in (select `e0`.`id` from (' +
'select distinct `e0`.`id` from `publisher2` as `e0` left join `book2` as `e1` on `e0`.`id` = `e1`.`publisher_id` where (`e1`.`author_id` = ? or `e1`.`title` = ?)' +
') as `e0`)');
expect(qb.getParams()).toEqual([123, 'book']);
});

test('update query with entity in data', async () => {
const qb = orm.em.createQueryBuilder(Publisher2);
qb.withSchema('test123');
Expand Down

0 comments on commit e44bc56

Please sign in to comment.