Skip to content

Commit

Permalink
feat(sql): allow update queries with auto-joining via sub-queries (#537)
Browse files Browse the repository at this point in the history
```typescript
qb.update({ name: 'test 123', type: PublisherType.GLOBAL }).where({ books: { author: 123 } });`
```

will result in following query:

```sql
update `publisher2` set `name` = ?, `type` = ? 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 #319
  • Loading branch information
B4nan committed Aug 9, 2020
1 parent 1699a30 commit cff9a3a
Show file tree
Hide file tree
Showing 7 changed files with 92 additions and 6 deletions.
6 changes: 6 additions & 0 deletions ROADMAP.md
Expand Up @@ -26,6 +26,8 @@ discuss specifics.
- [x] Embedded entities (allow in-lining child entity into parent one with prefixed keys)
- [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)
- [ ] 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 All @@ -36,6 +38,10 @@ discuss specifics.
- [ ] Use custom errors for specific cases (unique constraint violation, db not accessible, ...)
- [ ] Add custom types for blob, array, json
- [ ] Lazy scalar properties (allow having props that won't be loaded by default, but can be populated)
- [ ] Seeds (#251)
- [ ] Static checking of population (#214)
- [ ] Nested object validation (#466)
- [ ] Migrations Support for MongoDB (#295)

## Planned breaking changes for v4

Expand Down
6 changes: 6 additions & 0 deletions packages/knex/src/query/ArrayCriteriaNode.ts
Expand Up @@ -16,6 +16,12 @@ export class ArrayCriteriaNode extends CriteriaNode {
});
}

willAutoJoin(qb: QueryBuilder, alias?: string) {
return this.payload.some((node: CriteriaNode) => {
return node.willAutoJoin(qb, alias);
});
}

getPath(): string {
if (this.parent && this.parent.parent) {
return this.parent.parent.getPath();
Expand Down
4 changes: 4 additions & 0 deletions packages/knex/src/query/CriteriaNode.ts
Expand Up @@ -53,6 +53,10 @@ export class CriteriaNode {
return false;
}

willAutoJoin(qb: QueryBuilder, alias?: string) {
return false;
}

shouldRename(payload: any): boolean {
const type = this.prop ? this.prop.reference : null;
const composite = this.prop && this.prop.joinColumns ? this.prop.joinColumns.length > 1 : false;
Expand Down
18 changes: 18 additions & 0 deletions packages/knex/src/query/ObjectCriteriaNode.ts
Expand Up @@ -64,6 +64,24 @@ export class ObjectCriteriaNode extends CriteriaNode {
}, {});
}

willAutoJoin(qb: QueryBuilder, alias?: string): boolean {
const nestedAlias = qb.getAliasForEntity(this.entityName, this);
const ownerAlias = alias || qb.alias;

if (nestedAlias) {
alias = nestedAlias;
}

if (this.shouldAutoJoin(nestedAlias)) {
return true;
}

return Object.keys(this.payload).some(field => {
const childNode = this.payload[field] as CriteriaNode;
return childNode.willAutoJoin(qb, this.prop ? alias : ownerAlias);
});
}

shouldInline(payload: any): boolean {
const customExpression = QueryBuilderHelper.isCustomExpression(this.key!);
const scalar = Utils.isPrimaryKey(payload) || payload instanceof RegExp || payload instanceof Date || customExpression;
Expand Down
29 changes: 25 additions & 4 deletions packages/knex/src/query/QueryBuilder.ts
Expand Up @@ -113,13 +113,20 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {

const op = operator || params as keyof typeof GroupOperator;
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)) {
// use sub-query to support joining
this.select(this.metadata.get(this.entityName).primaryKeys, true);
this.setFlag(QueryFlag.UPDATE_SUB_QUERY);
}

if (topLevel) {
this._cond = CriteriaNode.create(this.metadata, this.entityName, cond).process(this);
this._cond = criteriaNode.process(this);
} else if (Array.isArray(this._cond[op])) {
this._cond[op].push(CriteriaNode.create(this.metadata, this.entityName, cond).process(this));
this._cond[op].push(criteriaNode.process(this));
} else {
const cond1 = [this._cond, CriteriaNode.create(this.metadata, this.entityName, cond).process(this)];
const cond1 = [this._cond, criteriaNode.process(this)];
this._cond = { [op]: cond1 };
}

Expand Down Expand Up @@ -433,6 +440,7 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
return;
}

const meta = this.metadata.get(this.entityName, false, false);
this._populate.forEach(field => {
const [fromAlias, fromField] = this.helper.splitField(field);
const aliasedField = `${fromAlias}.${fromField}`;
Expand All @@ -444,14 +452,27 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
if (this.metadata.has(field)) { // pivot table entity
this.autoJoinPivotTable(field);
} else if (this.helper.isOneToOneInverse(field)) {
const prop = this.metadata.get(this.entityName).properties[field];
const prop = meta.properties[field];
this._joins[prop.name] = this.helper.joinOneToReference(prop, this.alias, `e${this.aliasCounter++}`, 'leftJoin');
this._populateMap[field] = this._joins[field].alias;
}
});

SmartQueryHelper.processParams([this._data, this._cond, this._having]);
this.finalized = true;

if (this.flags.has(QueryFlag.UPDATE_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));

this.update(this._data).where({
[Utils.getPrimaryKeyHash(meta.primaryKeys)]: { $in: subSubQuery },
});
}
}

private autoJoinPivotTable(field: string): void {
Expand Down
1 change: 1 addition & 0 deletions packages/knex/src/query/enums.ts
Expand Up @@ -9,4 +9,5 @@ export enum QueryType {

export enum QueryFlag {
DISTINCT = 'DISTINCT',
UPDATE_SUB_QUERY = 'UPDATE_SUB_QUERY',
}
34 changes: 32 additions & 2 deletions tests/QueryBuilder.test.ts
@@ -1,8 +1,8 @@
import { inspect } from 'util';
import { LockMode, MikroORM, QueryOrder } from '@mikro-orm/core';
import { QueryFlag, CriteriaNode } from '@mikro-orm/knex';
import { QueryFlag, CriteriaNode, ArrayCriteriaNode } from '@mikro-orm/knex';
import { MySqlDriver } from '@mikro-orm/mysql';
import { Author2, Book2, BookTag2, Car2, CarOwner2, FooBar2, FooBaz2, Publisher2, PublisherType, Test2, User2 } from './entities-sql';
import { Author2, Book2, BookTag2, Car2, CarOwner2, FooBar2, FooBaz2, FooParam2, Publisher2, PublisherType, Test2, User2 } from './entities-sql';
import { initORMMySql } from './bootstrap';

describe('QueryBuilder', () => {
Expand Down Expand Up @@ -1064,6 +1064,36 @@ describe('QueryBuilder', () => {
expect(qb.getParams()).toEqual(['test 123', PublisherType.GLOBAL, 123, PublisherType.LOCAL]);
});

test('update query with auto-joining', async () => {
const qb = orm.em.createQueryBuilder(Publisher2);
qb.update({ name: 'test 123', type: PublisherType.GLOBAL }).where({ books: { author: 123 } });
expect(qb.getQuery()).toEqual('update `publisher2` set `name` = ?, `type` = ? ' +
'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(['test 123', PublisherType.GLOBAL, 123]);
});

test('update query with composite keys and auto-joining', async () => {
const qb = orm.em.createQueryBuilder(FooParam2);
qb.update({ value: 'test 123' }).where({ bar: { baz: 123 } });
expect(qb.getQuery()).toEqual('update `foo_param2` set `value` = ? ' +
'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(['test 123', 123]);
});

test('update query with or condition and auto-joining', async () => {
const qb = orm.em.createQueryBuilder(Publisher2);
qb.update({ name: 'test 123', type: PublisherType.GLOBAL }).where({ $or: [{ books: { author: 123 } }, { books: { title: 'book' } }] });
expect(qb.getQuery()).toEqual('update `publisher2` set `name` = ?, `type` = ? ' +
'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(['test 123', PublisherType.GLOBAL, 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 cff9a3a

Please sign in to comment.