Skip to content

Commit

Permalink
feat(sql): add support for computed properties via @Formula() (#553)
Browse files Browse the repository at this point in the history
`@Formula()` decorator can be used to map some SQL snippet to your entity.
The SQL fragment can be as complex as you want and even include subselects.

```typescript
@formula('obj_length * obj_height * obj_width')
objectVolume?: number;
```

Formulas will be added to the select clause automatically. In case you are facing
problems with `NonUniqueFieldNameException`, you can define the formula as a
callback that will receive the entity alias in the parameter:

```typescript
@formula(alias => `${alias}.obj_length * ${alias}.obj_height * ${alias}.obj_width`)
objectVolume?: number;
```
  • Loading branch information
B4nan committed Aug 9, 2020
1 parent 2f6687a commit 68b9336
Show file tree
Hide file tree
Showing 15 changed files with 143 additions and 52 deletions.
2 changes: 1 addition & 1 deletion ROADMAP.md
Expand Up @@ -31,8 +31,8 @@ discuss specifics.
- [x] Use custom errors for specific cases (unique constraint violation, db not accessible, ...)
- [x] Paginator helper or something similar ([doctrine docs](https://www.doctrine-project.org/projects/doctrine-orm/en/latest/tutorials/pagination.html))
- [x] Add `groupBy` and `distinct` to `FindOptions` and `FindOneOptions`
- [x] Support computed properties via `@Formula()` decorator
- [ ] Lazy scalar properties (allow having props that won't be loaded by default, but can be populated)
- [ ] Support computed properties
- [ ] 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
16 changes: 16 additions & 0 deletions docs/docs/decorators.md
Expand Up @@ -137,6 +137,22 @@ enum3 = 3;
enum4 = 'a';
```

### @Formula()

`@Formula()` decorator can be used to map some SQL snippet to your entity.
The SQL fragment can be as complex as you want and even include subselects.

See [Defining Entities](defining-entities.md#formulas).

| Parameter | Type | Optional | Description |
|-----------|------|----------|-------------|
| `formula` | `string` | `() => string` | no | SQL fragment that will be part of the select clause. |

```typescript
@Formula('obj_length * obj_height * obj_width')
objectVolume?: number;
```

### @Index() and @Unique()

Use `@Index()` to create an index, or `@Unique()` to create unique constraint. You can
Expand Down
19 changes: 19 additions & 0 deletions docs/docs/defining-entities.md
Expand Up @@ -256,6 +256,25 @@ export const enum UserStatus {
// export { OutsideEnum } from './OutsideEnum.ts';
```

## Formulas

`@Formula()` decorator can be used to map some SQL snippet to your entity.
The SQL fragment can be as complex as you want and even include subselects.

```typescript
@Formula('obj_length * obj_height * obj_width')
objectVolume?: number;
```

Formulas will be added to the select clause automatically. In case you are facing
problems with `NonUniqueFieldNameException`, you can define the formula as a
callback that will receive the entity alias in the parameter:

```typescript
@Formula(alias => `${alias}.obj_length * ${alias}.obj_height * ${alias}.obj_width`)
objectVolume?: number;
```

## Indexes

You can define indexes via `@Index()` decorator, for unique indexes, use `@Unique()` decorator.
Expand Down
10 changes: 10 additions & 0 deletions packages/core/src/decorators/Formula.ts
@@ -0,0 +1,10 @@
import { MetadataStorage } from '../metadata';
import { ReferenceType } from '../entity';
import { EntityProperty, AnyEntity } from '../typings';

export function Formula(formula: string | ((alias: string) => string)): Function {
return function (target: AnyEntity, propertyName: string) {
const meta = MetadataStorage.getMetadataFromDecorator(target.constructor);
meta.properties[propertyName] = { name: propertyName, reference: ReferenceType.SCALAR, persist: false, formula } as EntityProperty;
};
}
1 change: 1 addition & 0 deletions packages/core/src/decorators/Property.ts
Expand Up @@ -44,6 +44,7 @@ export type PropertyOptions = {
onUpdate?: () => any;
default?: string | number | boolean | null;
defaultRaw?: string;
formula?: string | ((alias: string) => string);
nullable?: boolean;
unsigned?: boolean;
persist?: boolean;
Expand Down
1 change: 1 addition & 0 deletions packages/core/src/decorators/index.ts
Expand Up @@ -6,6 +6,7 @@ export * from './ManyToMany';
export { OneToMany, OneToManyOptions } from './OneToMany';
export * from './Property';
export * from './Enum';
export * from './Formula';
export * from './Indexed';
export * from './Repository';
export * from './Embeddable';
Expand Down
5 changes: 5 additions & 0 deletions packages/core/src/metadata/EntitySchema.ts
Expand Up @@ -66,6 +66,11 @@ export class EntitySchema<T extends AnyEntity<T> = AnyEntity, U extends AnyEntit
prop.type = type as string;
}

if (Utils.isString(prop.formula)) {
const formula = prop.formula as string; // tmp var is needed here
prop.formula = () => formula;
}

this._meta.properties[name] = prop;
}

Expand Down
1 change: 1 addition & 0 deletions packages/core/src/typings.ts
Expand Up @@ -110,6 +110,7 @@ export interface EntityProperty<T extends AnyEntity<T> = any> {
fieldNames: string[];
default?: string | number | boolean | null;
defaultRaw?: string;
formula?: (alias: string) => string;
prefix?: string | boolean;
embedded?: [string, string];
embeddable: Constructor<T>;
Expand Down
10 changes: 10 additions & 0 deletions packages/knex/src/query/QueryBuilder.ts
Expand Up @@ -458,6 +458,16 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
}
});

if (this.metadata.has(this.entityName) && (this._fields?.includes('*') || this._fields?.includes(`${this.alias}.*`))) {
Object.values(meta.properties)
.filter(prop => prop.formula)
.forEach(prop => {
const formula = this.knex.ref(this.alias).toString();
const alias = this.knex.ref(prop.fieldNames[0]).toString();
this.addSelect(`${prop.formula!(formula)} as ${alias}`);
});
}

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

Expand Down
1 change: 1 addition & 0 deletions tests/EntityHelper.mysql.test.ts
Expand Up @@ -114,6 +114,7 @@ describe('EntityHelperMySql', () => {
fooBar: null,
id: 1,
name: 'fb',
random: 123,
version: a.version,
});
});
Expand Down
41 changes: 31 additions & 10 deletions tests/EntityManager.mysql.test.ts
Expand Up @@ -816,15 +816,15 @@ describe('EntityManagerMySql', () => {

const b1 = (await orm.em.findOne(FooBaz2, { id: baz.id }, ['bar']))!;
expect(mock.mock.calls[1][0]).toMatch('select `e0`.*, `e1`.`id` as `bar_id` from `foo_baz2` as `e0` left join `foo_bar2` as `e1` on `e0`.`id` = `e1`.`baz_id` where `e0`.`id` = ? limit ?');
expect(mock.mock.calls[2][0]).toMatch('select `e0`.* from `foo_bar2` as `e0` where `e0`.`id` in (?) order by `e0`.`id` asc');
expect(mock.mock.calls[2][0]).toMatch('select `e0`.*, (select 123) as `random` from `foo_bar2` as `e0` where `e0`.`id` in (?) order by `e0`.`id` asc');
expect(b1.bar).toBeInstanceOf(FooBar2);
expect(b1.bar!.id).toBe(bar.id);
expect(wrap(b1).toJSON()).toMatchObject({ bar: wrap(bar).toJSON() });
orm.em.clear();

const b2 = (await orm.em.findOne(FooBaz2, { bar: bar.id }, ['bar']))!;
expect(mock.mock.calls[3][0]).toMatch('select `e0`.*, `e1`.`id` as `bar_id` from `foo_baz2` as `e0` left join `foo_bar2` as `e1` on `e0`.`id` = `e1`.`baz_id` where `e1`.`id` = ? limit ?');
expect(mock.mock.calls[4][0]).toMatch('select `e0`.* from `foo_bar2` as `e0` where `e0`.`id` in (?) order by `e0`.`id` asc');
expect(mock.mock.calls[4][0]).toMatch('select `e0`.*, (select 123) as `random` from `foo_bar2` as `e0` where `e0`.`id` in (?) order by `e0`.`id` asc');
expect(b2.bar).toBeInstanceOf(FooBar2);
expect(b2.bar!.id).toBe(bar.id);
expect(wrap(b2).toJSON()).toMatchObject({ bar: wrap(bar).toJSON() });
Expand Down Expand Up @@ -1293,7 +1293,7 @@ describe('EntityManagerMySql', () => {

orm.em.clear();
const books = await orm.em.find(Book2, { tagsUnordered: { name: { $ne: 'funny' } } }, ['tagsUnordered'], { title: QueryOrder.DESC });
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e3`.`id` as `test_id` from `book2` as `e0` ' +
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e3`.`id` as `test_id` from `book2` as `e0` ' +
'left join `book_to_tag_unordered` as `e2` on `e0`.`uuid_pk` = `e2`.`book2_uuid_pk` ' +
'left join `book_tag2` as `e1` on `e2`.`book_tag2_id` = `e1`.`id` ' +
'left join `test2` as `e3` on `e0`.`uuid_pk` = `e3`.`book_uuid_pk` ' +
Expand All @@ -1310,7 +1310,7 @@ describe('EntityManagerMySql', () => {
orm.em.clear();
mock.mock.calls.length = 0;
const tags = await orm.em.find(BookTag2, { booksUnordered: { title: { $ne: 'My Life on The Wall, part 3' } } }, ['booksUnordered'], { name: QueryOrder.ASC });
expect(mock.mock.calls[1][0]).toMatch('select `e0`.*, `e1`.`book2_uuid_pk`, `e1`.`book_tag2_id`, `e2`.`id` as `test_id` from `book2` as `e0` ' +
expect(mock.mock.calls[1][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e1`.`book2_uuid_pk`, `e1`.`book_tag2_id`, `e2`.`id` as `test_id` from `book2` as `e0` ' +
'left join `book_to_tag_unordered` as `e1` on `e0`.`uuid_pk` = `e1`.`book2_uuid_pk` ' +
'left join `test2` as `e2` on `e0`.`uuid_pk` = `e2`.`book_uuid_pk` ' +
'where `e0`.`title` != ? and `e1`.`book_tag2_id` in (?, ?, ?, ?, ?, ?)');
Expand Down Expand Up @@ -1590,7 +1590,7 @@ describe('EntityManagerMySql', () => {
expect(res1[0].test).toBeInstanceOf(Test2);
expect(wrap(res1[0].test).isInitialized()).toBe(false);
expect(mock.mock.calls.length).toBe(1);
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e2`.`id` as `test_id` ' +
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e2`.`id` as `test_id` ' +
'from `book2` as `e0` ' +
'left join `author2` as `e1` on `e0`.`author_id` = `e1`.`id` ' +
'left join `test2` as `e2` on `e0`.`uuid_pk` = `e2`.`book_uuid_pk` ' + // auto-joined 1:1 to get test id as book is inverse side
Expand All @@ -1603,7 +1603,7 @@ describe('EntityManagerMySql', () => {
expect(res2[0].test).toBeInstanceOf(Test2);
expect(wrap(res2[0].test).isInitialized()).toBe(false);
expect(mock.mock.calls.length).toBe(1);
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e4`.`id` as `test_id` ' +
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e4`.`id` as `test_id` ' +
'from `book2` as `e0` ' +
'left join `author2` as `e1` on `e0`.`author_id` = `e1`.`id` ' +
'left join `book2` as `e2` on `e1`.`favourite_book_uuid_pk` = `e2`.`uuid_pk` ' +
Expand All @@ -1618,7 +1618,7 @@ describe('EntityManagerMySql', () => {
expect(res3[0].test).toBeInstanceOf(Test2);
expect(wrap(res3[0].test).isInitialized()).toBe(false);
expect(mock.mock.calls.length).toBe(1);
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e2`.`id` as `test_id` ' +
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e2`.`id` as `test_id` ' +
'from `book2` as `e0` ' +
'left join `author2` as `e1` on `e0`.`author_id` = `e1`.`id` ' +
'left join `test2` as `e2` on `e0`.`uuid_pk` = `e2`.`book_uuid_pk` ' +
Expand All @@ -1631,7 +1631,7 @@ describe('EntityManagerMySql', () => {
expect(res4[0].test).toBeInstanceOf(Test2);
expect(wrap(res4[0].test).isInitialized()).toBe(false);
expect(mock.mock.calls.length).toBe(1);
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e4`.`id` as `test_id` ' +
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e4`.`id` as `test_id` ' +
'from `book2` as `e0` ' +
'left join `author2` as `e1` on `e0`.`author_id` = `e1`.`id` ' +
'left join `book2` as `e2` on `e1`.`favourite_book_uuid_pk` = `e2`.`uuid_pk` ' +
Expand Down Expand Up @@ -1815,8 +1815,8 @@ describe('EntityManagerMySql', () => {

const res1 = await orm.em.find(Book2, { publisher: { $ne: null } }, { schema: 'mikro_orm_test_schema_2' });
const res2 = await orm.em.find(Book2, { publisher: { $ne: null } });
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e1`.`id` as `test_id` from `mikro_orm_test_schema_2`.`book2` as `e0` left join `mikro_orm_test_schema_2`.`test2` as `e1` on `e0`.`uuid_pk` = `e1`.`book_uuid_pk` where `e0`.`publisher_id` is not null');
expect(mock.mock.calls[1][0]).toMatch('select `e0`.*, `e1`.`id` as `test_id` from `book2` as `e0` left join `test2` as `e1` on `e0`.`uuid_pk` = `e1`.`book_uuid_pk` where `e0`.`publisher_id` is not null');
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e1`.`id` as `test_id` from `mikro_orm_test_schema_2`.`book2` as `e0` left join `mikro_orm_test_schema_2`.`test2` as `e1` on `e0`.`uuid_pk` = `e1`.`book_uuid_pk` where `e0`.`publisher_id` is not null');
expect(mock.mock.calls[1][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e1`.`id` as `test_id` from `book2` as `e0` left join `test2` as `e1` on `e0`.`uuid_pk` = `e1`.`book_uuid_pk` where `e0`.`publisher_id` is not null');
expect(res1.length).toBe(0);
expect(res2.length).toBe(1);
});
Expand Down Expand Up @@ -2033,6 +2033,27 @@ describe('EntityManagerMySql', () => {
expect(res3.map(a => a.name)).toEqual(['God 01', 'God 02', 'God 03', 'God 04', 'God 05']);
});

test('formulas', async () => {
const god = new Author2('God', 'hello@heaven.god');
const bible = new Book2('Bible', god);
bible.price = 1000;
await orm.em.persistAndFlush(bible);
orm.em.clear();

const mock = jest.fn();
const logger = new Logger(mock, true);
Object.assign(orm.em.config, { logger });

const b = await orm.em.findOneOrFail(Book2, { author: { name: 'God' } });
expect(b.price).toBe(1000);
expect(b.priceTaxed).toBe(1190);
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e0`.price * 1.19 as `price_taxed`, `e2`.`id` as `test_id` ' +
'from `book2` as `e0` ' +
'left join `author2` as `e1` on `e0`.`author_id` = `e1`.`id` ' +
'left join `test2` as `e2` on `e0`.`uuid_pk` = `e2`.`book_uuid_pk` ' +
'where `e1`.`name` = ? limit ?');
});

test('exceptions', async () => {
await orm.em.nativeInsert(Author2, { name: 'author', email: 'email' });
await expect(orm.em.nativeInsert(Author2, { name: 'author', email: 'email' })).rejects.toThrow(UniqueConstraintViolationException);
Expand Down
12 changes: 6 additions & 6 deletions tests/EntityManager.postgre.test.ts
Expand Up @@ -642,15 +642,15 @@ describe('EntityManagerPostgre', () => {

const b1 = await orm.em.findOneOrFail(FooBaz2, { id: baz.id }, ['bar']);
expect(mock.mock.calls[1][0]).toMatch('select "e0".*, "e1"."id" as "bar_id" from "foo_baz2" as "e0" left join "foo_bar2" as "e1" on "e0"."id" = "e1"."baz_id" where "e0"."id" = $1 limit $2');
expect(mock.mock.calls[2][0]).toMatch('select "e0".* from "foo_bar2" as "e0" where "e0"."baz_id" in ($1) order by "e0"."baz_id" asc');
expect(mock.mock.calls[2][0]).toMatch('select "e0".*, (select 123) as "random" from "foo_bar2" as "e0" where "e0"."baz_id" in ($1) order by "e0"."baz_id" asc');
expect(b1.bar).toBeInstanceOf(FooBar2);
expect(b1.bar!.id).toBe(bar.id);
expect(wrap(b1).toJSON()).toMatchObject({ bar: wrap(bar).toJSON() });
orm.em.clear();

const b2 = await orm.em.findOneOrFail(FooBaz2, { bar: bar.id }, ['bar']);
expect(mock.mock.calls[3][0]).toMatch('select "e0".*, "e1"."id" as "bar_id" from "foo_baz2" as "e0" left join "foo_bar2" as "e1" on "e0"."id" = "e1"."baz_id" where "e1"."id" = $1 limit $2');
expect(mock.mock.calls[4][0]).toMatch('select "e0".* from "foo_bar2" as "e0" where "e0"."baz_id" in ($1) order by "e0"."baz_id" asc');
expect(mock.mock.calls[4][0]).toMatch('select "e0".*, (select 123) as "random" from "foo_bar2" as "e0" where "e0"."baz_id" in ($1) order by "e0"."baz_id" asc');
expect(b2.bar).toBeInstanceOf(FooBar2);
expect(b2.bar!.id).toBe(bar.id);
expect(wrap(b2).toJSON()).toMatchObject({ bar: wrap(bar).toJSON() });
Expand Down Expand Up @@ -1126,7 +1126,7 @@ describe('EntityManagerPostgre', () => {
expect(res1).toHaveLength(3);
expect(res1[0].test).toBeUndefined();
expect(mock.mock.calls.length).toBe(1);
expect(mock.mock.calls[0][0]).toMatch('select "e0".* ' +
expect(mock.mock.calls[0][0]).toMatch('select "e0".*, "e0".price * 1.19 as "price_taxed" ' +
'from "book2" as "e0" ' +
'left join "author2" as "e1" on "e0"."author_id" = "e1"."id" ' +
'where "e1"."name" = $1');
Expand All @@ -1136,7 +1136,7 @@ describe('EntityManagerPostgre', () => {
const res2 = await orm.em.find(Book2, { author: { favouriteBook: { author: { name: 'Jon Snow' } } } });
expect(res2).toHaveLength(3);
expect(mock.mock.calls.length).toBe(1);
expect(mock.mock.calls[0][0]).toMatch('select "e0".* ' +
expect(mock.mock.calls[0][0]).toMatch('select "e0".*, "e0".price * 1.19 as "price_taxed" ' +
'from "book2" as "e0" ' +
'left join "author2" as "e1" on "e0"."author_id" = "e1"."id" ' +
'left join "book2" as "e2" on "e1"."favourite_book_uuid_pk" = "e2"."uuid_pk" ' +
Expand All @@ -1148,7 +1148,7 @@ describe('EntityManagerPostgre', () => {
const res3 = await orm.em.find(Book2, { author: { favouriteBook: book3 } });
expect(res3).toHaveLength(3);
expect(mock.mock.calls.length).toBe(1);
expect(mock.mock.calls[0][0]).toMatch('select "e0".* ' +
expect(mock.mock.calls[0][0]).toMatch('select "e0".*, "e0".price * 1.19 as "price_taxed" ' +
'from "book2" as "e0" ' +
'left join "author2" as "e1" on "e0"."author_id" = "e1"."id" ' +
'where "e1"."favourite_book_uuid_pk" = $1');
Expand All @@ -1158,7 +1158,7 @@ describe('EntityManagerPostgre', () => {
const res4 = await orm.em.find(Book2, { author: { favouriteBook: { $or: [{ author: { name: 'Jon Snow' } }] } } });
expect(res4).toHaveLength(3);
expect(mock.mock.calls.length).toBe(1);
expect(mock.mock.calls[0][0]).toMatch('select "e0".* ' +
expect(mock.mock.calls[0][0]).toMatch('select "e0".*, "e0".price * 1.19 as "price_taxed" ' +
'from "book2" as "e0" ' +
'left join "author2" as "e1" on "e0"."author_id" = "e1"."id" ' +
'left join "book2" as "e2" on "e1"."favourite_book_uuid_pk" = "e2"."uuid_pk" ' +
Expand Down

0 comments on commit 68b9336

Please sign in to comment.