Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

fix(abstract): patch jsonb operator for pg if value is json #13780

Merged
merged 11 commits into from Dec 22, 2021
24 changes: 18 additions & 6 deletions lib/dialects/abstract/query-generator.js
Expand Up @@ -1095,12 +1095,13 @@ class QueryGenerator {
/**
* Generates an SQL query that extract JSON property of given path.
*
* @param {string} column The JSON column
* @param {string|Array<string>} [path] The path to extract (optional)
* @returns {string} The generated sql query
* @param {string} column The JSON column
* @param {string|Array<string>} [path] The path to extract (optional)
* @param {boolean} [isJson] The value is JSON use alt symbols (optional)
* @returns {string} The generated sql query
* @private
*/
jsonPathExtractionQuery(column, path) {
jsonPathExtractionQuery(column, path, isJson) {
sdepold marked this conversation as resolved.
Show resolved Hide resolved
let paths = _.toPath(path);
let pathStr;
const quotedColumn = this.isIdentifierQuoted(column)
Expand Down Expand Up @@ -1135,8 +1136,9 @@ class QueryGenerator {
return `json_unquote(json_extract(${quotedColumn},${pathStr}))`;

case 'postgres':
const join = isJson ? '#>' : '#>>';
sdepold marked this conversation as resolved.
Show resolved Hide resolved
pathStr = this.escape(`{${paths.join(',')}}`);
return `(${quotedColumn}#>>${pathStr})`;
return `(${quotedColumn}${join}${pathStr})`;

default:
throw new Error(`Unsupported ${this.dialect} for JSON operations`);
Expand Down Expand Up @@ -2484,11 +2486,21 @@ class QueryGenerator {
path[path.length - 1] = tmp[0];
}

const pathKey = this.jsonPathExtractionQuery(baseKey, path);
let pathKey = this.jsonPathExtractionQuery(baseKey, path);

if (_.isPlainObject(item)) {
Utils.getOperators(item).forEach(op => {
const value = this._toJSONValue(item[op]);
let isJson = false;
if (typeof value === 'string' && op === Op.contains) {
try {
JSON.stringify(value);
isJson = true;
} catch (e) {
// failed to parse, is not json so isJson remains false
}
}
pathKey = this.jsonPathExtractionQuery(baseKey, path, isJson);
items.push(this.whereItemQuery(this._castKey(pathKey, value, cast), { [op]: value }));
});
_.forOwn(item, (value, itemProp) => {
Expand Down
54 changes: 52 additions & 2 deletions test/unit/dialects/abstract/query-generator.test.js
Expand Up @@ -2,8 +2,9 @@

const chai = require('chai'),
expect = chai.expect,
Op = require('sequelize/lib/operators'),
getAbstractQueryGenerator = require('../../support').getAbstractQueryGenerator;
Op = require('../../../../lib/operators'),
Support = require('../../support'),
getAbstractQueryGenerator = Support.getAbstractQueryGenerator;
const AbstractQueryGenerator = require('sequelize/lib/dialects/abstract/query-generator');

describe('QueryGenerator', () => {
Expand Down Expand Up @@ -134,6 +135,55 @@ describe('QueryGenerator', () => {
});
});

describe('jsonPathExtractionQuery', () => {
const expectQueryGenerator = (query, assertions) => {
const expectation = assertions[Support.sequelize.dialect.name];
if (!expectation) {
throw new Error(`Undefined expectation for "${Support.sequelize.dialect.name}"!`);
}
return expectation(query);
};

it('Should handle isJson parameter true', function() {
const QG = getAbstractQueryGenerator(this.sequelize);
expectQueryGenerator(() => QG.jsonPathExtractionQuery('profile', 'id', true), {
postgres: query => expect(query()).to.equal('(profile#>\'{id}\')'),
sqlite: query => expect(query()).to.equal('json_extract(profile,\'$.id\')'),
mariadb: query => expect(query()).to.equal('json_unquote(json_extract(profile,\'$.id\'))'),
mysql: query => expect(query()).to.equal("json_unquote(json_extract(profile,'$.\\\"id\\\"'))"),
mssql: query => expect(query).to.throw(Error),
snowflake: query => expect(query).to.throw(Error),
db2: query => expect(query).to.throw(Error)
});
});

it('Should use default handling if isJson is false', function() {
const QG = getAbstractQueryGenerator(this.sequelize);
expectQueryGenerator(() => QG.jsonPathExtractionQuery('profile', 'id', false), {
postgres: query => expect(query()).to.equal('(profile#>>\'{id}\')'),
sqlite: query => expect(query()).to.equal('json_extract(profile,\'$.id\')'),
mariadb: query => expect(query()).to.equal('json_unquote(json_extract(profile,\'$.id\'))'),
mysql: query => expect(query()).to.equal("json_unquote(json_extract(profile,'$.\\\"id\\\"'))"),
mssql: query => expect(query).to.throw(Error),
snowflake: query => expect(query).to.throw(Error),
db2: query => expect(query).to.throw(Error)
});
});

it('Should use default handling if isJson is not passed', function() {
const QG = getAbstractQueryGenerator(this.sequelize);
expectQueryGenerator(() => QG.jsonPathExtractionQuery('profile', 'id'), {
postgres: query => expect(query()).to.equal('(profile#>>\'{id}\')'),
sqlite: query => expect(query()).to.equal('json_extract(profile,\'$.id\')'),
mariadb: query => expect(query()).to.equal('json_unquote(json_extract(profile,\'$.id\'))'),
mysql: query => expect(query()).to.equal("json_unquote(json_extract(profile,'$.\\\"id\\\"'))"),
mssql: query => expect(query).to.throw(Error),
snowflake: query => expect(query).to.throw(Error),
db2: query => expect(query).to.throw(Error)
});
});
});

describe('queryIdentifier', () => {
it('should throw an error if call base quoteIdentifier', function() {
const QG = new AbstractQueryGenerator({ sequelize: this.sequelize, _dialect: this.sequelize.dialect });
Expand Down