Skip to content

Commit

Permalink
feat(mysql): support order by nulls first/last (#5021)
Browse files Browse the repository at this point in the history
- Added `getOrderByExpression` to AbstractSqlPlatform.ts as an
overridable method to format `orderBy` queries. This uses syntax that is
recognized by both SQLite and PostGreSQL
- Added override of `getOrderByExpression` to MariaDbPlatform.ts and
MySqlPlatform.ts that adds functionality to handle `(ASC|DESC) NULLS
(FIRST|LAST)` syntax

Closes #5004
  • Loading branch information
kpervin committed Dec 14, 2023
1 parent f845bfd commit df75b24
Show file tree
Hide file tree
Showing 5 changed files with 57 additions and 5 deletions.
7 changes: 7 additions & 0 deletions packages/knex/src/AbstractSqlPlatform.ts
Original file line number Diff line number Diff line change
Expand Up @@ -135,4 +135,11 @@ export abstract class AbstractSqlPlatform extends Platform {
return ret + 'else null end)';
}

/**
* @internal
*/
getOrderByExpression(column: string, direction: string): string[] {
return [ `${column} ${direction.toLowerCase()}` ];
}

}
2 changes: 1 addition & 1 deletion packages/knex/src/query/QueryBuilderHelper.ts
Original file line number Diff line number Diff line change
Expand Up @@ -638,7 +638,7 @@ export class QueryBuilderHelper {
if (Array.isArray(order)) {
order.forEach(part => ret.push(...this.getQueryOrderFromObject(type, part, populate)));
} else {
ret.push(`${colPart} ${order.toLowerCase()}`);
ret.push(...this.platform.getOrderByExpression(colPart, order));
}
}
}
Expand Down
23 changes: 22 additions & 1 deletion packages/mariadb/src/MariaDbPlatform.ts
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
import { AbstractSqlPlatform } from '@mikro-orm/knex';
import { AbstractSqlPlatform, QueryOrder } from '@mikro-orm/knex';
import { MariaDbSchemaHelper } from './MariaDbSchemaHelper';
import { MariaDbExceptionConverter } from './MariaDbExceptionConverter';
import { Utils, type SimpleColumnMeta, type Dictionary, type Type } from '@mikro-orm/core';
Expand Down Expand Up @@ -74,4 +74,25 @@ export class MariaDbPlatform extends AbstractSqlPlatform {
return `alter table ${quotedTableName} add fulltext index ${quotedIndexName}(${quotedColumnNames.join(',')})`;
}

private readonly ORDER_BY_NULLS_TRANSLATE = {
[QueryOrder.asc_nulls_first]: 'is not null',
[QueryOrder.asc_nulls_last]: 'is null',
[QueryOrder.desc_nulls_first]: 'is not null',
[QueryOrder.desc_nulls_last]: 'is null',
} as const;

/* istanbul ignore next */
override getOrderByExpression(column: string, direction: string): string[] {
const ret: string[] = [];
const dir = direction.toLowerCase() as keyof typeof this.ORDER_BY_NULLS_TRANSLATE;

if (dir in this.ORDER_BY_NULLS_TRANSLATE) {
ret.push(`${column} ${this.ORDER_BY_NULLS_TRANSLATE[dir]}`);
}

ret.push(`${column} ${dir.replace(/(\s|nulls|first|last)*/gi, '')}`);

return ret;
}

}
26 changes: 25 additions & 1 deletion packages/mysql/src/MySqlPlatform.ts
Original file line number Diff line number Diff line change
@@ -1,4 +1,8 @@
import { AbstractSqlPlatform, type IndexDef } from '@mikro-orm/knex';
import {
AbstractSqlPlatform,
type IndexDef,
QueryOrder,
} from '@mikro-orm/knex';
import { MySqlSchemaHelper } from './MySqlSchemaHelper';
import { MySqlExceptionConverter } from './MySqlExceptionConverter';
import { Utils, type SimpleColumnMeta, type Dictionary, type Type, type TransformContext } from '@mikro-orm/core';
Expand Down Expand Up @@ -88,4 +92,24 @@ export class MySqlPlatform extends AbstractSqlPlatform {
return `alter table ${quotedTableName} add fulltext index ${quotedIndexName}(${quotedColumnNames.join(',')})`;
}

private readonly ORDER_BY_NULLS_TRANSLATE = {
[QueryOrder.asc_nulls_first]: 'is not null',
[QueryOrder.asc_nulls_last]: 'is null',
[QueryOrder.desc_nulls_first]: 'is not null',
[QueryOrder.desc_nulls_last]: 'is null',
} as const;

override getOrderByExpression(column: string, direction: string): string[] {
const ret: string[] = [];
const dir = direction.toLowerCase() as keyof typeof this.ORDER_BY_NULLS_TRANSLATE;

if (dir in this.ORDER_BY_NULLS_TRANSLATE) {
ret.push(`${column} ${this.ORDER_BY_NULLS_TRANSLATE[dir]}`);
}

ret.push(`${column} ${dir.replace(/(\s|nulls|first|last)*/gi, '')}`);

return ret;
}

}
4 changes: 2 additions & 2 deletions tests/QueryBuilder.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -2207,13 +2207,13 @@ describe('QueryBuilder', () => {
test('order by asc nulls first', async () => {
const qb = orm.em.createQueryBuilder(Publisher2);
qb.select('*').orderBy({ name: QueryOrder.ASC_NULLS_FIRST });
expect(qb.getQuery()).toEqual('select `e0`.* from `publisher2` as `e0` order by `e0`.`name` asc nulls first');
expect(qb.getQuery()).toEqual('select `e0`.* from `publisher2` as `e0` order by `e0`.`name` is not null, `e0`.`name` asc');
});

test('order by nulls last', async () => {
const qb = orm.em.createQueryBuilder(Publisher2);
qb.select('*').orderBy({ name: QueryOrder.DESC_NULLS_LAST, type: QueryOrder.ASC_NULLS_LAST });
expect(qb.getQuery()).toEqual('select `e0`.* from `publisher2` as `e0` order by `e0`.`name` desc nulls last, `e0`.`type` asc nulls last');
expect(qb.getQuery()).toEqual('select `e0`.* from `publisher2` as `e0` order by `e0`.`name` is null, `e0`.`name` desc, `e0`.`type` is null, `e0`.`type` asc');
});

test('order by custom expression', async () => {
Expand Down

0 comments on commit df75b24

Please sign in to comment.