Support multi-column whereIn with query (#1390)

* Support multi-column `whereIn` with query

Add support for supplying a subquery for a `whereIn` statment on multiple columns.

Fixes #1384.

* Fixed method

* Removed duplicate import

* Fixed isArray calls and linter warnings

* Fixed isArray call

* Fixed tests and added assertions for all dialects
This commit is contained in:
Rhys van der Waerden 2018-02-22 07:51:09 +11:00 committed by Mikael Lepistö
parent 397104c3dc
commit 965542d3ef
4 changed files with 86 additions and 17 deletions

View File

@ -1,7 +1,6 @@
import QueryBuilder from './query/builder';
import Raw from './raw';
import { transform } from 'lodash'
import {transform} from 'lodash'
// Valid values for the `order by` clause generation.
const orderBys = ['asc', 'desc'];
@ -57,6 +56,29 @@ export default class Formatter {
return str;
}
// Formats `values` into a parenthesized list of parameters for a `VALUES`
// clause.
//
// [1, 2] -> '(?, ?)'
// [[1, 2], [3, 4]] -> '((?, ?), (?, ?))'
// knex('table') -> '(select * from "table")'
// knex.raw('select ?', 1) -> '(select ?)'
//
values(values) {
if (Array.isArray(values)) {
if (Array.isArray(values[0])) {
return `(${values.map(value => `(${this.parameterize(value)})`).join(', ')})`;
}
return `(${this.parameterize(values)})`;
}
if (values instanceof Raw) {
return `(${this.parameter(values)})`;
}
return this.parameter(values);
}
// Checks whether a value is a function... if it is, we compile it
// otherwise we check whether it's a raw
parameter(value) {

View File

@ -10,7 +10,6 @@ import {
assign, bind, compact, groupBy, isEmpty, isString, isUndefined, map, omitBy,
reduce
} from 'lodash';
import uuid from 'uuid';
const debugBindings = debug('knex:bindings')
@ -486,19 +485,15 @@ assign(QueryCompiler.prototype, {
// ------
whereIn(statement) {
if (Array.isArray(statement.column)) return this.multiWhereIn(statement);
return this.formatter.wrap(statement.column) + ' ' + this._not(statement, 'in ') +
this.wrap(this.formatter.parameterize(statement.value));
},
multiWhereIn(statement) {
let i = -1, sql = `(${this.formatter.columnize(statement.column)}) `
sql += this._not(statement, 'in ') + '(('
while (++i < statement.value.length) {
if (i !== 0) sql += '),('
sql += this.formatter.parameterize(statement.value[i])
let columns = null;
if (Array.isArray(statement.column)) {
columns = `(${this.formatter.columnize(statement.column)})`
} else {
columns = this.formatter.wrap(statement.column);
}
return sql + '))'
const values = this.formatter.values(statement.value);
return `${columns} ${this._not(statement, 'in ')}${values}`;
},
whereNull(statement) {

View File

@ -726,7 +726,7 @@ module.exports = function(knex) {
.select()
.testSql(function(tester) {
tester('mysql',
'select * from `composite_key_test` where (`column_a`, `column_b`) in ((?, ?),(?, ?)) order by `status` desc',
'select * from `composite_key_test` where (`column_a`, `column_b`) in ((?, ?), (?, ?)) order by `status` desc',
[1,1,1,2],
[{
column_a: 1,
@ -796,7 +796,7 @@ module.exports = function(knex) {
.select()
.testSql(function(tester) {
tester('mysql',
'select * from `composite_key_test` where `status` = ? and (`column_a`, `column_b`) in ((?, ?),(?, ?))',
'select * from `composite_key_test` where `status` = ? and (`column_a`, `column_b`) in ((?, ?), (?, ?))',
[1,1,1,1,2],
[{
column_a: 1,

View File

@ -838,6 +838,31 @@ describe("QueryBuilder", function() {
});
});
it("multi column where ins", function() {
testsql(qb().select('*').from('users').whereIn(['a', 'b'], [[1, 2], [3, 4], [5, 6]]), {
mysql: {
sql: 'select * from `users` where (`a`, `b`) in ((?, ?), (?, ?), (?, ?))',
bindings: [1, 2, 3, 4, 5, 6]
},
postgres: {
sql: 'select * from "users" where ("a", "b") in ((?, ?), (?, ?), (?, ?))',
bindings: [1, 2, 3, 4, 5, 6]
},
redshift: {
sql: 'select * from "users" where ("a", "b") in ((?, ?), (?, ?), (?, ?))',
bindings: [1, 2, 3, 4, 5, 6]
},
mssql: {
sql: 'select * from [users] where ([a], [b]) in ((?, ?), (?, ?), (?, ?))',
bindings: [1, 2, 3, 4, 5, 6]
},
oracle: {
sql: 'select * from "users" where ("a", "b") in ((?, ?), (?, ?), (?, ?))',
bindings: [1, 2, 3, 4, 5, 6]
},
});
});
it("orWhereIn", function() {
testsql(qb().select('*').from('users').where('id', '=', 1).orWhereIn('id', [1, 2, 3]), {
mysql: {
@ -1390,6 +1415,33 @@ describe("QueryBuilder", function() {
});
});
it("sub select multi column where ins", function() {
testsql(qb().select('*').from('users').whereIn(['id_a', 'id_b'], function(qb) {
qb.select('id_a', 'id_b').from('users').where('age', '>', 25).limit(3);
}), {
mysql: {
sql: 'select * from `users` where (`id_a`, `id_b`) in (select `id_a`, `id_b` from `users` where `age` > ? limit ?)',
bindings: [25, 3]
},
oracle: {
sql: 'select * from "users" where ("id_a", "id_b") in (select * from (select "id_a", "id_b" from "users" where "age" > ?) where rownum <= ?)',
bindings: [25, 3]
},
postgres: {
sql: 'select * from "users" where ("id_a", "id_b") in (select "id_a", "id_b" from "users" where "age" > ? limit ?)',
bindings: [25, 3]
},
redshift: {
sql: 'select * from "users" where ("id_a", "id_b") in (select "id_a", "id_b" from "users" where "age" > ? limit ?)',
bindings: [25, 3]
},
mssql: {
sql: 'select * from [users] where ([id_a], [id_b]) in (select top (?) [id_a], [id_b] from [users] where [age] > ?)',
bindings: [3, 25]
},
});
});
it("sub select where not ins", function() {
testsql(qb().select('*').from('users').whereNotIn('id', function(qb) {
qb.select('id').from('users').where('age', '>', 25);