From 40ae4d6b96fbc68ac8ff99edc3cd5209e0968527 Mon Sep 17 00:00:00 2001 From: Evan Trimboli Date: Tue, 23 Nov 2021 04:40:20 +1100 Subject: [PATCH] feat(core): add support for custom property ordering (#2444) --- docs/docs/decorators.md | 1 + docs/docs/entity-manager.md | 36 +++ packages/core/src/decorators/Property.ts | 1 + packages/core/src/platforms/Platform.ts | 8 + packages/core/src/typings.ts | 1 + packages/knex/src/AbstractSqlPlatform.ts | 9 + packages/knex/src/query/QueryBuilderHelper.ts | 10 +- tests/EntityManager.mongo.test.ts | 4 + .../custom-order/custom-order.mysql.test.ts | 259 ++++++++++++++++++ .../custom-order.postgres.test.ts | 259 ++++++++++++++++++ .../custom-order/custom-order.sqlite.test.ts | 259 ++++++++++++++++++ 11 files changed, 846 insertions(+), 1 deletion(-) create mode 100644 tests/features/custom-order/custom-order.mysql.test.ts create mode 100644 tests/features/custom-order/custom-order.postgres.test.ts create mode 100644 tests/features/custom-order/custom-order.sqlite.test.ts diff --git a/docs/docs/decorators.md b/docs/docs/decorators.md index 23c493c91e0b..40d11cea8b4d 100644 --- a/docs/docs/decorators.md +++ b/docs/docs/decorators.md @@ -46,6 +46,7 @@ extend the `@Property()` decorator, so you can also use its parameters there. | `comment` | `string` | yes | Specify comment of column for [Schema Generator](schema-generator.md).. **(SQL only)** | | `version` | `boolean` | yes | Set to true to enable [Optimistic Locking] via version field (transactions.md#optimistic-locking). **(SQL only)** | | `concurrencyCheck` | `boolean` | yes | Set to true to enable [Optimistic Locking] via concurrency fields (transactions.md#concurrency-checks).| +| `customOrder` | `string[] | number[] | boolean[]` | yes | Specify a custom order for the column. **(SQL only)** | > You can use property initializers as usual. diff --git a/docs/docs/entity-manager.md b/docs/docs/entity-manager.md index 5972370079a2..33dad1e07a5c 100644 --- a/docs/docs/entity-manager.md +++ b/docs/docs/entity-manager.md @@ -341,3 +341,39 @@ so you do not need to get them from `EntityManager` each time. For more examples, take a look at [`tests/EntityManager.mongo.test.ts`](https://github.com/mikro-orm/mikro-orm/blob/master/tests/EntityManager.mongo.test.ts) or [`tests/EntityManager.mysql.test.ts`](https://github.com/mikro-orm/mikro-orm/blob/master/tests/EntityManager.mysql.test.ts). + +## Custom Property Ordering +Entity properties provide some support for custom ordering via the `customOrder` attribute. This is +useful for values that have a natural order that doesn't align with their underlying data representation. Consider the code below, the natural sorting order would be `high`, `low`, `medium`. However we can provide the `customOrder` to indicate how the enum values should be sorted. + +```typescript +enum Priority { Low = 'low', Medium = 'medium', High = 'high' } +@Entity() +class Task { + @PrimaryKey() + id!: number + + @Property() + label!: string + + @Enum({ + items: () => Priority, + customOrder: [Priority.Low, Priority.Medium, Priority.High] + }) + priority!: Priority +} + +// ... + +await orm.em.persistAndFlush([ + orm.em.create(Task, { label: 'A', priority: Priority.Low }), + orm.em.create(Task, { label: 'B', priority: Priority.Medium }), + orm.em.create(Task, { label: 'C', priority: Priority.High }) +]); + +const tasks = await orm.em.find(Task, {}, { orderBy: { priority: QueryOrder.ASC } }); +for (const t of tasks) { + console.log(t.label); +} +// Logs A, B, C +``` \ No newline at end of file diff --git a/packages/core/src/decorators/Property.ts b/packages/core/src/decorators/Property.ts index ba726d797ae6..4fc85767d5b7 100644 --- a/packages/core/src/decorators/Property.ts +++ b/packages/core/src/decorators/Property.ts @@ -66,6 +66,7 @@ export type PropertyOptions = { serializedPrimaryKey?: boolean; serializer?: (value: any) => any; serializedName?: string; + customOrder?: string[] | number[] | boolean[]; comment?: string; /** mysql only */ extra?: string; diff --git a/packages/core/src/platforms/Platform.ts b/packages/core/src/platforms/Platform.ts index 79f8bcbfd6e3..57708b274ad0 100644 --- a/packages/core/src/platforms/Platform.ts +++ b/packages/core/src/platforms/Platform.ts @@ -381,4 +381,12 @@ export abstract class Platform { return; } + /** + * Generates a custom order by statement given a set of in order values, eg. + * ORDER BY (CASE WHEN priority = 'low' THEN 1 WHEN priority = 'medium' THEN 2 ELSE NULL END) + */ + generateCustomOrder(escapedColumn: string, values: unknown[]) { + throw new Error('Not supported'); + } + } diff --git a/packages/core/src/typings.ts b/packages/core/src/typings.ts index fe09e5f23bbd..74f2fa24bff3 100644 --- a/packages/core/src/typings.ts +++ b/packages/core/src/typings.ts @@ -237,6 +237,7 @@ export interface EntityProperty = any> { inversedBy: string; mappedBy: string; orderBy?: QueryOrderMap | QueryOrderMap[]; + customOrder?: string[] | number[] | boolean[]; fixedOrder?: boolean; fixedOrderColumn?: string; pivotTable: string; diff --git a/packages/knex/src/AbstractSqlPlatform.ts b/packages/knex/src/AbstractSqlPlatform.ts index b87a71442f39..1886ec8b7428 100644 --- a/packages/knex/src/AbstractSqlPlatform.ts +++ b/packages/knex/src/AbstractSqlPlatform.ts @@ -96,4 +96,13 @@ export abstract class AbstractSqlPlatform extends Platform { return false; } + /** @inheritDoc */ + generateCustomOrder(escapedColumn: string, values: unknown[]): string { + let ret = '(case '; + values.forEach((v, i) => { + ret += `when ${escapedColumn} = ${this.quoteValue(v)} then ${i} `; + }); + return ret + 'else null end)'; + } + } diff --git a/packages/knex/src/query/QueryBuilderHelper.ts b/packages/knex/src/query/QueryBuilderHelper.ts index 8071ddefa7c8..9ce0508a2f12 100644 --- a/packages/knex/src/query/QueryBuilderHelper.ts +++ b/packages/knex/src/query/QueryBuilderHelper.ts @@ -482,6 +482,7 @@ export class QueryBuilderHelper { // eslint-disable-next-line prefer-const let [alias, field] = this.splitField(k); alias = populate[alias] || alias; + Utils.splitPrimaryKeys(field).forEach(f => { const prop = this.getProperty(f, alias); const noPrefix = (prop && prop.persist === false) || QueryBuilderHelper.isCustomExpression(f); @@ -489,7 +490,14 @@ export class QueryBuilderHelper { /* istanbul ignore next */ const rawColumn = Utils.isString(column) ? column.split('.').map(e => this.knex.ref(e)).join('.') : column; - ret.push(`${rawColumn} ${order.toLowerCase()}`); + + const customOrder = prop?.customOrder; + + const colPart = customOrder + ? this.platform.generateCustomOrder(rawColumn, customOrder) + : rawColumn; + + ret.push(`${colPart} ${order.toLowerCase()}`); }); }); diff --git a/tests/EntityManager.mongo.test.ts b/tests/EntityManager.mongo.test.ts index ebb1e094ba3e..9c1723e85049 100644 --- a/tests/EntityManager.mongo.test.ts +++ b/tests/EntityManager.mongo.test.ts @@ -515,6 +515,10 @@ describe('EntityManagerMongo', () => { expect(driver.getConnection().getCollection(BookTag).collectionName).toBe('book-tag'); expect(orm.em.getCollection(BookTag).collectionName).toBe('book-tag'); + expect(() => { + driver.getPlatform().generateCustomOrder('foo', [1, 2, 3]); + }).toThrow(); + const conn = driver.getConnection(); const ctx = await conn.begin(); const first = await driver.nativeInsert(Publisher.name, { name: 'test 123', type: 'GLOBAL' }, { ctx }); diff --git a/tests/features/custom-order/custom-order.mysql.test.ts b/tests/features/custom-order/custom-order.mysql.test.ts new file mode 100644 index 000000000000..6be258ec0053 --- /dev/null +++ b/tests/features/custom-order/custom-order.mysql.test.ts @@ -0,0 +1,259 @@ +import { Collection, Entity, Enum, ManyToOne, MikroORM, OneToMany, PrimaryKey, Property, QueryOrder } from '@mikro-orm/core'; +import type { MySqlDriver } from '@mikro-orm/mysql'; +import { mockLogger } from '../../bootstrap'; + +type Rating = 'bad' | 'ok' | 'good'; + +enum Priority { + Low = 'low', + Medium = 'medium', + High = 'high' +} + +// Out of order on purpose +enum Difficulty { + Easy = 2, + Hard = 1, + Medium = 0 +} + +@Entity() +class User { + + @PrimaryKey() + id!: number; + + @Property() + name!: string; + + // eslint-disable-next-line @typescript-eslint/no-use-before-define + @OneToMany(() => Task, ({ owner }) => owner) + tasks = new Collection(this); + +} + +@Entity() +class Task { + + @PrimaryKey() + id!: number; + + @Property() + label!: string; + + @ManyToOne(() => User, { nullable: true }) + owner?: User; + + @Enum({ + items: () => Priority, + customOrder: [Priority.Low, Priority.Medium, Priority.High], + nullable: true, + }) + priority?: Priority; + + @Property({ customOrder: ['bad', 'ok', 'good'], nullable: true }) + rating?: Rating; + + @Enum({ + items: () => Difficulty, + customOrder: [Difficulty.Easy, Difficulty.Medium, Difficulty.Hard], + nullable: true, + }) + difficulty?: Difficulty; + +} + +const createWithPriority = (label: string, priority?: Priority) => { + const t = new Task(); + t.label = label; + t.priority = priority; + return t; +}; + +const createWithRating = (label: string, rating?: Rating) => { + const t = new Task(); + t.label = label; + t.rating = rating; + return t; +}; + +const createWithDifficulty = (label: string, difficulty?: Difficulty) => { + const t = new Task(); + t.label = label; + t.difficulty = difficulty; + return t; +}; + +describe('custom order [mysql]', () => { + + let orm: MikroORM; + + beforeAll(async () => { + orm = await MikroORM.init({ + entities: [Task, User], + dbName: `mikro_orm_test_custom_order`, + type: 'mysql', + port: 3307, + }); + + await orm.getSchemaGenerator().ensureDatabase(); + await orm.getSchemaGenerator().dropSchema(); + await orm.getSchemaGenerator().createSchema(); + }); + beforeEach(async () => { + await orm.em.nativeDelete(Task, {}); + await orm.em.nativeDelete(User, {}); + }); + afterAll(async () => orm.close(true)); + + test('query string enum ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithPriority('a', Priority.Medium), + createWithPriority('b', Priority.High), + createWithPriority('c', Priority.Low), + createWithPriority('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { priority: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['d', 'c', 'a', 'b']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`priority` = \'low\' then 0 when `t0`.`priority` = \'medium\' then 1 when `t0`.`priority` = \'high\' then 2 else null end) asc'); + }); + + test('query string enum DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithPriority('a', Priority.Medium), + createWithPriority('b', Priority.High), + createWithPriority('c', Priority.Low), + createWithPriority('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { priority: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['b', 'a', 'c', 'd']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`priority` = \'low\' then 0 when `t0`.`priority` = \'medium\' then 1 when `t0`.`priority` = \'high\' then 2 else null end) desc'); + }); + + test('query raw string ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithRating('a', 'good'), + createWithRating('b', 'bad'), + createWithRating('c', 'ok'), + createWithRating('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { rating: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['d', 'b', 'c', 'a']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`rating` = \'bad\' then 0 when `t0`.`rating` = \'ok\' then 1 when `t0`.`rating` = \'good\' then 2 else null end) asc'); + }); + + test('query raw string DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithRating('a', 'good'), + createWithRating('b', 'bad'), + createWithRating('c', 'ok'), + createWithRating('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { rating: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['a', 'c', 'b', 'd']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`rating` = \'bad\' then 0 when `t0`.`rating` = \'ok\' then 1 when `t0`.`rating` = \'good\' then 2 else null end) desc'); + }); + + test('query numeric enum ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithDifficulty('a', Difficulty.Hard), + createWithDifficulty('b'), + createWithDifficulty('c', Difficulty.Medium), + createWithDifficulty('d', Difficulty.Easy), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { difficulty: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['b', 'd', 'c', 'a']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`difficulty` = 2 then 0 when `t0`.`difficulty` = 0 then 1 when `t0`.`difficulty` = 1 then 2 else null end) asc'); + }); + + test('query numeric enum DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithDifficulty('a', Difficulty.Hard), + createWithDifficulty('b'), + createWithDifficulty('c', Difficulty.Medium), + createWithDifficulty('d', Difficulty.Easy), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { difficulty: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['a', 'c', 'd', 'b']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`difficulty` = 2 then 0 when `t0`.`difficulty` = 0 then 1 when `t0`.`difficulty` = 1 then 2 else null end) desc'); + }); + + test('multiple order', async () => { + const mock = mockLogger(orm); + + const { em } = orm; + + await em.persistAndFlush([ + em.create(Task, { label: 'a', priority: Priority.High, difficulty: Difficulty.Easy }), + em.create(Task, { label: 'b', priority: Priority.High, difficulty: Difficulty.Hard }), + em.create(Task, { label: 'c', priority: Priority.Low, difficulty: Difficulty.Hard }), + em.create(Task, { label: 'd', priority: Priority.Medium, difficulty: Difficulty.Medium }), + em.create(Task, { label: 'e', priority: Priority.Low, difficulty: Difficulty.Easy }), + em.create(Task, { label: 'f', priority: Priority.High, difficulty: Difficulty.Medium }), + ]); + em.clear(); + + const tasks = await em.find(Task, {}, { orderBy: { priority: QueryOrder.ASC, difficulty: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['c', 'e', 'd', 'b', 'f', 'a']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`priority` = \'low\' then 0 when `t0`.`priority` = \'medium\' then 1 when `t0`.`priority` = \'high\' then 2 else null end) asc, (case when `t0`.`difficulty` = 2 then 0 when `t0`.`difficulty` = 0 then 1 when `t0`.`difficulty` = 1 then 2 else null end) desc'); + }); + + test('as a relation', async () => { + const mock = mockLogger(orm); + + const { em } = orm; + + const user1 = em.create(User, { name: 'u1' }); + const user2 = em.create(User, { name: 'u2' }); + + user1.tasks.add(em.create(Task, { label: '1a', priority: Priority.High })); + user1.tasks.add(em.create(Task, { label: '1b', priority: Priority.Medium })); + user1.tasks.add(em.create(Task, { label: '1c', priority: Priority.Low })); + + user2.tasks.add(em.create(Task, { label: '2a', priority: Priority.Medium })); + user2.tasks.add(em.create(Task, { label: '2b', priority: Priority.Low })); + user2.tasks.add(em.create(Task, { label: '2c', priority: Priority.High })); + + await em.persistAndFlush([user1, user2]); + em.clear(); + + const users = await em.find(User, {}, { + populate: ['tasks'], + orderBy: { + name: QueryOrder.ASC, + tasks: { + priority: QueryOrder.ASC, + }, + }, + }); + + const ret = users.flatMap(u => u.tasks.getItems()).map(({ owner, label }) => `${owner?.name}-${label}`); + expect(ret).toEqual(['u1-1c', 'u1-1b', 'u1-1a', 'u2-2b', 'u2-2a', 'u2-2c']); + expect(mock.mock.calls[4][0]).toMatch('select `u0`.* from `user` as `u0` left join `task` as `t1` on `u0`.`id` = `t1`.`owner_id` order by `u0`.`name` asc, (case when `t1`.`priority` = \'low\' then 0 when `t1`.`priority` = \'medium\' then 1 when `t1`.`priority` = \'high\' then 2 else null end) asc'); + expect(mock.mock.calls[5][0]).toMatch('select `t0`.* from `task` as `t0` where `t0`.`owner_id` in (1, 2) order by (case when `t0`.`priority` = \'low\' then 0 when `t0`.`priority` = \'medium\' then 1 when `t0`.`priority` = \'high\' then 2 else null end) asc, `t0`.`owner_id` asc'); + }); +}); diff --git a/tests/features/custom-order/custom-order.postgres.test.ts b/tests/features/custom-order/custom-order.postgres.test.ts new file mode 100644 index 000000000000..e37d2e8e53f3 --- /dev/null +++ b/tests/features/custom-order/custom-order.postgres.test.ts @@ -0,0 +1,259 @@ +import { Entity, MikroORM, PrimaryKey, Property, Enum, QueryOrder, Collection, OneToMany, ManyToOne } from '@mikro-orm/core'; +import type { AbstractSqlDriver } from '@mikro-orm/knex'; +import { mockLogger } from '../../bootstrap'; + +type Rating = 'bad' | 'ok' | 'good'; + +enum Priority { + Low = 'low', + Medium = 'medium', + High = 'high' +} + +// Out of order on purpose +enum Difficulty { + Easy = 2, + Hard = 1, + Medium = 0 +} + +@Entity() +class User { + + @PrimaryKey() + id!: number; + + @Property() + name!: string; + + // eslint-disable-next-line @typescript-eslint/no-use-before-define + @OneToMany(() => Task, ({ owner }) => owner) + tasks = new Collection(this); + +} + +@Entity() +class Task { + + @PrimaryKey() + id!: number; + + @Property() + label!: string; + + @ManyToOne(() => User, { nullable: true }) + owner?: User; + + @Enum({ + items: () => Priority, + customOrder: [Priority.Low, Priority.Medium, Priority.High], + nullable: true, + }) + priority?: Priority; + + @Property({ customOrder: ['bad', 'ok', 'good'], nullable: true }) + rating?: Rating; + + @Enum({ + items: () => Difficulty, + customOrder: [Difficulty.Easy, Difficulty.Medium, Difficulty.Hard], + nullable: true, + }) + difficulty?: Difficulty; + +} + +const createWithPriority = (label: string, priority?: Priority) => { + const t = new Task(); + t.label = label; + t.priority = priority; + return t; +}; + +const createWithRating = (label: string, rating?: Rating) => { + const t = new Task(); + t.label = label; + t.rating = rating; + return t; +}; + +const createWithDifficulty = (label: string, difficulty?: Difficulty) => { + const t = new Task(); + t.label = label; + t.difficulty = difficulty; + return t; +}; + +describe('custom order [postgres]', () => { + + let orm: MikroORM; + + beforeAll(async () => { + orm = await MikroORM.init({ + entities: [User, Task], + dbName: `mikro_orm_test_custom_order`, + type: 'postgresql', + }); + await orm.getSchemaGenerator().ensureDatabase(); + await orm.getSchemaGenerator().dropSchema(); + await orm.getSchemaGenerator().createSchema(); + }); + + beforeEach(async () => { + await orm.em.createQueryBuilder(User).truncate().execute(); + await orm.em.createQueryBuilder(Task).truncate().execute(); + }); + + afterAll(() => orm.close(true)); + + test('query string enum ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithPriority('a', Priority.Medium), + createWithPriority('b', Priority.High), + createWithPriority('c', Priority.Low), + createWithPriority('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { priority: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['c', 'a', 'b', 'd']); + expect(mock.mock.calls[3][0]).toMatch(`select "t0".* from "task" as "t0" order by (case when "t0"."priority" = 'low' then 0 when "t0"."priority" = 'medium' then 1 when "t0"."priority" = 'high' then 2 else null end)`); + }); + + test('query string enum DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithPriority('a', Priority.Medium), + createWithPriority('b', Priority.High), + createWithPriority('c', Priority.Low), + createWithPriority('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { priority: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['d', 'b', 'a', 'c']); + expect(mock.mock.calls[3][0]).toMatch(`select "t0".* from "task" as "t0" order by (case when "t0"."priority" = 'low' then 0 when "t0"."priority" = 'medium' then 1 when "t0"."priority" = 'high' then 2 else null end)`); + }); + + test('query raw string ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithRating('a', 'good'), + createWithRating('b', 'bad'), + createWithRating('c', 'ok'), + createWithRating('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { rating: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['b', 'c', 'a', 'd']); + expect(mock.mock.calls[3][0]).toMatch(`select "t0".* from "task" as "t0" order by (case when "t0"."rating" = 'bad' then 0 when "t0"."rating" = 'ok' then 1 when "t0"."rating" = 'good' then 2 else null end)`); + }); + + test('query raw string DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithRating('a', 'good'), + createWithRating('b', 'bad'), + createWithRating('c', 'ok'), + createWithRating('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { rating: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['d', 'a', 'c', 'b']); + expect(mock.mock.calls[3][0]).toMatch(`select "t0".* from "task" as "t0" order by (case when "t0"."rating" = 'bad' then 0 when "t0"."rating" = 'ok' then 1 when "t0"."rating" = 'good' then 2 else null end) desc`); + }); + + test('query numeric enum ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithDifficulty('a', Difficulty.Hard), + createWithDifficulty('b'), + createWithDifficulty('c', Difficulty.Medium), + createWithDifficulty('d', Difficulty.Easy), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { difficulty: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['d', 'c', 'a', 'b']); + expect(mock.mock.calls[3][0]).toMatch(`select "t0".* from "task" as "t0" order by (case when "t0"."difficulty" = 2 then 0 when "t0"."difficulty" = 0 then 1 when "t0"."difficulty" = 1 then 2 else null end)`); + }); + + test('query numeric enum DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithDifficulty('a', Difficulty.Hard), + createWithDifficulty('b'), + createWithDifficulty('c', Difficulty.Medium), + createWithDifficulty('d', Difficulty.Easy), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { difficulty: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['b', 'a', 'c', 'd']); + expect(mock.mock.calls[3][0]).toMatch(`select "t0".* from "task" as "t0" order by (case when "t0"."difficulty" = 2 then 0 when "t0"."difficulty" = 0 then 1 when "t0"."difficulty" = 1 then 2 else null end) desc`); + }); + + test('multiple order', async () => { + const mock = mockLogger(orm); + + const { em } = orm; + + await em.persistAndFlush([ + em.create(Task, { label: 'a', priority: Priority.High, difficulty: Difficulty.Easy }), + em.create(Task, { label: 'b', priority: Priority.High, difficulty: Difficulty.Hard }), + em.create(Task, { label: 'c', priority: Priority.Low, difficulty: Difficulty.Hard }), + em.create(Task, { label: 'd', priority: Priority.Medium, difficulty: Difficulty.Medium }), + em.create(Task, { label: 'e', priority: Priority.Low, difficulty: Difficulty.Easy }), + em.create(Task, { label: 'f', priority: Priority.High, difficulty: Difficulty.Medium }), + ]); + em.clear(); + + const tasks = await em.find(Task, {}, { orderBy: { priority: QueryOrder.ASC, difficulty: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['c', 'e', 'd', 'b', 'f', 'a']); + expect(mock.mock.calls[3][0]).toMatch(`select "t0".* from "task" as "t0" order by (case when "t0"."priority" = 'low' then 0 when "t0"."priority" = 'medium' then 1 when "t0"."priority" = 'high' then 2 else null end) asc, (case when "t0"."difficulty" = 2 then 0 when "t0"."difficulty" = 0 then 1 when "t0"."difficulty" = 1 then 2 else null end) desc`); + }); + + test('as a relation', async () => { + const mock = mockLogger(orm); + + const { em } = orm; + + const user1 = em.create(User, { name: 'u1' }); + const user2 = em.create(User, { name: 'u2' }); + + user1.tasks.add(em.create(Task, { label: '1a', priority: Priority.High })); + user1.tasks.add(em.create(Task, { label: '1b', priority: Priority.Medium })); + user1.tasks.add(em.create(Task, { label: '1c', priority: Priority.Low })); + + user2.tasks.add(em.create(Task, { label: '2a', priority: Priority.Medium })); + user2.tasks.add(em.create(Task, { label: '2b', priority: Priority.Low })); + user2.tasks.add(em.create(Task, { label: '2c', priority: Priority.High })); + + await em.persistAndFlush([user1, user2]); + em.clear(); + + const users = await em.find(User, {}, { + populate: ['tasks'], + orderBy: { + name: QueryOrder.ASC, + tasks: { + priority: QueryOrder.ASC, + }, + }, + }); + + const ret = users.flatMap(u => u.tasks.getItems()).map(({ owner, label }) => `${owner?.name}-${label}`); + expect(ret).toEqual(['u1-1c', 'u1-1b', 'u1-1a', 'u2-2b', 'u2-2a', 'u2-2c']); + expect(mock.mock.calls[4][0]).toMatch(`select "u0".* from "user" as "u0" left join "task" as "t1" on "u0"."id" = "t1"."owner_id" order by "u0"."name" asc, (case when "t1"."priority" = 'low' then 0 when "t1"."priority" = 'medium' then 1 when "t1"."priority" = 'high' then 2 else null end) asc`); + expect(mock.mock.calls[5][0]).toMatch(`select "t0".* from "task" as "t0" where "t0"."owner_id" in (1, 2) order by (case when "t0"."priority" = 'low' then 0 when "t0"."priority" = 'medium' then 1 when "t0"."priority" = 'high' then 2 else null end) asc, "t0"."owner_id" asc`); + }); +}); diff --git a/tests/features/custom-order/custom-order.sqlite.test.ts b/tests/features/custom-order/custom-order.sqlite.test.ts new file mode 100644 index 000000000000..b866064a6417 --- /dev/null +++ b/tests/features/custom-order/custom-order.sqlite.test.ts @@ -0,0 +1,259 @@ +import { Entity, MikroORM, PrimaryKey, Property, Enum, QueryOrder, OneToMany, Collection, ManyToOne } from '@mikro-orm/core'; +import type { SqliteDriver } from '@mikro-orm/sqlite'; +import { mockLogger } from '../../bootstrap'; + +type Rating = 'bad' | 'ok' | 'good'; + +enum Priority { + Low = 'low', + Medium = 'medium', + High = 'high' +} + +// Out of order on purpose +enum Difficulty { + Easy = 2, + Hard = 1, + Medium = 0 +} + +@Entity() +class User { + + @PrimaryKey() + id!: number; + + @Property() + name!: string; + + // eslint-disable-next-line @typescript-eslint/no-use-before-define + @OneToMany(() => Task, ({ owner }) => owner) + tasks = new Collection(this); + +} + +@Entity() +class Task { + + @PrimaryKey() + id!: number; + + @Property() + label!: string; + + @ManyToOne(() => User, { nullable: true }) + owner?: User; + + @Enum({ + items: () => Priority, + customOrder: [Priority.Low, Priority.Medium, Priority.High], + nullable: true, + }) + priority?: Priority; + + @Property({ customOrder: ['bad', 'ok', 'good'], nullable: true }) + rating?: Rating; + + @Enum({ + items: () => Difficulty, + customOrder: [Difficulty.Easy, Difficulty.Medium, Difficulty.Hard], + nullable: true, + }) + difficulty?: Difficulty; + +} + +const createWithPriority = (label: string, priority?: Priority) => { + const t = new Task(); + t.label = label; + t.priority = priority; + return t; +}; + +const createWithRating = (label: string, rating?: Rating) => { + const t = new Task(); + t.label = label; + t.rating = rating; + return t; +}; + +const createWithDifficulty = (label: string, difficulty?: Difficulty) => { + const t = new Task(); + t.label = label; + t.difficulty = difficulty; + return t; +}; + +describe('custom order [sqlite]', () => { + + let orm: MikroORM; + + beforeAll(async () => { + orm = await MikroORM.init({ + entities: [User, Task], + type: 'sqlite', + dbName: ':memory:', + }); + await orm.getSchemaGenerator().dropSchema(); + await orm.getSchemaGenerator().createSchema(); + }); + + beforeEach(async () => { + await orm.em.createQueryBuilder(Task).truncate().execute(); + await orm.em.createQueryBuilder(User).truncate().execute(); + }); + + afterAll(() => orm.close(true)); + + test('query string enum ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithPriority('a', Priority.Medium), + createWithPriority('b', Priority.High), + createWithPriority('c', Priority.Low), + createWithPriority('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { priority: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['d', 'c', 'a', 'b']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`priority` = \'low\' then 0 when `t0`.`priority` = \'medium\' then 1 when `t0`.`priority` = \'high\' then 2 else null end) asc'); + }); + + test('query string enum DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithPriority('a', Priority.Medium), + createWithPriority('b', Priority.High), + createWithPriority('c', Priority.Low), + createWithPriority('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { priority: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['b', 'a', 'c', 'd']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`priority` = \'low\' then 0 when `t0`.`priority` = \'medium\' then 1 when `t0`.`priority` = \'high\' then 2 else null end) desc'); + }); + + test('query raw string ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithRating('a', 'good'), + createWithRating('b', 'bad'), + createWithRating('c', 'ok'), + createWithRating('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { rating: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['d', 'b', 'c', 'a']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`rating` = \'bad\' then 0 when `t0`.`rating` = \'ok\' then 1 when `t0`.`rating` = \'good\' then 2 else null end) asc'); + }); + + test('query raw string DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithRating('a', 'good'), + createWithRating('b', 'bad'), + createWithRating('c', 'ok'), + createWithRating('d'), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { rating: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['a', 'c', 'b', 'd']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`rating` = \'bad\' then 0 when `t0`.`rating` = \'ok\' then 1 when `t0`.`rating` = \'good\' then 2 else null end) desc'); + }); + + test('query numeric enum ASC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithDifficulty('a', Difficulty.Hard), + createWithDifficulty('b'), + createWithDifficulty('c', Difficulty.Medium), + createWithDifficulty('d', Difficulty.Easy), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { difficulty: QueryOrder.ASC } }); + expect(tasks.map(({ label }) => label)).toEqual(['b', 'd', 'c', 'a']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`difficulty` = 2 then 0 when `t0`.`difficulty` = 0 then 1 when `t0`.`difficulty` = 1 then 2 else null end) asc'); + }); + + test('query numeric enum DESC', async () => { + const mock = mockLogger(orm); + + await orm.em.persistAndFlush([ + createWithDifficulty('a', Difficulty.Hard), + createWithDifficulty('b'), + createWithDifficulty('c', Difficulty.Medium), + createWithDifficulty('d', Difficulty.Easy), + ]); + orm.em.clear(); + + const tasks = await orm.em.find(Task, {}, { orderBy: { difficulty: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['a', 'c', 'd', 'b']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`difficulty` = 2 then 0 when `t0`.`difficulty` = 0 then 1 when `t0`.`difficulty` = 1 then 2 else null end) desc'); + }); + + test('multiple order', async () => { + const mock = mockLogger(orm); + + const { em } = orm; + + await em.persistAndFlush([ + em.create(Task, { label: 'a', priority: Priority.High, difficulty: Difficulty.Easy }), + em.create(Task, { label: 'b', priority: Priority.High, difficulty: Difficulty.Hard }), + em.create(Task, { label: 'c', priority: Priority.Low, difficulty: Difficulty.Hard }), + em.create(Task, { label: 'd', priority: Priority.Medium, difficulty: Difficulty.Medium }), + em.create(Task, { label: 'e', priority: Priority.Low, difficulty: Difficulty.Easy }), + em.create(Task, { label: 'f', priority: Priority.High, difficulty: Difficulty.Medium }), + ]); + em.clear(); + + const tasks = await em.find(Task, {}, { orderBy: { priority: QueryOrder.ASC, difficulty: QueryOrder.DESC } }); + expect(tasks.map(({ label }) => label)).toEqual(['c', 'e', 'd', 'b', 'f', 'a']); + expect(mock.mock.calls[3][0]).toMatch('select `t0`.* from `task` as `t0` order by (case when `t0`.`priority` = \'low\' then 0 when `t0`.`priority` = \'medium\' then 1 when `t0`.`priority` = \'high\' then 2 else null end) asc, (case when `t0`.`difficulty` = 2 then 0 when `t0`.`difficulty` = 0 then 1 when `t0`.`difficulty` = 1 then 2 else null end) desc'); + }); + + test('as a relation', async () => { + const mock = mockLogger(orm); + + const { em } = orm; + + const user1 = em.create(User, { name: 'u1' }); + const user2 = em.create(User, { name: 'u2' }); + + user1.tasks.add(em.create(Task, { label: '1a', priority: Priority.High })); + user1.tasks.add(em.create(Task, { label: '1b', priority: Priority.Medium })); + user1.tasks.add(em.create(Task, { label: '1c', priority: Priority.Low })); + + user2.tasks.add(em.create(Task, { label: '2a', priority: Priority.Medium })); + user2.tasks.add(em.create(Task, { label: '2b', priority: Priority.Low })); + user2.tasks.add(em.create(Task, { label: '2c', priority: Priority.High })); + + await em.persistAndFlush([user1, user2]); + em.clear(); + + const users = await em.find(User, {}, { + populate: ['tasks'], + orderBy: { + name: QueryOrder.ASC, + tasks: { + priority: QueryOrder.ASC, + }, + }, + }); + + const ret = users.flatMap(u => u.tasks.getItems()).map(({ owner, label }) => `${owner?.name}-${label}`); + expect(ret).toEqual(['u1-1c', 'u1-1b', 'u1-1a', 'u2-2b', 'u2-2a', 'u2-2c']); + expect(mock.mock.calls[4][0]).toMatch('select `u0`.* from `user` as `u0` left join `task` as `t1` on `u0`.`id` = `t1`.`owner_id` order by `u0`.`name` asc, (case when `t1`.`priority` = \'low\' then 0 when `t1`.`priority` = \'medium\' then 1 when `t1`.`priority` = \'high\' then 2 else null end) asc'); + expect(mock.mock.calls[5][0]).toMatch('select `t0`.* from `task` as `t0` where `t0`.`owner_id` in (1, 2) order by (case when `t0`.`priority` = \'low\' then 0 when `t0`.`priority` = \'medium\' then 1 when `t0`.`priority` = \'high\' then 2 else null end) asc, `t0`.`owner_id` asc'); + }); + +});