不要怂,就是干,撸起袖子干!

Commit 75841f3e by Youngrok Kim Committed by Sushant

SQLite JSON datatype support (with JSON1 extension) (#7094)

* Adds JSON support for sqlite

* Add JSON support to sqlite query-generator

* add integration test for sqlite json

* add unit test for sqlite json

* fix inaccurate test for json from postgres

* Fix failing test spec in postgres

* Change accroding to review

- Change MySqlQueryGenerator to AbstractQueryGenerator (sqlite)
- Move parseConditionObject method to the AbstractQueryGenerator (sqlite, postgres)
- Remove unnecessary module require
- Remove extra lines

* Fix failing test with sequelize static reference

* Add JSONB type alias to sqlite data types

* Update changelog.md

* Update jsdoc for JSON datatype

* Updates from PR feedback

- Convert es5 syntax to es6 for sqlite query-generator

* Fix parenthesis with single parameter

* Fix deleteQuery condition with JSON field

* Update integration/data-types.test.js

* Add JSON injection preventation code for sqlite

- Add checkValidJsonStatement method to sqlite query-generator
- Add injection tests for sqlite

* Update sqlite JSON query-generator

* Move common json DAO tests to abstract/dao.test.js

- Add support for json property accessors (sqlite, postgres)

* Fix wrong indentation in abstract/query-generator.js

* Update query-generator.js to use common json method

* Fix inconsistent postgres cast syntax

* Update JSON test specs

- Add injection test for postgres/query-generators.js
- Replace default sql test expectation with specific dialect (postgres)
- Update expectsql from test/support.js to throw error when no default expectation

* Fix failing postgres test with cast

* Fix postgres casting syntax

* Fix failing test for postgres

* Revert indentation of postgres query-generator

* Cleanup unnecessarily added code

update jsdoc of jsonPathExtractionQuery to match the exact function arguments

* Move integration/dialects/abstract/dao.test.js to integration/json.test.js

* Rewrite unit tests for json query-generator in unit/sql/json.test.js

* Capitalize AND operator while generating json query via condition object

* Fix failed tests
1 parent 0b215062
...@@ -7,6 +7,7 @@ ...@@ -7,6 +7,7 @@
- [FIXED] MSSQL tedious debug regression fix when dialectOptions are not passed [#7130](https://github.com/sequelize/sequelize/pull/7130) - [FIXED] MSSQL tedious debug regression fix when dialectOptions are not passed [#7130](https://github.com/sequelize/sequelize/pull/7130)
- [CHANGED] `setIsolationLevelQuery` to skip under MSSQL dialect, added debug listener for tedious [#7130](https://github.com/sequelize/sequelize/pull/7130) - [CHANGED] `setIsolationLevelQuery` to skip under MSSQL dialect, added debug listener for tedious [#7130](https://github.com/sequelize/sequelize/pull/7130)
- [FIXED] `sourceKey` FOR `hasMany` now also works if a `where` was specified in an `include` [#7141](https://github.com/sequelize/sequelize/issues/7141) - [FIXED] `sourceKey` FOR `hasMany` now also works if a `where` was specified in an `include` [#7141](https://github.com/sequelize/sequelize/issues/7141)
- [ADDED] SQLite JSON datatype support [#7094](https://github.com/sequelize/sequelize/pull/7094)
- [FIXED] `removeColumn` method to support dropping primaryKey column (MSSQL) [#7081](https://github.com/sequelize/sequelize/pull/7081) - [FIXED] `removeColumn` method to support dropping primaryKey column (MSSQL) [#7081](https://github.com/sequelize/sequelize/pull/7081)
- [ADDED] Filtered Indexes support for SQL Server [#7016](https://github.com/sequelize/sequelize/issues/7016) - [ADDED] Filtered Indexes support for SQL Server [#7016](https://github.com/sequelize/sequelize/issues/7016)
- [FIXED] Set `timestamps` and `paranoid` options from through model on `belongsToMany` association - [FIXED] Set `timestamps` and `paranoid` options from through model on `belongsToMany` association
......
...@@ -502,7 +502,7 @@ HSTORE.prototype.validate = function validate(value) { ...@@ -502,7 +502,7 @@ HSTORE.prototype.validate = function validate(value) {
}; };
/** /**
* A JSON string column. Only available in postgres. * A JSON string column. Only available in postgres and sqlite.
* *
* @function JSON * @function JSON
* @memberof DataTypes * @memberof DataTypes
......
...@@ -1749,6 +1749,7 @@ const QueryGenerator = { ...@@ -1749,6 +1749,7 @@ const QueryGenerator = {
} }
return ''; return '';
}, },
whereItemsQuery(where, options, binding) { whereItemsQuery(where, options, binding) {
if ( if (
(Array.isArray(where) && where.length === 0) || (Array.isArray(where) && where.length === 0) ||
...@@ -1779,6 +1780,7 @@ const QueryGenerator = { ...@@ -1779,6 +1780,7 @@ const QueryGenerator = {
return items.length && items.filter(item => item && item.length).join(binding) || ''; return items.length && items.filter(item => item && item.length).join(binding) || '';
}, },
whereItemQuery(key, value, options) { whereItemQuery(key, value, options) {
options = options || {}; options = options || {};
...@@ -1947,17 +1949,17 @@ const QueryGenerator = { ...@@ -1947,17 +1949,17 @@ const QueryGenerator = {
path[path.length - 1] = tmp[0]; path[path.length - 1] = tmp[0];
} }
let baseKey = this.quoteIdentifier(key)+'#>>\'{'+path.join(', ')+'}\''; let baseKey = this.quoteIdentifier(key);
if (options.prefix) { if (options.prefix) {
if (options.prefix instanceof Utils.Literal) { if (options.prefix instanceof Utils.Literal) {
baseKey = this.handleSequelizeMethod(options.prefix)+'.'+baseKey; baseKey = `${this.handleSequelizeMethod(options.prefix)}.${baseKey}`;
} else { } else {
baseKey = this.quoteTable(options.prefix)+'.'+baseKey; baseKey = `${this.quoteTable(options.prefix)}.${baseKey}`;
} }
} }
baseKey = '('+baseKey+')'; baseKey = this.jsonPathExtractionQuery(baseKey, path);
const castKey = item => { const castKey = item => {
let key = baseKey; let key = baseKey;
...@@ -1973,7 +1975,7 @@ const QueryGenerator = { ...@@ -1973,7 +1975,7 @@ const QueryGenerator = {
} }
if (cast) { if (cast) {
key += '::'+cast; return this.handleSequelizeMethod(new Utils.Cast(new Utils.Literal(key), cast));
} }
return key; return key;
...@@ -2233,6 +2235,38 @@ const QueryGenerator = { ...@@ -2233,6 +2235,38 @@ const QueryGenerator = {
return result ? result : '1=1'; return result ? result : '1=1';
}, },
// A recursive parser for nested where conditions
parseConditionObject(conditions, path) {
path = path || [];
return _.reduce(conditions, (result, value, key) => {
if (_.isObject(value)) {
result = result.concat(this.parseConditionObject(value, path.concat(key))); // Recursively parse objects
} else {
result.push({ path: path.concat(key), value: value });
}
return result;
}, []);
},
/**
* 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
* @private
*/
jsonPathExtractionQuery(column, path) {
const paths = _.toPath(path);
const pathStr = `{${paths.join(',')}}`;
const quotedColumn = this.isIdentifierQuoted(column) ? column : this.quoteIdentifier(column);
return `${quotedColumn}#>>'${pathStr}'`;
},
isIdentifierQuoted(string) {
return /^\s*(?:([`"'])(?:(?!\1).|\1{2})*\1\.?)+\s*$/i.test(string);
},
booleanValue(value) { booleanValue(value) {
return value; return value;
} }
......
...@@ -63,7 +63,7 @@ const QueryGenerator = { ...@@ -63,7 +63,7 @@ const QueryGenerator = {
const values = { const values = {
table: this.quoteTable(tableName), table: this.quoteTable(tableName),
attributes: attrStr.join(', '), attributes: attrStr.join(', '),
comments: Utils._.template(comments)({ table: this.quoteTable(tableName)}) comments: Utils._.template(comments)({ table: this.quoteTable(tableName) })
}; };
if (!!options.uniqueKeys) { if (!!options.uniqueKeys) {
...@@ -121,17 +121,86 @@ const QueryGenerator = { ...@@ -121,17 +121,86 @@ const QueryGenerator = {
`WHERE c.table_name = ${this.escape(tableName)} AND c.table_schema = ${this.escape(schema)} `; `WHERE c.table_name = ${this.escape(tableName)} AND c.table_schema = ${this.escape(schema)} `;
}, },
// A recursive parser for nested where conditions /**
parseConditionObject(_conditions, path) { * Check whether the statmement is json function or simple path
path = path || []; *
return Utils._.reduce(_conditions, (r, v, k) => { // result, key, value * @param {String} stmt The statement to validate
if (Utils._.isObject(v)) { * @returns {Boolean} true if the given statement is json function
r = r.concat(this.parseConditionObject(v, path.concat(k))); // Recursively parse objects * @throws {Error} throw if the statement looks like json function but has invalid token
} else { */
r.push({ path: path.concat(k), value: v }); checkValidJsonStatement(stmt) {
if (!_.isString(stmt)) {
return false;
}
// https://www.postgresql.org/docs/current/static/functions-json.html
const jsonFunctionRegex = /^\s*((?:[a-z]+_){0,2}jsonb?(?:_[a-z]+){0,2})\([^)]*\)/i;
const jsonOperatorRegex = /^\s*(->>?|#>>?|@>|<@|\?[|&]?|\|{2}|#-)/i;
const tokenCaptureRegex = /^\s*((?:([`"'])(?:(?!\2).|\2{2})*\2)|[\w\d\s]+|[().,;+-])/i;
let currentIndex = 0;
let openingBrackets = 0;
let closingBrackets = 0;
let hasJsonFunction = false;
let hasInvalidToken = false;
while (currentIndex < stmt.length) {
const string = stmt.substr(currentIndex);
const functionMatches = jsonFunctionRegex.exec(string);
if (functionMatches) {
currentIndex += functionMatches[0].indexOf('(');
hasJsonFunction = true;
continue;
}
const operatorMatches = jsonOperatorRegex.exec(string);
if (operatorMatches) {
currentIndex += operatorMatches[0].length;
hasJsonFunction = true;
continue;
} }
return r;
}, []); const tokenMatches = tokenCaptureRegex.exec(string);
if (tokenMatches) {
const capturedToken = tokenMatches[1];
if (capturedToken === '(') {
openingBrackets++;
} else if (capturedToken === ')') {
closingBrackets++;
} else if (capturedToken === ';') {
hasInvalidToken = true;
break;
}
currentIndex += tokenMatches[0].length;
continue;
}
break;
}
// Check invalid json statement
hasInvalidToken |= openingBrackets !== closingBrackets;
if (hasJsonFunction && hasInvalidToken) {
throw new Error('Invalid json statement: ' + stmt);
}
// return true if the statement has valid json function
return hasJsonFunction;
},
/**
* 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
* @private
*/
jsonPathExtractionQuery(column, path) {
const paths = _.toPath(path);
const pathStr = `{${paths.join(',')}}`;
const quotedColumn = this.isIdentifierQuoted(column) ? column : this.quoteIdentifier(column);
return `(${quotedColumn}#>>'${pathStr}')`;
}, },
handleSequelizeMethod(smth, tableName, factory, options, prepend) { handleSequelizeMethod(smth, tableName, factory, options, prepend) {
...@@ -139,20 +208,21 @@ const QueryGenerator = { ...@@ -139,20 +208,21 @@ const QueryGenerator = {
// Parse nested object // Parse nested object
if (smth.conditions) { if (smth.conditions) {
const conditions = _.map(this.parseConditionObject(smth.conditions), condition => const conditions = _.map(this.parseConditionObject(smth.conditions), condition =>
`${this.quoteIdentifier(_.first(condition.path))}#>>'{${_.tail(condition.path).join(',')}}' = '${condition.value}'` `${this.jsonPathExtractionQuery(_.first(condition.path), _.tail(condition.path))} = '${condition.value}'`
); );
return conditions.join(' and '); return conditions.join(' AND ');
} else if (smth.path) { } else if (smth.path) {
let str; let str;
// Allow specifying conditions using the postgres json syntax // Allow specifying conditions using the postgres json syntax
if (_.some(['->', '->>', '#>'], _.partial(_.includes, smth.path))) { if (this.checkValidJsonStatement(smth.path)) {
str = smth.path; str = smth.path;
} else { } else {
// Also support json dot notation // Also support json property accessors
const path = smth.path.split('.'); const paths = _.toPath(smth.path);
str = `${this.quoteIdentifier(_.first(path))}#>>'{${_.tail(path).join(',')}}'`; const column = paths.shift();
str = this.jsonPathExtractionQuery(column, paths);
} }
if (smth.value) { if (smth.value) {
...@@ -161,14 +231,13 @@ const QueryGenerator = { ...@@ -161,14 +231,13 @@ const QueryGenerator = {
return str; return str;
} }
} else {
return AbstractQueryGenerator.handleSequelizeMethod.call(this, smth, tableName, factory, options, prepend);
} }
return AbstractQueryGenerator.handleSequelizeMethod.call(this, smth, tableName, factory, options, prepend);
}, },
addColumnQuery(table, key, dataType) { addColumnQuery(table, key, dataType) {
const dbDataType = this.attributeToSQL(dataType, {context: 'addColumn'}); const dbDataType = this.attributeToSQL(dataType, { context: 'addColumn' });
const definition = this.dataTypeMapping(table, key, dbDataType); const definition = this.dataTypeMapping(table, key, dbDataType);
const quotedKey = this.quoteIdentifier(key); const quotedKey = this.quoteIdentifier(key);
const quotedTable = this.quoteTable(this.extractTableDetails(table)); const quotedTable = this.quoteTable(this.extractTableDetails(table));
...@@ -281,7 +350,7 @@ const QueryGenerator = { ...@@ -281,7 +350,7 @@ const QueryGenerator = {
}, },
exceptionFn(fnName, tableName, main, then, when, returns, language) { exceptionFn(fnName, tableName, main, then, when, returns, language) {
when = when || 'unique_violation'; when = when || 'unique_violation';
const body = `${main} EXCEPTION WHEN ${when} THEN ${then};`; const body = `${main} EXCEPTION WHEN ${when} THEN ${then};`;
...@@ -605,7 +674,6 @@ const QueryGenerator = { ...@@ -605,7 +674,6 @@ const QueryGenerator = {
return paramList.join(', '); return paramList.join(', ');
}, },
expandOptions(options) { expandOptions(options) {
return Utils._.isUndefined(options) || Utils._.isEmpty(options) ? return Utils._.isUndefined(options) || Utils._.isEmpty(options) ?
'' : '\n\t' + options.join('\n\t'); '' : '\n\t' + options.join('\n\t');
...@@ -779,8 +847,7 @@ const QueryGenerator = { ...@@ -779,8 +847,7 @@ const QueryGenerator = {
} }
}, },
/* /**
/**
* Generates an SQL query that returns all foreign keys of a table. * Generates an SQL query that returns all foreign keys of a table.
* *
* @param {String} tableName The name of the table. * @param {String} tableName The name of the table.
...@@ -805,7 +872,6 @@ const QueryGenerator = { ...@@ -805,7 +872,6 @@ const QueryGenerator = {
return 'ALTER TABLE ' + this.quoteTable(tableName) + ' DROP CONSTRAINT ' + this.quoteIdentifier(foreignKey) + ';'; return 'ALTER TABLE ' + this.quoteTable(tableName) + ' DROP CONSTRAINT ' + this.quoteIdentifier(foreignKey) + ';';
}, },
setAutocommitQuery(value, options) { setAutocommitQuery(value, options) {
if (options.parent) { if (options.parent) {
return; return;
......
...@@ -23,6 +23,17 @@ module.exports = BaseTypes => { ...@@ -23,6 +23,17 @@ module.exports = BaseTypes => {
BaseTypes.REAL.types.sqlite = ['REAL']; BaseTypes.REAL.types.sqlite = ['REAL'];
BaseTypes.DOUBLE.types.sqlite = ['DOUBLE PRECISION']; BaseTypes.DOUBLE.types.sqlite = ['DOUBLE PRECISION'];
BaseTypes.GEOMETRY.types.sqlite = false; BaseTypes.GEOMETRY.types.sqlite = false;
BaseTypes.JSON.types.sqlite = ['JSON', 'JSONB'];
function JSONTYPE() {
if (!(this instanceof JSONTYPE)) return new JSONTYPE();
BaseTypes.JSON.apply(this, arguments);
}
inherits(JSONTYPE, BaseTypes.JSON);
JSONTYPE.parse = function parse(data) {
return JSON.parse(data);
};
function DATE(length) { function DATE(length) {
if (!(this instanceof DATE)) return new DATE(length); if (!(this instanceof DATE)) return new DATE(length);
...@@ -205,7 +216,8 @@ module.exports = BaseTypes => { ...@@ -205,7 +216,8 @@ module.exports = BaseTypes => {
INTEGER, INTEGER,
BIGINT, BIGINT,
TEXT, TEXT,
ENUM ENUM,
JSON: JSONTYPE
}; };
_.forIn(exports, (DataType, key) => { _.forIn(exports, (DataType, key) => {
......
...@@ -34,7 +34,8 @@ SqliteDialect.prototype.supports = _.merge(_.cloneDeep(AbstractDialect.prototype ...@@ -34,7 +34,8 @@ SqliteDialect.prototype.supports = _.merge(_.cloneDeep(AbstractDialect.prototype
}, },
joinTableDependent: false, joinTableDependent: false,
groupedLimit: false, groupedLimit: false,
ignoreDuplicates: ' OR IGNORE' ignoreDuplicates: ' OR IGNORE',
JSON: true
}); });
ConnectionManager.prototype.defaultVersion = '3.8.0'; ConnectionManager.prototype.defaultVersion = '3.8.0';
......
...@@ -2,9 +2,11 @@ ...@@ -2,9 +2,11 @@
/* jshint -W110 */ /* jshint -W110 */
const Utils = require('../../utils'); const Utils = require('../../utils');
const util = require('util');
const Transaction = require('../../transaction'); const Transaction = require('../../transaction');
const _ = require('lodash'); const _ = require('lodash');
const MySqlQueryGenerator = require('../mysql/query-generator'); const MySqlQueryGenerator = require('../mysql/query-generator');
const AbstractQueryGenerator = require('../abstract/query-generator');
const QueryGenerator = { const QueryGenerator = {
/* jshint proto:true */ /* jshint proto:true */
...@@ -75,15 +77,128 @@ const QueryGenerator = { ...@@ -75,15 +77,128 @@ const QueryGenerator = {
return this.replaceBooleanDefaults(sql); return this.replaceBooleanDefaults(sql);
}, },
booleanValue(value){ booleanValue(value) {
return !!value ? 1 : 0; return !!value ? 1 : 0;
}, },
addColumnQuery(table, key, dataType) { /**
* Check whether the statmement is json function or simple path
*
* @param {String} stmt The statement to validate
* @returns {Boolean} true if the given statement is json function
* @throws {Error} throw if the statement looks like json function but has invalid token
*/
checkValidJsonStatement(stmt) {
if (!_.isString(stmt)) {
return false;
}
// https://sqlite.org/json1.html
const jsonFunctionRegex = /^\s*(json(?:_[a-z]+){0,2})\([^)]*\)/i;
const tokenCaptureRegex = /^\s*((?:([`"'])(?:(?!\2).|\2{2})*\2)|[\w\d\s]+|[().,;+-])/i;
let currentIndex = 0;
let openingBrackets = 0;
let closingBrackets = 0;
let hasJsonFunction = false;
let hasInvalidToken = false;
while (currentIndex < stmt.length) {
const string = stmt.substr(currentIndex);
const functionMatches = jsonFunctionRegex.exec(string);
if (functionMatches) {
currentIndex += functionMatches[0].indexOf('(');
hasJsonFunction = true;
continue;
}
const tokenMatches = tokenCaptureRegex.exec(string);
if (tokenMatches) {
const capturedToken = tokenMatches[1];
if (capturedToken === '(') {
openingBrackets++;
} else if (capturedToken === ')') {
closingBrackets++;
} else if (capturedToken === ';') {
hasInvalidToken = true;
break;
}
currentIndex += tokenMatches[0].length;
continue;
}
break;
}
// Check invalid json statement
hasInvalidToken |= openingBrackets !== closingBrackets;
if (hasJsonFunction && hasInvalidToken) {
throw new Error('Invalid json statement: ' + stmt);
}
// return true if the statement has valid json function
return hasJsonFunction;
},
/**
* 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
* @private
*/
jsonPathExtractionQuery(column, path) {
const paths = _.toPath(path);
const pathStr = ['$']
.concat(paths)
.join('.')
.replace(/\.(\d+)(?:(?=\.)|$)/g, (_, digit) => `[${digit}]`);
const quotedColumn = this.isIdentifierQuoted(column) ? column : this.quoteIdentifier(column);
return `json_extract(${quotedColumn}, '${pathStr}')`;
},
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(_.first(condition.path), _.tail(condition.path))} = '${condition.value}'`
);
return conditions.join(' AND ');
} else 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 str;
}
} else if (smth instanceof Utils.Cast) {
if (/timestamp/i.test(smth.type)) {
smth.type = 'datetime';
}
}
return AbstractQueryGenerator.handleSequelizeMethod.call(this, smth, tableName, factory, options, prepend);
},
addColumnQuery(table, key, dataType) {
const attributes = {}; const attributes = {};
attributes[key] = dataType; attributes[key] = dataType;
const fields = this.attributesToSQL(attributes, {context: 'addColumn'}); const fields = this.attributesToSQL(attributes, { context: 'addColumn' });
const attribute = this.quoteIdentifier(key) + ' ' + fields[key]; const attribute = this.quoteIdentifier(key) + ' ' + fields[key];
const sql = `ALTER TABLE ${this.quoteTable(table)} ADD ${attribute};`; const sql = `ALTER TABLE ${this.quoteTable(table)} ADD ${attribute};`;
...@@ -129,10 +244,11 @@ const QueryGenerator = { ...@@ -129,10 +244,11 @@ const QueryGenerator = {
return `UPDATE ${this.quoteTable(tableName)} SET ${values.join(',')} ${this.whereQuery(where)}`; return `UPDATE ${this.quoteTable(tableName)} SET ${values.join(',')} ${this.whereQuery(where)}`;
}, },
deleteQuery(tableName, where, options) { deleteQuery(tableName, where, options, model) {
options = options || {}; options = options || {};
_.defaults(options, this.options);
let whereClause = this.getWhereConditions(where); let whereClause = this.getWhereConditions(where, null, model, options);
if (whereClause) { if (whereClause) {
whereClause = ' WHERE ' + whereClause; whereClause = ' WHERE ' + whereClause;
} }
...@@ -173,11 +289,11 @@ const QueryGenerator = { ...@@ -173,11 +289,11 @@ const QueryGenerator = {
} }
} }
if(dataType.references) { if (dataType.references) {
const referencesTable = this.quoteTable(dataType.references.model); const referencesTable = this.quoteTable(dataType.references.model);
let referencesKey; let referencesKey;
if(dataType.references.key) { if (dataType.references.key) {
referencesKey = this.quoteIdentifier(dataType.references.key); referencesKey = this.quoteIdentifier(dataType.references.key);
} else { } else {
referencesKey = this.quoteIdentifier('id'); referencesKey = this.quoteIdentifier('id');
...@@ -185,11 +301,11 @@ const QueryGenerator = { ...@@ -185,11 +301,11 @@ const QueryGenerator = {
sql += ` REFERENCES ${referencesTable} (${referencesKey})`; sql += ` REFERENCES ${referencesTable} (${referencesKey})`;
if(dataType.onDelete) { if (dataType.onDelete) {
sql += ' ON DELETE ' + dataType.onDelete.toUpperCase(); sql += ' ON DELETE ' + dataType.onDelete.toUpperCase();
} }
if(dataType.onUpdate) { if (dataType.onUpdate) {
sql += ' ON UPDATE ' + dataType.onUpdate.toUpperCase(); sql += ' ON UPDATE ' + dataType.onUpdate.toUpperCase();
} }
...@@ -303,7 +419,7 @@ const QueryGenerator = { ...@@ -303,7 +419,7 @@ const QueryGenerator = {
return 'SAVEPOINT ' + this.quoteIdentifier(transaction.name) + ';'; return 'SAVEPOINT ' + this.quoteIdentifier(transaction.name) + ';';
} }
return 'BEGIN ' + transaction.options.type + ' TRANSACTION;'; return 'BEGIN ' + transaction.options.type + ' TRANSACTION;';
}, },
setAutocommitQuery() { setAutocommitQuery() {
......
'use strict'; 'use strict';
var chai = require('chai') const chai = require('chai')
, expect = chai.expect , expect = chai.expect
, Support = require(__dirname + '/../../support') , Support = require(__dirname + '/../../support')
, DataTypes = require(__dirname + '/../../../../lib/data-types') , Sequelize = Support.Sequelize
, dialect = Support.getTestDialect(); , dialect = Support.getTestDialect()
, DataTypes = require(__dirname + '/../../../../lib/data-types');
if (dialect === 'sqlite') { if (dialect === 'sqlite') {
describe('[SQLITE Specific] DAO', function() { describe('[SQLITE Specific] DAO', function () {
beforeEach(function() { beforeEach(function () {
this.User = this.sequelize.define('User', { this.User = this.sequelize.define('User', {
username: DataTypes.STRING, username: DataTypes.STRING,
emergency_contact: DataTypes.JSON,
emergencyContact: DataTypes.JSON,
dateField: { dateField: {
type: DataTypes.DATE, type: DataTypes.DATE,
field: 'date_field' field: 'date_field'
...@@ -27,60 +30,87 @@ if (dialect === 'sqlite') { ...@@ -27,60 +30,87 @@ if (dialect === 'sqlite') {
return this.sequelize.sync({ force: true }); return this.sequelize.sync({ force: true });
}); });
describe('findAll', function() { describe('findAll', function () {
it('handles dates correctly', function() { it('handles dates correctly', function () {
var self = this const user = this.User.build({ username: 'user' });
, user = this.User.build({ username: 'user' });
user.dataValues.createdAt = new Date(2011, 4, 4); user.dataValues.createdAt = new Date(2011, 4, 4);
return user.save().then(function() { return user.save().then(() => {
return self.User.create({ username: 'new user' }).then(function() { return this.User.create({ username: 'new user' }).then(() => {
return self.User.findAll({ return this.User.findAll({
where: { createdAt: { $gt: new Date(2012, 1, 1) }} where: { createdAt: { $gt: new Date(2012, 1, 1) } }
}).then(function(users) { }).then(users => {
expect(users).to.have.length(1); expect(users).to.have.length(1);
}); });
}); });
}); });
}); });
it('handles dates with aliasses correctly #3611', function() { it('handles dates with aliasses correctly #3611', function () {
return this.User.create({ return this.User.create({
dateField: new Date(2010, 10, 10) dateField: new Date(2010, 10, 10)
}).bind(this).then(function () { }).then(() => {
return this.User.findAll().get(0); return this.User.findAll().get(0);
}).then(function (user) { }).then(user => {
expect(user.get('dateField')).to.be.an.instanceof(Date); expect(user.get('dateField')).to.be.an.instanceof(Date);
expect(user.get('dateField')).to.equalTime(new Date(2010, 10, 10)); expect(user.get('dateField')).to.equalTime(new Date(2010, 10, 10));
}); });
}); });
it('handles dates in includes correctly #2644', function() { it('handles dates in includes correctly #2644', function () {
return this.User.create({ return this.User.create({
projects: [ projects: [
{ dateField: new Date(1990, 5, 5) } { dateField: new Date(1990, 5, 5) }
] ]
}, { include: [this.Project]}).bind(this).then(function () { }, { include: [this.Project] }).then(() => {
return this.User.findAll({ return this.User.findAll({
include: [this.Project] include: [this.Project]
}).get(0); }).get(0);
}).then(function (user) { }).then(user => {
expect(user.projects[0].get('dateField')).to.be.an.instanceof(Date); expect(user.projects[0].get('dateField')).to.be.an.instanceof(Date);
expect(user.projects[0].get('dateField')).to.equalTime(new Date(1990, 5, 5)); expect(user.projects[0].get('dateField')).to.equalTime(new Date(1990, 5, 5));
}); });
}); });
}); });
describe('regression tests', function() { describe('json', function () {
it('should be able to retrieve a row with json_extract function', function () {
it('do not crash while parsing unique constraint errors', function() { return this.sequelize.Promise.all([
var Payments = this.sequelize.define('payments', {}); this.User.create({ username: 'swen', emergency_contact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergency_contact: { name: 'joe' } })
]).then(() => {
return this.User.find({
where: Sequelize.json(`json_extract(emergency_contact, '$.name')`, 'kate'),
attributes: ['username', 'emergency_contact']
});
}).then(user => {
expect(user.emergency_contact.name).to.equal('kate');
});
});
return Payments.sync({force: true}).then(function () { it('should be able to retrieve a row by json_type function', function () {
return (expect(Payments.bulkCreate([{id: 1}, {id: 1}], { ignoreDuplicates: false })).to.eventually.be.rejected); return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergency_contact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergency_contact: ['kate', 'joe'] })
]).then(() => {
return this.User.find({
where: Sequelize.json(`json_type(emergency_contact)`, 'array'),
attributes: ['username', 'emergency_contact']
});
}).then(user => {
expect(user.username).to.equal('anna');
}); });
});
});
describe('regression tests', function () {
it('do not crash while parsing unique constraint errors', function () {
const Payments = this.sequelize.define('payments', {});
return Payments.sync({ force: true }).then(() => {
return (expect(Payments.bulkCreate([{ id: 1 }, { id: 1 }], { ignoreDuplicates: false })).to.eventually.be.rejected);
});
}); });
}); });
}); });
......
'use strict';
const chai = require('chai')
, expect = chai.expect
, Support = require('./support')
, Sequelize = Support.Sequelize
, current = Support.sequelize
, DataTypes = Sequelize.DataTypes;
describe('model', function () {
if (current.dialect.supports.JSON) {
describe('json', function () {
beforeEach(function () {
this.User = this.sequelize.define('User', {
username: DataTypes.STRING,
emergency_contact: DataTypes.JSON,
emergencyContact: DataTypes.JSON,
});
return this.sequelize.sync({ force: true });
});
it('should tell me that a column is json', function () {
return this.sequelize.queryInterface.describeTable('Users')
.then(table => {
expect(table.emergency_contact.type).to.equal('JSON');
});
});
it('should stringify json with insert', function () {
return this.User.create({
username: 'bob',
emergency_contact: { name: 'joe', phones: [1337, 42] }
}, {
fields: ['id', 'username', 'document', 'emergency_contact'],
logging: sql => {
const expected = '\'{"name":"joe","phones":[1337,42]}\'';
expect(sql.indexOf(expected)).not.to.equal(-1);
}
});
});
it('should insert json using a custom field name', function () {
this.UserFields = this.sequelize.define('UserFields', {
emergencyContact: { type: DataTypes.JSON, field: 'emergy_contact' }
});
return this.UserFields.sync({ force: true }).then(() => {
return this.UserFields.create({
emergencyContact: { name: 'joe', phones: [1337, 42] }
}).then(user => {
expect(user.emergencyContact.name).to.equal('joe');
});
});
});
it('should update json using a custom field name', function () {
this.UserFields = this.sequelize.define('UserFields', {
emergencyContact: { type: DataTypes.JSON, field: 'emergy_contact' }
});
return this.UserFields.sync({ force: true }).then(() => {
return this.UserFields.create({
emergencyContact: { name: 'joe', phones: [1337, 42] }
}).then(user => {
user.emergencyContact = { name: 'larry' };
return user.save();
}).then(user => {
expect(user.emergencyContact.name).to.equal('larry');
});
});
});
it('should be able retrieve json value as object', function () {
const emergencyContact = { name: 'kate', phone: 1337 };
return this.User.create({ username: 'swen', emergency_contact: emergencyContact })
.then(user => {
expect(user.emergency_contact).to.eql(emergencyContact);
return this.User.find({ where: { username: 'swen' }, attributes: ['emergency_contact'] });
})
.then(user => {
expect(user.emergency_contact).to.eql(emergencyContact);
});
});
it('should be able to retrieve element of array by index', function () {
const emergencyContact = { name: 'kate', phones: [1337, 42] };
return this.User.create({ username: 'swen', emergency_contact: emergencyContact })
.then(user => {
expect(user.emergency_contact).to.eql(emergencyContact);
return this.User.find({
where: { username: 'swen' },
attributes: [[Sequelize.json('emergency_contact.phones[1]'), 'firstEmergencyNumber']]
});
})
.then(user => {
expect(parseInt(user.getDataValue('firstEmergencyNumber'))).to.equal(42);
});
});
it('should be able to retrieve root level value of an object by key', function () {
const emergencyContact = { kate: 1337 };
return this.User.create({ username: 'swen', emergency_contact: emergencyContact })
.then(user => {
expect(user.emergency_contact).to.eql(emergencyContact);
return this.User.find({
where: { username: 'swen' },
attributes: [[Sequelize.json('emergency_contact.kate'), 'katesNumber']]
});
})
.then(user => {
expect(parseInt(user.getDataValue('katesNumber'))).to.equal(1337);
});
});
it('should be able to retrieve nested value of an object by path', function () {
const emergencyContact = { kate: { email: 'kate@kate.com', phones: [1337, 42] } };
return this.User.create({ username: 'swen', emergency_contact: emergencyContact })
.then(user => {
expect(user.emergency_contact).to.eql(emergencyContact);
return this.User.find({
where: { username: 'swen' },
attributes: [[Sequelize.json('emergency_contact.kate.email'), 'katesEmail']]
});
}).then(user => {
expect(user.getDataValue('katesEmail')).to.equal('kate@kate.com');
}).then(() => {
return this.User.find({
where: { username: 'swen' },
attributes: [[Sequelize.json('emergency_contact.kate.phones[1]'), 'katesFirstPhone']]
});
}).then(user => {
expect(parseInt(user.getDataValue('katesFirstPhone'))).to.equal(42);
});
});
it('should be able to retrieve a row based on the values of the json document', function () {
return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergency_contact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergency_contact: { name: 'joe' } })
]).then(() => {
return this.User.find({
where: Sequelize.json('emergency_contact.name', 'kate'),
attributes: ['username', 'emergency_contact']
});
}).then(user => {
expect(user.emergency_contact.name).to.equal('kate');
});
});
it('should be able to query using the nested query language', function () {
return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergency_contact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergency_contact: { name: 'joe' } })
]).then(() => {
return this.User.find({
where: Sequelize.json({ emergency_contact: { name: 'kate' } })
});
}).then(user => {
expect(user.emergency_contact.name).to.equal('kate');
});
});
it('should be able to query using dot notation', function () {
return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergency_contact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergency_contact: { name: 'joe' } })
]).then(() => {
return this.User.find({ where: Sequelize.json('emergency_contact.name', 'joe') });
}).then(user => {
expect(user.emergency_contact.name).to.equal('joe');
});
});
it('should be able to query using dot notation with uppercase name', function () {
return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergencyContact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergencyContact: { name: 'joe' } })
]).then(() => {
return this.User.find({
attributes: [[Sequelize.json('emergencyContact.name'), 'contactName']],
where: Sequelize.json('emergencyContact.name', 'joe')
});
}).then(user => {
expect(user.get('contactName')).to.equal('joe');
});
});
it('should be able to query array using property accessor', function () {
return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergency_contact: ['kate', 'joe'] }),
this.User.create({ username: 'anna', emergency_contact: [{ name: 'joe' }] })
]).then(() => {
return this.User.find({ where: Sequelize.json('emergency_contact.0', 'kate') });
}).then(user => {
expect(user.username).to.equal('swen');
}).then(() => {
return this.User.find({ where: Sequelize.json('emergency_contact[0].name', 'joe') });
}).then(user => {
expect(user.username).to.equal('anna');
});
});
it('should be able to store values that require JSON escaping', function () {
const text = `Multi-line '$string' needing "escaping" for $$ and $1 type values`;
return this.User.create({
username: 'swen',
emergency_contact: { value: text }
}).then(user => {
expect(user.isNewRecord).to.equal(false);
}).then(() => {
return this.User.find({ where: { username: 'swen' } });
}).then(() => {
return this.User.find({ where: Sequelize.json('emergency_contact.value', text) });
}).then(user => {
expect(user.username).to.equal('swen');
});
});
it('should be able to findOrCreate with values that require JSON escaping', function () {
const text = `Multi-line '$string' needing "escaping" for $$ and $1 type values`;
return this.User.findOrCreate({
where: { username: 'swen' },
defaults: { emergency_contact: { value: text } }
}).then(user => {
expect(!user.isNewRecord).to.equal(true);
}).then(() => {
return this.User.find({ where: { username: 'swen' } });
}).then(() => {
return this.User.find({ where: Sequelize.json('emergency_contact.value', text) });
}).then(user => {
expect(user.username).to.equal('swen');
});
});
});
}
});
'use strict'; 'use strict';
/* jshint -W030 */ /* jshint -W030 */
/* jshint -W079 */
/* jshint -W110 */ /* jshint -W110 */
var chai = require('chai') const chai = require('chai')
, Sequelize = require('../../../index') , Sequelize = require('../../../index')
, Promise = Sequelize.Promise , Promise = Sequelize.Promise
, expect = chai.expect , expect = chai.expect
...@@ -10,27 +11,26 @@ var chai = require('chai') ...@@ -10,27 +11,26 @@ var chai = require('chai')
, DataTypes = require(__dirname + '/../../../lib/data-types') , DataTypes = require(__dirname + '/../../../lib/data-types')
, current = Support.sequelize; , current = Support.sequelize;
describe(Support.getTestDialectTeaser('Model'), function() { describe(Support.getTestDialectTeaser('Model'), function () {
if (current.dialect.supports.JSONB) { if (current.dialect.supports.JSON) {
describe('JSONB', function () { describe('JSON', function () {
beforeEach(function () { beforeEach(function () {
this.Event = this.sequelize.define('Event', { this.Event = this.sequelize.define('Event', {
data: { data: {
type: DataTypes.JSONB, type: DataTypes.JSON,
field: 'event_data', field: 'event_data',
index: true index: true
}, },
json: DataTypes.JSON json: DataTypes.JSON
}); });
return this.Event.sync({force: true}); return this.Event.sync({ force: true });
}); });
if (current.dialect.supports.lock) { if (current.dialect.supports.lock) {
it('findOrCreate supports transactions, json and locks', function() { it('findOrCreate supports transactions, json and locks', function () {
var self = this; return current.transaction().then(transaction => {
return current.transaction().then(function(t) { return this.Event.findOrCreate({
return self.Event.findOrCreate({
where: { where: {
json: { some: { input: 'Hello' } } json: { some: { input: 'Hello' } }
}, },
...@@ -38,18 +38,18 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -38,18 +38,18 @@ describe(Support.getTestDialectTeaser('Model'), function() {
json: { some: { input: 'Hello' }, input: [1, 2, 3] }, json: { some: { input: 'Hello' }, input: [1, 2, 3] },
data: { some: { input: 'There' }, input: [4, 5, 6] } data: { some: { input: 'There' }, input: [4, 5, 6] }
}, },
transaction: t, transaction: transaction,
lock: t.LOCK.UPDATE, lock: transaction.LOCK.UPDATE,
logging: function (sql) { logging: sql => {
if (sql.indexOf('SELECT') !== -1 && sql.indexOf('CREATE') === -1) { if (sql.indexOf('SELECT') !== -1 && sql.indexOf('CREATE') === -1) {
expect(sql.indexOf('FOR UPDATE')).not.to.be.equal(-1); expect(sql.indexOf('FOR UPDATE')).not.to.be.equal(-1);
} }
} }
}).then(function() { }).then(() => {
return self.Event.count().then(function(count) { return this.Event.count().then(count => {
expect(count).to.equal(0); expect(count).to.equal(0);
return t.commit().then(function() { return transaction.commit().then(() => {
return self.Event.count().then(function(count) { return this.Event.count().then(count => {
expect(count).to.equal(1); expect(count).to.equal(1);
}); });
}); });
...@@ -59,7 +59,7 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -59,7 +59,7 @@ describe(Support.getTestDialectTeaser('Model'), function() {
}); });
} }
it('should create an instance with JSONB data', function () { it('should create an instance with JSON data', function () {
return this.Event.create({ return this.Event.create({
data: { data: {
name: { name: {
...@@ -68,9 +68,9 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -68,9 +68,9 @@ describe(Support.getTestDialectTeaser('Model'), function() {
}, },
employment: 'Nuclear Safety Inspector' employment: 'Nuclear Safety Inspector'
} }
}).bind(this).then(function () { }).then(() => {
return this.Event.findAll().then(function (events) { return this.Event.findAll().then(events => {
var event = events[0]; const event = events[0];
expect(event.get('data')).to.eql({ expect(event.get('data')).to.eql({
name: { name: {
...@@ -83,7 +83,7 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -83,7 +83,7 @@ describe(Support.getTestDialectTeaser('Model'), function() {
}); });
}); });
it('should update an instance with JSONB data', function () { it('should update an instance with JSON data', function () {
return this.Event.create({ return this.Event.create({
data: { data: {
name: { name: {
...@@ -92,7 +92,7 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -92,7 +92,7 @@ describe(Support.getTestDialectTeaser('Model'), function() {
}, },
employment: 'Nuclear Safety Inspector' employment: 'Nuclear Safety Inspector'
} }
}).bind(this).then(function (event) { }).then(event => {
return event.update({ return event.update({
data: { data: {
name: { name: {
...@@ -102,9 +102,9 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -102,9 +102,9 @@ describe(Support.getTestDialectTeaser('Model'), function() {
employment: null employment: null
} }
}); });
}).then(function () { }).then(() => {
return this.Event.findAll().then(function (events) { return this.Event.findAll().then(events => {
var event = events[0]; const event = events[0];
expect(event.get('data')).to.eql({ expect(event.get('data')).to.eql({
name: { name: {
...@@ -137,15 +137,15 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -137,15 +137,15 @@ describe(Support.getTestDialectTeaser('Model'), function() {
employment: 'Housewife' employment: 'Housewife'
} }
}) })
).bind(this).then(function () { ).then(() => {
return this.Event.findAll({ return this.Event.findAll({
where: { where: {
data: { data: {
employment: 'Housewife' employment: 'Housewife'
} }
} }
}).then(function (events) { }).then(events => {
var event = events[0]; const event = events[0];
expect(events.length).to.equal(1); expect(events.length).to.equal(1);
expect(event.get('data')).to.eql({ expect(event.get('data')).to.eql({
...@@ -179,7 +179,7 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -179,7 +179,7 @@ describe(Support.getTestDialectTeaser('Model'), function() {
age: 37 age: 37
} }
}) })
).bind(this).then(function () { ).then(() => {
return this.Event.findAll({ return this.Event.findAll({
where: { where: {
data: { data: {
...@@ -188,8 +188,8 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -188,8 +188,8 @@ describe(Support.getTestDialectTeaser('Model'), function() {
} }
} }
} }
}).then(function (events) { }).then(events => {
var event = events[0]; const event = events[0];
expect(events.length).to.equal(1); expect(events.length).to.equal(1);
expect(event.get('data')).to.eql({ expect(event.get('data')).to.eql({
...@@ -223,14 +223,14 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -223,14 +223,14 @@ describe(Support.getTestDialectTeaser('Model'), function() {
employment: null employment: null
} }
}) })
).bind(this).then(function () { ).then(() => {
return this.Event.findAll({ return this.Event.findAll({
where: { where: {
data: { data: {
employment: null employment: null
} }
} }
}).then(function (events) { }).then(events => {
expect(events.length).to.equal(1); expect(events.length).to.equal(1);
expect(events[0].get('data')).to.eql({ expect(events[0].get('data')).to.eql({
name: { name: {
...@@ -244,7 +244,6 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -244,7 +244,6 @@ describe(Support.getTestDialectTeaser('Model'), function() {
}); });
it('should be possible to query multiple nested values', function () { it('should be possible to query multiple nested values', function () {
var self = this;
return this.Event.create({ return this.Event.create({
data: { data: {
name: { name: {
...@@ -253,9 +252,9 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -253,9 +252,9 @@ describe(Support.getTestDialectTeaser('Model'), function() {
}, },
employment: 'Nuclear Safety Inspector' employment: 'Nuclear Safety Inspector'
} }
}).then(function() { }).then(() => {
return Promise.join( return Promise.join(
self.Event.create({ this.Event.create({
data: { data: {
name: { name: {
first: 'Marge', first: 'Marge',
...@@ -264,7 +263,7 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -264,7 +263,7 @@ describe(Support.getTestDialectTeaser('Model'), function() {
employment: 'Housewife' employment: 'Housewife'
} }
}), }),
self.Event.create({ this.Event.create({
data: { data: {
name: { name: {
first: 'Bart', first: 'Bart',
...@@ -274,8 +273,8 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -274,8 +273,8 @@ describe(Support.getTestDialectTeaser('Model'), function() {
} }
}) })
); );
}).then(function () { }).then(() => {
return self.Event.findAll({ return this.Event.findAll({
where: { where: {
data: { data: {
name: { name: {
...@@ -289,7 +288,7 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -289,7 +288,7 @@ describe(Support.getTestDialectTeaser('Model'), function() {
order: [ order: [
['id', 'ASC'] ['id', 'ASC']
] ]
}).then(function (events) { }).then(events => {
expect(events.length).to.equal(2); expect(events.length).to.equal(2);
expect(events[0].get('data')).to.eql({ expect(events[0].get('data')).to.eql({
...@@ -312,10 +311,10 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -312,10 +311,10 @@ describe(Support.getTestDialectTeaser('Model'), function() {
}); });
it('should be possible to destroy with where', function () { it('should be possible to destroy with where', function () {
var conditionSearch = { const conditionSearch = {
where: { where: {
data: { data: {
employment : 'Hacker' employment: 'Hacker'
} }
} }
}; };
...@@ -348,15 +347,72 @@ describe(Support.getTestDialectTeaser('Model'), function() { ...@@ -348,15 +347,72 @@ describe(Support.getTestDialectTeaser('Model'), function() {
employment: 'CTO' employment: 'CTO'
} }
}) })
).bind(this).then(function () { ).then(() => {
return expect(this.Event.findAll(conditionSearch)).to.eventually.have.length(2); return expect(this.Event.findAll(conditionSearch)).to.eventually.have.length(2);
}).then(function() { }).then(() => {
return this.Event.destroy(conditionSearch); return this.Event.destroy(conditionSearch);
}).then(function(){ }).then(() => {
return expect(this.Event.findAll(conditionSearch)).to.eventually.have.length(0); return expect(this.Event.findAll(conditionSearch)).to.eventually.have.length(0);
}); });
}); });
describe('sql injection attacks', function () {
beforeEach(function () {
this.Model = this.sequelize.define('Model', {
data: DataTypes.JSON
});
return this.sequelize.sync({ force: true });
});
it('should properly escape the single quotes', function () {
return this.Model.create({
data: {
type: 'Point',
properties: {
exploit: "'); DELETE YOLO INJECTIONS; -- "
}
}
});
});
it('should properly escape the single quotes in array', function () {
return this.Model.create({
data: {
type: 'Point',
coordinates: [39.807222, "'); DELETE YOLO INJECTIONS; --"]
}
});
});
it('should be possible to find with properly escaped select query', function () {
return this.Model.create({
data: {
type: 'Point',
properties: {
exploit: "'); DELETE YOLO INJECTIONS; -- "
},
}
}).then(() => {
return this.Model.findOne({
where: {
data: {
type: 'Point',
properties: {
exploit: "'); DELETE YOLO INJECTIONS; -- "
},
}
}
});
}).then(result => {
expect(result.get('data')).to.deep.equal({
type: 'Point',
properties: {
exploit: "'); DELETE YOLO INJECTIONS; -- "
}
});
});
});
});
}); });
} }
}); });
...@@ -196,13 +196,13 @@ describe(Support.getTestDialectTeaser('Utils'), function() { ...@@ -196,13 +196,13 @@ describe(Support.getTestDialectTeaser('Utils'), function() {
}, },
another_json_field: { x: 1 } another_json_field: { x: 1 }
}; };
var expected = `"metadata"#>>'{language}' = 'icelandic' and "metadata"#>>'{pg_rating,dk}' = 'G' and "another_json_field"#>>'{x}' = '1'`; var expected = `("metadata"#>>'{language}') = 'icelandic' AND ("metadata"#>>'{pg_rating,dk}') = 'G' AND ("another_json_field"#>>'{x}') = '1'`;
expect(queryGenerator.handleSequelizeMethod(new Utils.Json(conditions))).to.deep.equal(expected); expect(queryGenerator.handleSequelizeMethod(new Utils.Json(conditions))).to.deep.equal(expected);
}); });
it('successfully parses a string using dot notation', function() { it('successfully parses a string using dot notation', function() {
var path = 'metadata.pg_rating.dk'; var path = 'metadata.pg_rating.dk';
expect(queryGenerator.handleSequelizeMethod(new Utils.Json(path))).to.equal(`"metadata"#>>'{pg_rating,dk}'`); expect(queryGenerator.handleSequelizeMethod(new Utils.Json(path))).to.equal(`("metadata"#>>'{pg_rating,dk}')`);
}); });
it('allows postgres json syntax', function() { it('allows postgres json syntax', function() {
...@@ -213,7 +213,7 @@ describe(Support.getTestDialectTeaser('Utils'), function() { ...@@ -213,7 +213,7 @@ describe(Support.getTestDialectTeaser('Utils'), function() {
it('can take a value to compare against', function() { it('can take a value to compare against', function() {
var path = 'metadata.pg_rating.is'; var path = 'metadata.pg_rating.is';
var value = 'U'; var value = 'U';
expect(queryGenerator.handleSequelizeMethod(new Utils.Json(path, value))).to.equal(`"metadata"#>>'{pg_rating,is}' = 'U'`); expect(queryGenerator.handleSequelizeMethod(new Utils.Json(path, value))).to.equal(`("metadata"#>>'{pg_rating,is}') = 'U'`);
}); });
}); });
} }
......
...@@ -200,9 +200,13 @@ var Support = { ...@@ -200,9 +200,13 @@ var Support = {
var expectation = expectations[Support.sequelize.dialect.name]; var expectation = expectations[Support.sequelize.dialect.name];
if (!expectation) { if (!expectation) {
expectation = expectations['default'] if (expectations['default'] !== undefined) {
.replace(/\[/g, Support.sequelize.dialect.TICK_CHAR_LEFT) expectation = expectations['default']
.replace(/\]/g, Support.sequelize.dialect.TICK_CHAR_RIGHT); .replace(/\[/g, Support.sequelize.dialect.TICK_CHAR_LEFT)
.replace(/\]/g, Support.sequelize.dialect.TICK_CHAR_RIGHT);
} else {
throw new Error('Undefined expectation for "' + Support.sequelize.dialect.name + '"!');
}
} }
if (_.isError(query)) { if (_.isError(query)) {
......
...@@ -128,7 +128,7 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -128,7 +128,7 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
}); });
} }
if (current.dialect.supports.JSON) { if (current.dialect.supports.JSONB) {
test('operator', function () { test('operator', function () {
expectsql(sql.addIndexQuery('table', { expectsql(sql.addIndexQuery('table', {
fields: ['event'], fields: ['event'],
......
'use strict'; 'use strict';
var Support = require(__dirname + '/../support') /*jshint -W110 */
const Support = require(__dirname + '/../support')
, DataTypes = require(__dirname + '/../../../lib/data-types') , DataTypes = require(__dirname + '/../../../lib/data-types')
, expect = require('chai').expect
, expectsql = Support.expectsql , expectsql = Support.expectsql
, current = Support.sequelize , Sequelize = Support.Sequelize
, sql = current.dialect.QueryGenerator , current = Support.sequelize
, current = Support.sequelize; , sql = current.dialect.QueryGenerator;
// Notice: [] will be replaced by dialect specific tick/quote character when there is not dialect specific expectation but only a default expectation // Notice: [] will be replaced by dialect specific tick/quote character when there is not dialect specific expectation but only a default expectation
if (current.dialect.supports.JSON) { if (current.dialect.supports.JSON) {
suite(Support.getTestDialectTeaser('SQL'), function() { suite(Support.getTestDialectTeaser('SQL'), function () {
suite('JSON', function () { suite('JSON', function () {
suite('escape', function () { suite('escape', function () {
test('plain string', function () { test('plain string', function () {
...@@ -49,24 +51,104 @@ if (current.dialect.supports.JSON) { ...@@ -49,24 +51,104 @@ if (current.dialect.supports.JSON) {
}); });
}); });
test('array of JSON', function () { if (current.dialect.supports.ARRAY) {
expectsql(sql.escape([ test('array of JSON', function () {
{ some: 'nested', more: { nested: true }, answer: 42 }, expectsql(sql.escape([
43, { some: 'nested', more: { nested: true }, answer: 42 },
'joe' 43,
], { type: DataTypes.ARRAY(DataTypes.JSON)}), { 'joe'
postgres: 'ARRAY[\'{"some":"nested","more":{"nested":true},"answer":42}\',\'43\',\'"joe"\']::JSON[]' ], { type: DataTypes.ARRAY(DataTypes.JSON) }), {
postgres: 'ARRAY[\'{"some":"nested","more":{"nested":true},"answer":42}\',\'43\',\'"joe"\']::JSON[]'
});
});
if (current.dialect.supports.JSONB) {
test('array of JSONB', function () {
expectsql(sql.escape([
{ some: 'nested', more: { nested: true }, answer: 42 },
43,
'joe'
], { type: DataTypes.ARRAY(DataTypes.JSONB) }), {
postgres: 'ARRAY[\'{"some":"nested","more":{"nested":true},"answer":42}\',\'43\',\'"joe"\']::JSONB[]'
});
});
}
}
});
suite('path extraction', function () {
test('condition object', function () {
expectsql(sql.whereItemQuery(undefined, Sequelize.json({ id: 1 })), {
postgres: `("id"#>>'{}') = '1'`,
sqlite: "json_extract(`id`, '$') = '1'"
});
});
test('nested condition object', function () {
expectsql(sql.whereItemQuery(undefined, Sequelize.json({ profile: { id: 1 } })), {
postgres: `("profile"#>>'{id}') = '1'`,
sqlite: "json_extract(`profile`, '$.id') = '1'"
});
});
test('multiple condition object', function () {
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'"
});
});
test('dot notaion', function () {
expectsql(sql.whereItemQuery(Sequelize.json('profile.id'), '1'), {
postgres: `("profile"#>>'{id}') = '1'`,
sqlite: "json_extract(`profile`, '$.id') = '1'"
});
});
test('column named "json"', function () {
expectsql(sql.whereItemQuery(Sequelize.json('json'), '{}'), {
postgres: `("json"#>>'{}') = '{}'`,
sqlite: "json_extract(`json`, '$') = '{}'"
});
});
});
suite('raw json query', function () {
if (current.dialect.name === 'postgres') {
test('#>> operator', function () {
expectsql(sql.whereItemQuery(Sequelize.json(`("data"#>>'{id}')`), 'id'), {
postgres: `("data"#>>'{id}') = 'id'`
});
});
}
test('json function', function () {
expectsql(sql.handleSequelizeMethod(Sequelize.json(`json('{"profile":{"name":"david"}}')`)), {
default: `json('{"profile":{"name":"david"}}')`
}); });
}); });
test('array of JSONB', function () {
expectsql(sql.escape([ test('nested json functions', function () {
{ some: 'nested', more: { nested: true }, answer: 42 }, expectsql(sql.handleSequelizeMethod(Sequelize.json(`json_extract(json_object('{"profile":null}'), "profile")`)), {
43, default: `json_extract(json_object('{"profile":null}'), "profile")`
'joe'
], { type: DataTypes.ARRAY(DataTypes.JSONB)}), {
postgres: 'ARRAY[\'{"some":"nested","more":{"nested":true},"answer":42}\',\'43\',\'"joe"\']::JSONB[]'
}); });
}); });
test('escaped string argument', function () {
expectsql(sql.handleSequelizeMethod(Sequelize.json(`json('{"quote":{"single":"''","double":""""},"parenthesis":"())("}')`)), {
default: `json('{"quote":{"single":"''","double":""""},"parenthesis":"())("}')`
});
});
test(`unbalnced statement`, function () {
expect(() => sql.handleSequelizeMethod(Sequelize.json('json())'))).to.throw();
expect(() => sql.handleSequelizeMethod(Sequelize.json('json_extract(json()'))).to.throw();
});
test('separator injection', function () {
expect(() => sql.handleSequelizeMethod(Sequelize.json('json(; DELETE YOLO INJECTIONS; -- )'))).to.throw();
expect(() => sql.handleSequelizeMethod(Sequelize.json('json(); DELETE YOLO INJECTIONS; -- '))).to.throw();
});
}); });
}); });
}); });
......
...@@ -717,9 +717,10 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -717,9 +717,10 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
if (current.dialect.supports.JSON) { if (current.dialect.supports.JSON) {
suite('JSON', function () { suite('JSON', function () {
test('sequelize.json("profile->>\'id\', sequelize.cast(2, \'text\')")', function () { test('sequelize.json("profile.id"), sequelize.cast(2, \'text\')")', function () {
expectsql(sql.whereItemQuery(undefined, this.sequelize.json("profile->>'id'", this.sequelize.cast('12346-78912', 'text'))), { expectsql(sql.whereItemQuery(undefined, this.sequelize.json("profile.id", this.sequelize.cast('12346-78912', 'text'))), {
postgres: "profile->>'id' = CAST('12346-78912' AS TEXT)" postgres: "(\"profile\"#>>'{id}') = CAST('12346-78912' AS TEXT)",
sqlite: "json_extract(`profile`, '$.id') = CAST('12346-78912' AS TEXT)"
}); });
}); });
...@@ -733,7 +734,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -733,7 +734,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
}, },
prefix: 'User' prefix: 'User'
}, { }, {
default: "([User].[data]#>>'{nested, attribute}') = 'value'" postgres: "(\"User\".\"data\"#>>'{nested,attribute}') = 'value'",
sqlite: "json_extract(`User`.`data`, '$.nested.attribute') = 'value'"
}); });
testsql('data', { testsql('data', {
...@@ -749,7 +751,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -749,7 +751,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
}, },
prefix: 'User' prefix: 'User'
}, { }, {
default: "(([User].[data]#>>'{nested, attribute}') = 'value' AND ([User].[data]#>>'{nested, prop}') != 'None')" postgres: "((\"User\".\"data\"#>>'{nested,attribute}') = 'value' AND (\"User\".\"data\"#>>'{nested,prop}') != 'None')",
sqlite: "(json_extract(`User`.`data`, '$.nested.attribute') = 'value' AND json_extract(`User`.`data`, '$.nested.prop') != 'None')"
}); });
testsql('data', { testsql('data', {
...@@ -765,7 +768,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -765,7 +768,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
}, },
prefix: 'User' prefix: 'User'
}, { }, {
default: "(([User].[data]#>>'{name, last}') = 'Simpson' AND ([User].[data]#>>'{employment}') != 'None')" postgres: "((\"User\".\"data\"#>>'{name,last}') = 'Simpson' AND (\"User\".\"data\"#>>'{employment}') != 'None')",
sqlite: "(json_extract(`User`.`data`, '$.name.last') = 'Simpson' AND json_extract(`User`.`data`, '$.employment') != 'None')"
}); });
testsql('data.nested.attribute', 'value', { testsql('data.nested.attribute', 'value', {
...@@ -777,19 +781,21 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -777,19 +781,21 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
} }
} }
}, { }, {
default: "([data]#>>'{nested, attribute}') = 'value'" postgres: "(\"data\"#>>'{nested,attribute}') = 'value'",
sqlite: "json_extract(`data`, '$.nested.attribute') = 'value'"
}); });
testsql('data.nested.attribute', 4, { testsql('data.nested.attribute', 4, {
model: { model: {
rawAttributes: { rawAttributes: {
data: { data: {
type: new DataTypes.JSONB() type: new DataTypes.JSON()
} }
} }
} }
}, { }, {
default: "([data]#>>'{nested, attribute}')::double precision = 4" postgres: "CAST((\"data\"#>>'{nested,attribute}') AS DOUBLE PRECISION) = 4",
sqlite: "CAST(json_extract(`data`, '$.nested.attribute') AS DOUBLE PRECISION) = 4"
}); });
testsql('data.nested.attribute', { testsql('data.nested.attribute', {
...@@ -803,7 +809,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -803,7 +809,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
} }
} }
}, { }, {
default: "([data]#>>'{nested, attribute}') IN (3, 7)" postgres: "(\"data\"#>>'{nested,attribute}') IN (3, 7)",
sqlite: "json_extract(`data`, '$.nested.attribute') IN (3, 7)"
}); });
testsql('data', { testsql('data', {
...@@ -817,7 +824,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -817,7 +824,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
type: new DataTypes.JSONB() type: new DataTypes.JSONB()
} }
}, { }, {
default: "([data]#>>'{nested, attribute}')::double precision > 2" postgres: "CAST((\"data\"#>>'{nested,attribute}') AS DOUBLE PRECISION) > 2",
sqlite: "CAST(json_extract(`data`, '$.nested.attribute') AS DOUBLE PRECISION) > 2"
}); });
testsql('data', { testsql('data', {
...@@ -831,7 +839,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -831,7 +839,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
type: new DataTypes.JSONB() type: new DataTypes.JSONB()
} }
}, { }, {
default: "([data]#>>'{nested, attribute}')::integer > 2" postgres: "CAST((\"data\"#>>'{nested,attribute}') AS INTEGER) > 2",
sqlite: "CAST(json_extract(`data`, '$.nested.attribute') AS INTEGER) > 2"
}); });
var dt = new Date(); var dt = new Date();
...@@ -846,7 +855,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -846,7 +855,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
type: new DataTypes.JSONB() type: new DataTypes.JSONB()
} }
}, { }, {
default: "([data]#>>'{nested, attribute}')::timestamptz > "+sql.escape(dt) postgres: "CAST((\"data\"#>>'{nested,attribute}') AS TIMESTAMPTZ) > "+sql.escape(dt),
sqlite: "CAST(json_extract(`data`, '$.nested.attribute') AS DATETIME) > "+sql.escape(dt)
}); });
testsql('data', { testsql('data', {
...@@ -858,19 +868,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -858,19 +868,8 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
type: new DataTypes.JSONB() type: new DataTypes.JSONB()
} }
}, { }, {
default: "([data]#>>'{nested, attribute}')::boolean = true" postgres: "CAST((\"data\"#>>'{nested,attribute}') AS BOOLEAN) = true",
}); sqlite: "CAST(json_extract(`data`, '$.nested.attribute') AS BOOLEAN) = 1"
testsql('data', {
$contains: {
company: 'Magnafone'
}
}, {
field: {
type: new DataTypes.JSONB()
}
}, {
default: '[data] @> \'{"company":"Magnafone"}\''
}); });
testsql('metaData.nested.attribute', 'value', { testsql('metaData.nested.attribute', 'value', {
...@@ -884,7 +883,24 @@ suite(Support.getTestDialectTeaser('SQL'), function() { ...@@ -884,7 +883,24 @@ suite(Support.getTestDialectTeaser('SQL'), function() {
} }
} }
}, { }, {
default: "([meta_data]#>>'{nested, attribute}') = 'value'" postgres: "(\"meta_data\"#>>'{nested,attribute}') = 'value'",
sqlite: "json_extract(`meta_data`, '$.nested.attribute') = 'value'"
});
});
}
if (current.dialect.supports.JSONB) {
suite('JSONB', function () {
testsql('data', {
$contains: {
company: 'Magnafone'
}
}, {
field: {
type: new DataTypes.JSONB()
}
}, {
default: '[data] @> \'{"company":"Magnafone"}\''
}); });
}); });
} }
......
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!