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

refactor: use common path extraction for mysql/mariadb/sqlite #11329

Merged
merged 2 commits into from Aug 18, 2019
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
28 changes: 17 additions & 11 deletions lib/dialects/abstract/query-generator.js
Expand Up @@ -1068,24 +1068,30 @@ class QueryGenerator {

switch (this.dialect) {
case 'mysql':
case 'mariadb':
case 'sqlite':
/**
* Sub paths need to be quoted as ECMAScript identifiers
* Non digit sub paths need to be quoted as ECMAScript identifiers
* https://bugs.mysql.com/bug.php?id=81896
*/
paths = paths.map(subPath => Utils.addTicks(subPath, '"'));
pathStr = this.escape(['$'].concat(paths).join('.'));
return `(${quotedColumn}->>${pathStr})`;

case 'mariadb':
pathStr = this.escape(['$'].concat(paths).join('.'));
return `json_unquote(json_extract(${quotedColumn},${pathStr}))`;
if (this.dialect === 'mysql') {
paths = paths.map(subPath => {
return /\D/.test(subPath)
? Utils.addTicks(subPath, '"')
: subPath;
});
}

case 'sqlite':
pathStr = this.escape(['$']
.concat(paths)
.join('.')
.replace(/\.(\d+)(?:(?=\.)|$)/g, (_, digit) => `[${digit}]`));
return `json_extract(${quotedColumn}, ${pathStr})`;
.replace(/\.(\d+)(?:(?=\.)|$)/g, (__, digit) => `[${digit}]`));

if (this.dialect === 'sqlite') {
return `json_extract(${quotedColumn},${pathStr})`;
}

return `json_unquote(json_extract(${quotedColumn},${pathStr}))`;

case 'postgres':
pathStr = this.escape(`{${paths.join(',')}}`);
Expand Down
72 changes: 0 additions & 72 deletions lib/dialects/mariadb/query-generator.js
@@ -1,12 +1,8 @@
'use strict';

const _ = require('lodash');
const Utils = require('../../utils');
const MySQLQueryGenerator = require('../mysql/query-generator');
const util = require('util');

class MariaDBQueryGenerator extends MySQLQueryGenerator {

createSchema(schema, options) {
options = Object.assign({
charset: null,
Expand All @@ -31,74 +27,6 @@ class MariaDBQueryGenerator extends MySQLQueryGenerator {
showTablesQuery() {
return 'SELECT TABLE_NAME, TABLE_SCHEMA FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA NOT IN (\'MYSQL\', \'INFORMATION_SCHEMA\', \'PERFORMANCE_SCHEMA\') AND TABLE_TYPE = \'BASE TABLE\'';
}

handleSequelizeMethod(smth, tableName, factory, options, prepend) {
if (smth instanceof Utils.Json) {
// Parse nested object
if (smth.conditions) {
const conditions = this.parseConditionObject(smth.conditions).map(
condition =>
`json_unquote(json_extract(${this.quoteIdentifier(
condition.path[0])},'$.${_.tail(condition.path).join(
'.')}')) = '${condition.value}'`
);

return conditions.join(' and ');
}
if (smth.path) {
let str;

// Allow specifying conditions using the sqlite json functions
if (this._checkValidJsonStatement(smth.path)) {
str = smth.path;
} else {
// Also support json dot notation
let path = smth.path;
let startWithDot = true;

// Convert .number. to [number].
path = path.replace(/\.(\d+)\./g, '[$1].');
// Convert .number$ to [number]
path = path.replace(/\.(\d+)$/, '[$1]');

path = path.split('.');

let columnName = path.shift();
const match = columnName.match(/\[\d+\]$/);
// If columnName ends with [\d+]
if (match !== null) {
path.unshift(columnName.substr(match.index));
columnName = columnName.substr(0, match.index);
startWithDot = false;
}

str = `json_unquote(json_extract(${this.quoteIdentifier(
columnName)},'$${startWithDot ? '.' : ''}${path.join('.')}'))`;
}

if (smth.value) {
str += util.format(' = %s', this.escape(smth.value));
}

return str;
}
} else if (smth instanceof Utils.Cast) {
const lowType = smth.type.toLowerCase();
if (lowType.includes('timestamp')) {
smth.type = 'datetime';
} else if (smth.json && lowType.includes('boolean')) {
// true or false cannot be casted as booleans within a JSON structure
smth.type = 'char';
} else if (lowType.includes('double precision') || lowType.includes('boolean') || lowType.includes('integer')) {
smth.type = 'decimal';
} else if (lowType.includes('text')) {
smth.type = 'char';
}
}

return super.handleSequelizeMethod(smth, tableName, factory, options, prepend);
}

}

module.exports = MariaDBQueryGenerator;
29 changes: 6 additions & 23 deletions lib/dialects/mysql/query-generator.js
Expand Up @@ -209,10 +209,10 @@ class MySQLQueryGenerator extends AbstractQueryGenerator {
// Parse nested object
if (smth.conditions) {
const conditions = this.parseConditionObject(smth.conditions).map(condition =>
`${this.quoteIdentifier(condition.path[0])}->>'$.${_.tail(condition.path).join('.')}' = '${condition.value}'`
`${this.jsonPathExtractionQuery(condition.path[0], _.tail(condition.path))} = '${condition.value}'`
);

return conditions.join(' and ');
return conditions.join(' AND ');
}
if (smth.path) {
let str;
Expand All @@ -221,27 +221,10 @@ class MySQLQueryGenerator extends AbstractQueryGenerator {
if (this._checkValidJsonStatement(smth.path)) {
str = smth.path;
} else {
// Also support json dot notation
let path = smth.path;
let startWithDot = true;

// Convert .number. to [number].
path = path.replace(/\.(\d+)\./g, '[$1].');
// Convert .number$ to [number]
path = path.replace(/\.(\d+)$/, '[$1]');

path = path.split('.');

let columnName = path.shift();
const match = columnName.match(/\[\d+\]$/);
// If columnName ends with [\d+]
if (match !== null) {
path.unshift(columnName.substr(match.index));
columnName = columnName.substr(0, match.index);
startWithDot = false;
}

str = `${this.quoteIdentifier(columnName)}->>'$${startWithDot ? '.' : ''}${path.join('.')}'`;
// Also support json property accessors
const paths = _.toPath(smth.path);
const column = paths.shift();
str = this.jsonPathExtractionQuery(column, paths);
}

if (smth.value) {
Expand Down
31 changes: 3 additions & 28 deletions lib/dialects/sqlite/query-generator.js
@@ -1,7 +1,6 @@
'use strict';

const Utils = require('../../utils');
const util = require('util');
const Transaction = require('../../transaction');
const _ = require('lodash');
const MySqlQueryGenerator = require('../mysql/query-generator');
Expand Down Expand Up @@ -149,34 +148,10 @@ class SQLiteQueryGenerator extends MySqlQueryGenerator {

handleSequelizeMethod(smth, tableName, factory, options, prepend) {
if (smth instanceof Utils.Json) {
// Parse nested object
if (smth.conditions) {
const conditions = this.parseConditionObject(smth.conditions).map(condition =>
`${this.jsonPathExtractionQuery(condition.path[0], _.tail(condition.path))} = '${condition.value}'`
);

return conditions.join(' AND ');
}
if (smth.path) {
let str;

// Allow specifying conditions using the sqlite json functions
if (this._checkValidJsonStatement(smth.path)) {
str = smth.path;
} else {
// Also support json property accessors
const paths = _.toPath(smth.path);
const column = paths.shift();
str = this.jsonPathExtractionQuery(column, paths);
}

if (smth.value) {
str += util.format(' = %s', this.escape(smth.value));
}
return super.handleSequelizeMethod(smth, tableName, factory, options, prepend);
}

return str;
}
} else if (smth instanceof Utils.Cast) {
if (smth instanceof Utils.Cast) {
if (/timestamp/i.test(smth.type)) {
smth.type = 'datetime';
}
Expand Down
8 changes: 8 additions & 0 deletions test/integration/model/json.test.js
Expand Up @@ -697,6 +697,14 @@ describe(Support.getTestDialectTeaser('Model'), () => {
});
});

it('should properly escape path keys with sequelize.json', function() {
return this.Model.findAll({
raw: true,
attributes: ['id'],
where: this.sequelize.json("data.id')) AS DECIMAL) = 1 DELETE YOLO INJECTIONS; -- ", '1')
});
});

it('should properly escape the single quotes in array', function() {
return this.Model.create({
data: {
Expand Down
36 changes: 18 additions & 18 deletions test/unit/sql/json.test.js
Expand Up @@ -82,63 +82,63 @@ if (current.dialect.supports.JSON) {
it('condition object', () => {
expectsql(sql.whereItemQuery(undefined, Sequelize.json({ id: 1 })), {
postgres: '("id"#>>\'{}\') = \'1\'',
sqlite: "json_extract(`id`, '$') = '1'",
mariadb: "json_unquote(json_extract(`id`,'$.')) = '1'",
mysql: "`id`->>'$.' = '1'"
sqlite: "json_extract(`id`,'$') = '1'",
mariadb: "json_unquote(json_extract(`id`,'$')) = '1'",
mysql: "json_unquote(json_extract(`id`,'$')) = '1'"
});
});

it('nested condition object', () => {
expectsql(sql.whereItemQuery(undefined, Sequelize.json({ profile: { id: 1 } })), {
postgres: '("profile"#>>\'{id}\') = \'1\'',
sqlite: "json_extract(`profile`, '$.id') = '1'",
sqlite: "json_extract(`profile`,'$.id') = '1'",
mariadb: "json_unquote(json_extract(`profile`,'$.id')) = '1'",
mysql: "`profile`->>'$.id' = '1'"
mysql: "json_unquote(json_extract(`profile`,'$.\\\"id\\\"')) = '1'"
});
});

it('multiple condition object', () => {
expectsql(sql.whereItemQuery(undefined, Sequelize.json({ property: { value: 1 }, another: { value: 'string' } })), {
postgres: '("property"#>>\'{value}\') = \'1\' AND ("another"#>>\'{value}\') = \'string\'',
sqlite: "json_extract(`property`, '$.value') = '1' AND json_extract(`another`, '$.value') = 'string'",
mariadb: "json_unquote(json_extract(`property`,'$.value')) = '1' and json_unquote(json_extract(`another`,'$.value')) = 'string'",
mysql: "`property`->>'$.value' = '1' and `another`->>'$.value' = 'string'"
sqlite: "json_extract(`property`,'$.value') = '1' AND json_extract(`another`,'$.value') = 'string'",
mariadb: "json_unquote(json_extract(`property`,'$.value')) = '1' AND json_unquote(json_extract(`another`,'$.value')) = 'string'",
mysql: "json_unquote(json_extract(`property`,'$.\\\"value\\\"')) = '1' AND json_unquote(json_extract(`another`,'$.\\\"value\\\"')) = 'string'"
});
});

it('property array object', () => {
expectsql(sql.whereItemQuery(undefined, Sequelize.json({ property: [[4, 6], [8]] })), {
postgres: '("property"#>>\'{0,0}\') = \'4\' AND ("property"#>>\'{0,1}\') = \'6\' AND ("property"#>>\'{1,0}\') = \'8\'',
sqlite: "json_extract(`property`, '$[0][0]') = '4' AND json_extract(`property`, '$[0][1]') = '6' AND json_extract(`property`, '$[1][0]') = '8'",
mariadb: "json_unquote(json_extract(`property`,'$.0.0')) = '4' and json_unquote(json_extract(`property`,'$.0.1')) = '6' and json_unquote(json_extract(`property`,'$.1.0')) = '8'",
mysql: "`property`->>'$.0.0' = '4' and `property`->>'$.0.1' = '6' and `property`->>'$.1.0' = '8'"
sqlite: "json_extract(`property`,'$[0][0]') = '4' AND json_extract(`property`,'$[0][1]') = '6' AND json_extract(`property`,'$[1][0]') = '8'",
mariadb: "json_unquote(json_extract(`property`,'$[0][0]')) = '4' AND json_unquote(json_extract(`property`,'$[0][1]')) = '6' AND json_unquote(json_extract(`property`,'$[1][0]')) = '8'",
mysql: "json_unquote(json_extract(`property`,'$[0][0]')) = '4' AND json_unquote(json_extract(`property`,'$[0][1]')) = '6' AND json_unquote(json_extract(`property`,'$[1][0]')) = '8'"
});
});

it('dot notation', () => {
expectsql(sql.whereItemQuery(Sequelize.json('profile.id'), '1'), {
postgres: '("profile"#>>\'{id}\') = \'1\'',
sqlite: "json_extract(`profile`, '$.id') = '1'",
sqlite: "json_extract(`profile`,'$.id') = '1'",
mariadb: "json_unquote(json_extract(`profile`,'$.id')) = '1'",
mysql: "`profile`->>'$.id' = '1'"
mysql: "json_unquote(json_extract(`profile`,'$.\\\"id\\\"')) = '1'"
});
});

it('item dot notation array', () => {
expectsql(sql.whereItemQuery(Sequelize.json('profile.id.0.1'), '1'), {
postgres: '("profile"#>>\'{id,0,1}\') = \'1\'',
sqlite: "json_extract(`profile`, '$.id[0][1]') = '1'",
sqlite: "json_extract(`profile`,'$.id[0][1]') = '1'",
mariadb: "json_unquote(json_extract(`profile`,'$.id[0][1]')) = '1'",
mysql: "`profile`->>'$.id[0][1]' = '1'"
mysql: "json_unquote(json_extract(`profile`,'$.\\\"id\\\"[0][1]')) = '1'"
});
});

it('column named "json"', () => {
expectsql(sql.whereItemQuery(Sequelize.json('json'), '{}'), {
postgres: '("json"#>>\'{}\') = \'{}\'',
sqlite: "json_extract(`json`, '$') = '{}'",
mariadb: "json_unquote(json_extract(`json`,'$.')) = '{}'",
mysql: "`json`->>'$.' = '{}'"
sqlite: "json_extract(`json`,'$') = '{}'",
mariadb: "json_unquote(json_extract(`json`,'$')) = '{}'",
mysql: "json_unquote(json_extract(`json`,'$')) = '{}'"
});
});
});
Expand Down