Skip to content

Commit

Permalink
Fix: orWhereJson (#5361)
Browse files Browse the repository at this point in the history
  • Loading branch information
SuhyeongCho committed Nov 18, 2022
1 parent 4fc939a commit 72bd1f7
Show file tree
Hide file tree
Showing 3 changed files with 121 additions and 66 deletions.
29 changes: 11 additions & 18 deletions lib/query/querybuilder.js
Expand Up @@ -1501,17 +1501,16 @@ class Builder extends EventEmitter {
return this;
}

orWhereJsonObject(column, operator, value) {
return this._bool('or').whereJsonObject(column, operator, value);
orWhereJsonObject(column, value) {
return this._bool('or').whereJsonObject(column, value);
}

whereNotJsonObject(column, value) {
this._not(true)._whereJsonWrappedValue('whereJsonObject', column, value);
return this;
return this._not(true).whereJsonObject(column, value);
}

orWhereNotJsonObject(column, operator, value) {
return this._not(true)._bool('or').whereJsonObject(column, operator, value);
orWhereNotJsonObject(column, value) {
return this._bool('or').whereNotJsonObject(column, value);
}

whereJsonPath(column, path, operator, value) {
Expand All @@ -1530,18 +1529,15 @@ class Builder extends EventEmitter {
}

whereJsonNotSupersetOf(column, value) {
this._not(true).whereJsonSupersetOf(column, value);
return this;
return this._not(true).whereJsonSupersetOf(column, value);
}

orWhereJsonSupersetOf(column, value) {
this._whereJsonWrappedValue('whereJsonSupersetOf', column, value);
return this;
return this._bool('or').whereJsonSupersetOf(column, value);
}

orWhereJsonNotSupersetOf(column, value) {
this._not(true)._bool('or').whereJsonSupersetOf(column, value);
return this;
return this._bool('or').whereJsonNotSupersetOf(column, value);
}

// Json subset wheres
Expand All @@ -1551,18 +1547,15 @@ class Builder extends EventEmitter {
}

whereJsonNotSubsetOf(column, value) {
this._not(true).whereJsonSubsetOf(column, value);
return this;
return this._not(true).whereJsonSubsetOf(column, value);
}

orWhereJsonSubsetOf(column, value) {
this._whereJsonWrappedValue('whereJsonSubsetOf', column, value);
return this;
return this._bool('or').whereJsonSubsetOf(column, value);
}

orWhereJsonNotSubsetOf(column, value) {
this._not(true)._bool('or').whereJsonSubsetOf(column, value);
return this;
return this._bool('or').whereJsonNotSubsetOf(column, value);
}

whereJsonHasNone(column, values) {
Expand Down
53 changes: 53 additions & 0 deletions test/integration2/query/select/where.spec.js
Expand Up @@ -794,6 +794,33 @@ describe('Where', function () {
]);
});

it('or where json superset of', async function () {
if (!(isPostgreSQL(knex) || isMysql(knex))) {
this.skip();
}
const result = await knex('cities')
.select('name')
// where descriptions json object contains type : 'bigcity' or 'city'
.whereJsonSupersetOf('descriptions', {
type: 'bigcity',
})
.orWhereJsonSupersetOf('descriptions', {
type: 'city',
});
expect(result.length).to.equal(3);
assertJsonEquals(result, [
{
name: 'Paris',
},
{
name: 'Milan',
},
{
name: 'Oslo',
},
]);
});

it('where json superset of with string', async function () {
if (!(isPostgreSQL(knex) || isMysql(knex))) {
this.skip();
Expand Down Expand Up @@ -830,6 +857,32 @@ describe('Where', function () {
},
]);
});

it('or where json subset of', async function () {
if (!(isPostgreSQL(knex) || isMysql(knex))) {
this.skip();
}
const result = await knex('cities')
.select('name')
// where temperature json object is included in given object
.whereJsonSubsetOf('temperature', {
desc: 'cold',
desc2: 'very cold',
})
.orWhereJsonSubsetOf('temperature', {
desc: 'warm',
desc2: 'very warm',
});
expect(result.length).to.equal(2);
assertJsonEquals(result, [
{
name: 'Paris',
},
{
name: 'Milan',
},
]);
});
});
});
});
Expand Down
105 changes: 57 additions & 48 deletions test/unit/query/builder.js
Expand Up @@ -11023,31 +11023,32 @@ describe('QueryBuilder', () => {
qb()
.select()
.from('users')
.whereJsonPath('address', '$.street.number', '>', 5),
.whereJsonPath('address', '$.street.number', '>', 5)
.orWhereJsonPath('address', '$.street.number', '<', 8),
{
pg: {
sql: 'select * from "users" where jsonb_path_query_first("address", ?)::int > ?',
bindings: ['$.street.number', 5],
sql: 'select * from "users" where jsonb_path_query_first("address", ?)::int > ? or jsonb_path_query_first("address", ?)::int < ?',
bindings: ['$.street.number', 5, '$.street.number', 8],
},
mysql: {
sql: 'select * from `users` where json_extract(`address`, ?) > ?',
bindings: ['$.street.number', 5],
sql: 'select * from `users` where json_extract(`address`, ?) > ? or json_extract(`address`, ?) < ?',
bindings: ['$.street.number', 5, '$.street.number', 8],
},
mssql: {
sql: 'select * from [users] where JSON_VALUE([address], ?) > ?',
bindings: ['$.street.number', 5],
sql: 'select * from [users] where JSON_VALUE([address], ?) > ? or JSON_VALUE([address], ?) < ?',
bindings: ['$.street.number', 5, '$.street.number', 8],
},
oracledb: {
sql: 'select * from "users" where json_value("address", \'$.street.number\') > ?',
bindings: [5],
sql: 'select * from "users" where json_value("address", \'$.street.number\') > ? or json_value("address", \'$.street.number\') < ?',
bindings: [5, 8],
},
sqlite3: {
sql: 'select * from `users` where json_extract(`address`, ?) > ?',
bindings: ['$.street.number', 5],
sql: 'select * from `users` where json_extract(`address`, ?) > ? or json_extract(`address`, ?) < ?',
bindings: ['$.street.number', 5, '$.street.number', 8],
},
cockroachdb: {
sql: 'select * from "users" where json_extract_path("address", ?, ?)::int > ?',
bindings: ['street', 'number', 5],
sql: 'select * from "users" where json_extract_path("address", ?, ?)::int > ? or json_extract_path("address", ?, ?)::int < ?',
bindings: ['street', 'number', 5, 'street', 'number', 8],
},
}
);
Expand All @@ -11058,39 +11059,44 @@ describe('QueryBuilder', () => {
qb()
.select()
.from('users')
.whereJsonSupersetOf('address', { test: 'value' }),
.whereJsonSupersetOf('address', { test: 'value' })
.orWhereJsonSupersetOf('address', { test: 'value2' }),
{
pg: {
sql: 'select * from "users" where "address" @> ?',
bindings: ['{"test":"value"}'],
sql: 'select * from "users" where "address" @> ? or "address" @> ?',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
mysql: {
sql: 'select * from `users` where json_contains(`address`,?)',
bindings: ['{"test":"value"}'],
sql: 'select * from `users` where json_contains(`address`,?) or json_contains(`address`,?)',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
cockroachdb: {
sql: 'select * from "users" where "address" @> ?',
bindings: ['{"test":"value"}'],
sql: 'select * from "users" where "address" @> ? or "address" @> ?',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
}
);
});

it('where a json column is a superset of value', async function () {
testsql(
qb().select().from('users').whereJsonSupersetOf('address', 'test'),
qb()
.select()
.from('users')
.whereJsonSupersetOf('address', 'test')
.orWhereJsonSupersetOf('address', 'test2'),
{
pg: {
sql: 'select * from "users" where "address" @> ?',
bindings: ['test'],
sql: 'select * from "users" where "address" @> ? or "address" @> ?',
bindings: ['test', 'test2'],
},
mysql: {
sql: 'select * from `users` where json_contains(`address`,?)',
bindings: ['test'],
sql: 'select * from `users` where json_contains(`address`,?) or json_contains(`address`,?)',
bindings: ['test', 'test2'],
},
cockroachdb: {
sql: 'select * from "users" where "address" @> ?',
bindings: ['test'],
sql: 'select * from "users" where "address" @> ? or "address" @> ?',
bindings: ['test', 'test2'],
},
}
);
Expand All @@ -11101,19 +11107,20 @@ describe('QueryBuilder', () => {
qb()
.select()
.from('users')
.whereJsonNotSupersetOf('address', { test: 'value' }),
.whereJsonNotSupersetOf('address', { test: 'value' })
.orWhereJsonNotSupersetOf('address', { test: 'value2' }),
{
pg: {
sql: 'select * from "users" where not "address" @> ?',
bindings: ['{"test":"value"}'],
sql: 'select * from "users" where not "address" @> ? or not "address" @> ?',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
mysql: {
sql: 'select * from `users` where not json_contains(`address`,?)',
bindings: ['{"test":"value"}'],
sql: 'select * from `users` where not json_contains(`address`,?) or not json_contains(`address`,?)',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
cockroachdb: {
sql: 'select * from "users" where not "address" @> ?',
bindings: ['{"test":"value"}'],
sql: 'select * from "users" where not "address" @> ? or not "address" @> ?',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
}
);
Expand All @@ -11124,19 +11131,20 @@ describe('QueryBuilder', () => {
qb()
.select()
.from('users')
.whereJsonSubsetOf('address', { test: 'value' }),
.whereJsonSubsetOf('address', { test: 'value' })
.orWhereJsonSubsetOf('address', { test: 'value2' }),
{
pg: {
sql: 'select * from "users" where "address" <@ ?',
bindings: ['{"test":"value"}'],
sql: 'select * from "users" where "address" <@ ? or "address" <@ ?',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
mysql: {
sql: 'select * from `users` where json_contains(?,`address`)',
bindings: ['{"test":"value"}'],
sql: 'select * from `users` where json_contains(?,`address`) or json_contains(?,`address`)',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
cockroachdb: {
sql: 'select * from "users" where "address" <@ ?',
bindings: ['{"test":"value"}'],
sql: 'select * from "users" where "address" <@ ? or "address" <@ ?',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
}
);
Expand All @@ -11147,19 +11155,20 @@ describe('QueryBuilder', () => {
qb()
.select()
.from('users')
.whereJsonNotSubsetOf('address', { test: 'value' }),
.whereJsonNotSubsetOf('address', { test: 'value' })
.orWhereJsonNotSubsetOf('address', { test: 'value2' }),
{
pg: {
sql: 'select * from "users" where not "address" <@ ?',
bindings: ['{"test":"value"}'],
sql: 'select * from "users" where not "address" <@ ? or not "address" <@ ?',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
mysql: {
sql: 'select * from `users` where not json_contains(?,`address`)',
bindings: ['{"test":"value"}'],
sql: 'select * from `users` where not json_contains(?,`address`) or not json_contains(?,`address`)',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
cockroachdb: {
sql: 'select * from "users" where not "address" <@ ?',
bindings: ['{"test":"value"}'],
sql: 'select * from "users" where not "address" <@ ? or not "address" <@ ?',
bindings: ['{"test":"value"}', '{"test":"value2"}'],
},
}
);
Expand Down

0 comments on commit 72bd1f7

Please sign in to comment.