mirror of
https://github.com/knex/knex.git
synced 2025-12-30 00:30:14 +00:00
parent
d45a8c8607
commit
126b84639e
@ -5,6 +5,7 @@ const QueryCompiler = require('../../../query/querycompiler');
|
||||
const compact = require('lodash/compact');
|
||||
const identity = require('lodash/identity');
|
||||
const isEmpty = require('lodash/isEmpty');
|
||||
const Raw = require('../../../raw.js');
|
||||
|
||||
const components = [
|
||||
'columns',
|
||||
@ -226,6 +227,21 @@ class QueryCompiler_MSSQL extends QueryCompiler {
|
||||
};
|
||||
}
|
||||
|
||||
_formatGroupsItemValue(value, nulls) {
|
||||
const column = super._formatGroupsItemValue(value);
|
||||
// MSSQL dont support 'is null' syntax in order by,
|
||||
// so we override this function and add MSSQL specific syntax.
|
||||
if (nulls && !(value instanceof Raw)) {
|
||||
const collNulls = `IIF(${column} is null,`;
|
||||
if (nulls === 'first') {
|
||||
return `${collNulls}0,1)`;
|
||||
} else if (nulls === 'last') {
|
||||
return `${collNulls}1,0)`;
|
||||
}
|
||||
}
|
||||
return column;
|
||||
}
|
||||
|
||||
standardUpdate() {
|
||||
const top = this.top();
|
||||
const withSQL = this.with();
|
||||
|
||||
@ -631,7 +631,7 @@ class Builder extends EventEmitter {
|
||||
}
|
||||
|
||||
// Adds a `order by` clause to the query.
|
||||
orderBy(column, direction) {
|
||||
orderBy(column, direction, nulls = '') {
|
||||
if (Array.isArray(column)) {
|
||||
return this._orderByArray(column);
|
||||
}
|
||||
@ -640,6 +640,7 @@ class Builder extends EventEmitter {
|
||||
type: 'orderByBasic',
|
||||
value: column,
|
||||
direction,
|
||||
nulls,
|
||||
});
|
||||
return this;
|
||||
}
|
||||
@ -654,6 +655,7 @@ class Builder extends EventEmitter {
|
||||
type: 'orderByBasic',
|
||||
value: columnInfo['column'],
|
||||
direction: columnInfo['order'],
|
||||
nulls: columnInfo['nulls'],
|
||||
});
|
||||
} else if (isString(columnInfo)) {
|
||||
this._statements.push({
|
||||
|
||||
@ -1226,8 +1226,15 @@ class QueryCompiler {
|
||||
return vals;
|
||||
}
|
||||
|
||||
_formatGroupsItemValue(value) {
|
||||
_formatGroupsItemValue(value, nulls) {
|
||||
const { formatter } = this;
|
||||
let nullOrder = '';
|
||||
if (nulls === 'last') {
|
||||
nullOrder = ' is null';
|
||||
} else if (nulls === 'first') {
|
||||
nullOrder = ' is not null';
|
||||
}
|
||||
|
||||
if (value instanceof Raw) {
|
||||
return unwrapRaw_(
|
||||
value,
|
||||
@ -1236,8 +1243,8 @@ class QueryCompiler {
|
||||
this.client,
|
||||
this.bindingsHolder
|
||||
);
|
||||
} else if (value instanceof QueryBuilder) {
|
||||
return '(' + formatter.columnize(value) + ')';
|
||||
} else if (value instanceof QueryBuilder || nulls) {
|
||||
return '(' + formatter.columnize(value) + nullOrder + ')';
|
||||
} else {
|
||||
return formatter.columnize(value);
|
||||
}
|
||||
@ -1248,7 +1255,7 @@ class QueryCompiler {
|
||||
const items = this.grouped[type];
|
||||
if (!items) return '';
|
||||
const sql = items.map((item) => {
|
||||
const column = this._formatGroupsItemValue(item.value);
|
||||
const column = this._formatGroupsItemValue(item.value, item.nulls);
|
||||
const direction =
|
||||
type === 'order' && item.type !== 'orderByRaw'
|
||||
? ` ${direction_(
|
||||
|
||||
@ -558,6 +558,127 @@ describe('Selects', function () {
|
||||
});
|
||||
});
|
||||
|
||||
it('order by with null', async () => {
|
||||
await knex.schema
|
||||
.dropTableIfExists('OrderByNullTest')
|
||||
.createTable('OrderByNullTest', function (table) {
|
||||
table.increments('id').primary();
|
||||
table.string('null_col').nullable().defaultTo(null);
|
||||
});
|
||||
|
||||
await knex('OrderByNullTest').insert([
|
||||
{
|
||||
null_col: 'test',
|
||||
},
|
||||
{
|
||||
null_col: 'test2',
|
||||
},
|
||||
{
|
||||
null_col: null,
|
||||
},
|
||||
{
|
||||
null_col: null,
|
||||
},
|
||||
]);
|
||||
|
||||
await knex('OrderByNullTest')
|
||||
.pluck('id')
|
||||
.orderBy('null_col', 'asc', 'first')
|
||||
.testSql(function (tester) {
|
||||
tester(
|
||||
'mysql',
|
||||
'select `id` from `OrderByNullTest` order by (`null_col` is not null) asc',
|
||||
[],
|
||||
[3, 4, 1, 2]
|
||||
);
|
||||
tester(
|
||||
'pg',
|
||||
'select "id" from "OrderByNullTest" order by ("null_col" is not null) asc',
|
||||
[],
|
||||
[3, 4, 1, 2]
|
||||
);
|
||||
tester(
|
||||
'pgnative',
|
||||
'select "id" from "OrderByNullTest" order by ("null_col" is not null) asc',
|
||||
[],
|
||||
[3, 4, 1, 2]
|
||||
);
|
||||
tester(
|
||||
'pg-redshift',
|
||||
'select "id" from "OrderByNullTest" order by ("null_col" is not null) asc',
|
||||
[],
|
||||
['3', '4', '1', '2']
|
||||
);
|
||||
tester(
|
||||
'sqlite3',
|
||||
'select `id` from `OrderByNullTest` order by (`null_col` is not null) asc',
|
||||
[],
|
||||
[3, 4, 1, 2]
|
||||
);
|
||||
tester(
|
||||
'oracledb',
|
||||
'select "id" from "OrderByNullTest" order by ("null_col" is not null) asc',
|
||||
[],
|
||||
[3, 4, 1, 2]
|
||||
);
|
||||
tester(
|
||||
'mssql',
|
||||
'select [id] from [OrderByNullTest] order by IIF([null_col] is null,0,1) asc',
|
||||
[],
|
||||
[3, 4, 1, 2]
|
||||
);
|
||||
});
|
||||
|
||||
await knex('OrderByNullTest')
|
||||
.pluck('id')
|
||||
.orderBy('null_col', 'asc', 'last')
|
||||
.testSql(function (tester) {
|
||||
tester(
|
||||
'mysql',
|
||||
'select `id` from `OrderByNullTest` order by (`null_col` is null) asc',
|
||||
[],
|
||||
[1, 2, 3, 4]
|
||||
);
|
||||
tester(
|
||||
'pg',
|
||||
'select "id" from "OrderByNullTest" order by ("null_col" is null) asc',
|
||||
[],
|
||||
[1, 2, 3, 4]
|
||||
);
|
||||
tester(
|
||||
'pgnative',
|
||||
'select "id" from "OrderByNullTest" order by ("null_col" is null) asc',
|
||||
[],
|
||||
[1, 2, 3, 4]
|
||||
);
|
||||
tester(
|
||||
'pg-redshift',
|
||||
'select "id" from "OrderByNullTest" order by ("null_col" is null) asc',
|
||||
[],
|
||||
['1', '2', '3', '4']
|
||||
);
|
||||
tester(
|
||||
'sqlite3',
|
||||
'select `id` from `OrderByNullTest` order by (`null_col` is null) asc',
|
||||
[],
|
||||
[1, 2, 3, 4]
|
||||
);
|
||||
tester(
|
||||
'oracledb',
|
||||
'select "id" from "OrderByNullTest" order by ("null_col" is null) asc',
|
||||
[],
|
||||
[1, 2, 3, 4]
|
||||
);
|
||||
tester(
|
||||
'mssql',
|
||||
'select [id] from [OrderByNullTest] order by IIF([null_col] is null,1,0) asc',
|
||||
[],
|
||||
[1, 2, 3, 4]
|
||||
);
|
||||
});
|
||||
await knex.schema.dropTable('OrderByNullTest');
|
||||
});
|
||||
|
||||
describe('simple "where" cases', function () {
|
||||
it('allows key, value', function () {
|
||||
return knex('accounts')
|
||||
|
||||
@ -5625,6 +5625,84 @@ describe('QueryBuilder', () => {
|
||||
);
|
||||
});
|
||||
|
||||
it('order by, null first', () => {
|
||||
testsql(qb().from('users').orderBy('foo', 'desc', 'first'), {
|
||||
mysql: {
|
||||
sql: 'select * from `users` order by (`foo` is not null) desc',
|
||||
},
|
||||
mssql: {
|
||||
sql: 'select * from [users] order by IIF([foo] is null,0,1) desc',
|
||||
},
|
||||
pg: {
|
||||
sql: 'select * from "users" order by ("foo" is not null) desc',
|
||||
},
|
||||
'pg-redshift': {
|
||||
sql: 'select * from "users" order by ("foo" is not null) desc',
|
||||
},
|
||||
});
|
||||
});
|
||||
|
||||
it('order by, null first, array notation', () => {
|
||||
testsql(
|
||||
qb()
|
||||
.from('users')
|
||||
.orderBy([{ column: 'foo', order: 'desc', nulls: 'first' }]),
|
||||
{
|
||||
mysql: {
|
||||
sql: 'select * from `users` order by (`foo` is not null) desc',
|
||||
},
|
||||
mssql: {
|
||||
sql: 'select * from [users] order by IIF([foo] is null,0,1) desc',
|
||||
},
|
||||
pg: {
|
||||
sql: 'select * from "users" order by ("foo" is not null) desc',
|
||||
},
|
||||
'pg-redshift': {
|
||||
sql: 'select * from "users" order by ("foo" is not null) desc',
|
||||
},
|
||||
}
|
||||
);
|
||||
});
|
||||
|
||||
it('order by, null last', () => {
|
||||
testsql(qb().from('users').orderBy('foo', 'desc', 'last'), {
|
||||
mysql: {
|
||||
sql: 'select * from `users` order by (`foo` is null) desc',
|
||||
},
|
||||
mssql: {
|
||||
sql: 'select * from [users] order by IIF([foo] is null,1,0) desc',
|
||||
},
|
||||
pg: {
|
||||
sql: 'select * from "users" order by ("foo" is null) desc',
|
||||
},
|
||||
'pg-redshift': {
|
||||
sql: 'select * from "users" order by ("foo" is null) desc',
|
||||
},
|
||||
});
|
||||
});
|
||||
|
||||
it('order by, null last, array notation', () => {
|
||||
testsql(
|
||||
qb()
|
||||
.from('users')
|
||||
.orderBy([{ column: 'foo', order: 'desc', nulls: 'last' }]),
|
||||
{
|
||||
mysql: {
|
||||
sql: 'select * from `users` order by (`foo` is null) desc',
|
||||
},
|
||||
mssql: {
|
||||
sql: 'select * from [users] order by IIF([foo] is null,1,0) desc',
|
||||
},
|
||||
pg: {
|
||||
sql: 'select * from "users" order by ("foo" is null) desc',
|
||||
},
|
||||
'pg-redshift': {
|
||||
sql: 'select * from "users" order by ("foo" is null) desc',
|
||||
},
|
||||
}
|
||||
);
|
||||
});
|
||||
|
||||
it('update method with joins mysql', () => {
|
||||
testsql(
|
||||
qb()
|
||||
|
||||
13
types/index.d.ts
vendored
13
types/index.d.ts
vendored
@ -1483,7 +1483,10 @@ export declare namespace Knex {
|
||||
TAlias extends string,
|
||||
TKey extends keyof ResolveTableType<TRecord>,
|
||||
TResult2 = AggregationQueryResult<TResult, {[x in TAlias]: number}>
|
||||
>(alias: TAlias, orderBy: TKey | TKey[] | { columnName: TKey, order?: 'asc' | 'desc' }, partitionBy?: TKey | TKey[] | { columnName: TKey, order?: 'asc' | 'desc' }): QueryBuilder<
|
||||
>(alias: TAlias,
|
||||
orderBy: TKey | TKey[] | { columnName: TKey, order?: 'asc' | 'desc', nulls?: 'first' | 'last' },
|
||||
partitionBy?: TKey | TKey[] | { columnName: TKey, order?: 'asc' | 'desc' }):
|
||||
QueryBuilder<
|
||||
TRecord,
|
||||
TResult2
|
||||
>;
|
||||
@ -1494,16 +1497,17 @@ export declare namespace Knex {
|
||||
ColumnNameQueryBuilder<TRecord, TResult> {}
|
||||
|
||||
interface OrderBy<TRecord = any, TResult = unknown[]> {
|
||||
(columnName: keyof TRecord | QueryBuilder, order?: 'asc' | 'desc'): QueryBuilder<
|
||||
(columnName: keyof TRecord | QueryBuilder, order?: 'asc' | 'desc', nulls?: 'first' | 'last'): QueryBuilder<
|
||||
TRecord,
|
||||
TResult
|
||||
>;
|
||||
(columnName: string | QueryBuilder, order?: string): QueryBuilder<TRecord, TResult>;
|
||||
(columnName: string | QueryBuilder, order?: string, nulls?: string): QueryBuilder<TRecord, TResult>;
|
||||
(
|
||||
columnDefs: Array<
|
||||
keyof TRecord | Readonly<{
|
||||
column: keyof TRecord | QueryBuilder;
|
||||
order?: 'asc' | 'desc'
|
||||
order?: 'asc' | 'desc',
|
||||
nulls?: 'first' | 'last'
|
||||
}>
|
||||
>
|
||||
): QueryBuilder<TRecord, TResult>;
|
||||
@ -1511,6 +1515,7 @@ export declare namespace Knex {
|
||||
columnDefs: Array<string | Readonly<{
|
||||
column: string | QueryBuilder;
|
||||
order?: string;
|
||||
nulls?: string;
|
||||
}>>
|
||||
): QueryBuilder<TRecord, TResult>;
|
||||
}
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user