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

Commit 2965c048 by Mick Hansen

Merge pull request #2314 from sveinnfannar/feature/postgresql-json-support

Rough implementation of PostgreSQL JSON support
2 parents 47c03431 15f2b412
......@@ -42,3 +42,6 @@ matrix:
allow_failures:
- node_js: "0.10"
env: COVERAGE=true
addons:
postgresql: "9.3"
\ No newline at end of file
/*
Title: PostgreSQL JSON Data-Type
An example of using PostgreSQL's JSON data-type.
In this example we create a single table that can handle multiple types of different media and it's metadata.
This example uses the promise API preferred in 2.0 and above.
*/
var Sequelize = require(__dirname + "/../../index")
, config = require(__dirname + "/../../test/config/config")
, sequelize = new Sequelize(config.postgres.database, config.postgres.username, config.postgres.password, {
dialect: 'postgres',
logging: false
});
var Content = sequelize.define('Content', {
title: { type: Sequelize.STRING },
type: { type: Sequelize.STRING },
metadata: { type: Sequelize.JSON }
})
, movie = Content.build({
title: 'Grave of the Fireflies',
type: 'Movie',
metadata: {
director: 'Isao Takahata',
language: 'Japanese',
year: 1988
}
})
, episode = Content.build({
title: 'Chapter 3',
type: 'Episode',
metadata: {
season: 1,
episode: 3,
language: 'English',
seriesTitle: 'House of Cards',
genres: ['Drama', 'Political thriller']
}
});
sequelize.sync({ force: true })
.then(function() {
return sequelize.Promise.all([
movie.save(),
episode.save()
]);
})
.then(function() {
console.log('=====================================');
console.log('Searching for any content in Japanese');
console.log('-------------------------------------');
// Using nested object query syntax
return Content.find({ where: Sequelize.json({ metadata: { language: 'Japanese' } }) })
.then(function(content) {
console.log('Result:', content.dataValues);
console.log('=====================================');
})
})
.then(function() {
console.log('=====================================');
console.log('Searching for any content in English');
console.log('-------------------------------------');
// Using the postgres json syntax
return Content.find({ where: Sequelize.json("metadata->>'language'", 'English') })
.then(function(content) {
console.log('Result:', content.dataValues);
console.log('=====================================');
})
})
.then(function() {
console.log('===========================================');
console.log('Searching for series named "House of Cards"');
console.log('-------------------------------------------');
return Content.find({ where: Sequelize.json('metadata.seriesTitle', 'House of Cards') })
.then(function(content) {
console.log('Result:', content.dataValues);
console.log('===========================================');
})
});
\ No newline at end of file
......@@ -404,6 +404,11 @@ module.exports = {
HSTORE: 'HSTORE',
/**
* A JSON string column. Only available in postgres.
*/
JSON: 'JSON',
/**
* A virtual value that is not stored in the DB. This could for example be useful if you want to provide a default value in your model
* that is returned to the user but not stored in the DB.
*
......
......@@ -1267,6 +1267,8 @@ module.exports = (function() {
result = (value === 'NULL') ? key + ' IS NULL' : [key, value].join('=');
}
} else if (smth instanceof Utils.json) {
result = smth.toString(this);
} else if (Utils._.isPlainObject(smth)) {
if (prepend) {
if (tableName) options.keysEscaped = true;
......
......@@ -776,6 +776,7 @@ module.exports = (function() {
quoteIdentifier: function(identifier, force) {
var _ = Utils._;
if (identifier === '*') return identifier;
if (!force && this.options && this.options.quoteIdentifiers === false) { // default is `true`
// In Postgres, if tables or attributes are created double-quoted,
......@@ -799,6 +800,8 @@ module.exports = (function() {
if (Utils._.isObject(value) && field && (field.type === DataTypes.HSTORE || field.type === DataTypes.ARRAY(DataTypes.HSTORE))) {
value = hstore.stringify(value);
} else if (Utils._.isObject(value) && field && (field.type === DataTypes.JSON)) {
value = JSON.stringify(value);
}
return SqlString.escape(value, false, this.options.timezone, this.dialect, field);
......
......@@ -247,6 +247,7 @@ module.exports = (function() {
this._booleanAttributes = [];
this._dateAttributes = [];
this._hstoreAttributes = [];
this._jsonAttributes = [];
this._virtualAttributes = [];
this._defaultValues = {};
this.Instance.prototype.validators = {};
......@@ -260,6 +261,8 @@ module.exports = (function() {
self._dateAttributes.push(name);
} else if (type === DataTypes.HSTORE) {
self._hstoreAttributes.push(name);
} else if (type === DataTypes.JSON) {
self._jsonAttributes.push(name);
} else if (type === DataTypes.VIRTUAL) {
self._virtualAttributes.push(name);
}
......@@ -289,6 +292,11 @@ module.exports = (function() {
return self._hstoreAttributes.indexOf(key) !== -1;
});
this._hasJsonAttributes = !!this._jsonAttributes.length;
this._isJsonAttribute = Utils._.memoize(function(key) {
return self._jsonAttributes.indexOf(key) !== -1;
});
this._hasVirtualAttributes = !!this._virtualAttributes.length;
this._isVirtualAttribute = Utils._.memoize(function(key) {
return self._virtualAttributes.indexOf(key) !== -1;
......
......@@ -866,6 +866,19 @@ module.exports = (function() {
return new Utils.or(Array.prototype.slice.call(arguments));
};
/**
* Creates an object representing nested where conditions for postgres's json data-type.
* @see {Model#find}
*
* @method json
* @param {String|Object} conditions A hash containing strings/numbers or other nested hash, a string using dot notation or a string using postgres json syntax.
* @param {String|Number|Boolean} [value] An optional value to compare against. Produces a string of the form "<json path> = '<value>'".
* @return {Sequelize.json}
*/
Sequelize.json = Sequelize.prototype.json = function (conditionsOrPath, value) {
return new Utils.json(conditionsOrPath, value);
};
/*
* A way of specifying attr = condition. Mostly used internally
* @see {Model#find}
......
......@@ -547,6 +547,17 @@ var Utils = module.exports = {
this.args = args;
},
json: function(conditionsOrPath, value) {
if (Utils._.isObject(conditionsOrPath)) {
this.conditions = conditionsOrPath;
} else {
this.path = conditionsOrPath;
if (value) {
this.value = value;
}
}
},
where: function(attribute, logic) {
this.attribute = attribute;
this.logic = logic;
......@@ -572,7 +583,8 @@ Utils.where.prototype._isSequelizeMethod =
Utils.literal.prototype._isSequelizeMethod =
Utils.cast.prototype._isSequelizeMethod =
Utils.fn.prototype._isSequelizeMethod =
Utils.col.prototype._isSequelizeMethod = true;
Utils.col.prototype._isSequelizeMethod =
Utils.json.prototype._isSequelizeMethod = true;
// I know this may seem silly, but this gives us the ability to recognize whether
// or not we should be escaping or if we should trust the user. Basically, it
......@@ -613,6 +625,54 @@ Utils.col.prototype.toString = function(queryGenerator, parentModel) {
return queryGenerator.quote(this.col, parentModel);
};
Utils.json.prototype.toString = function (queryGenerator) {
var _ = Utils._;
// A recursive parser for nested where conditions
function parseConditionObject(_conditions, path) {
path = path || [];
return _.reduce(_conditions, function (r, v, k) { // result, key, value
if (_.isObject(v)) {
r = r.concat(parseConditionObject(v, path.concat(k))); // Recursively parse objects
} else {
r.push({ path: path.concat(k), value: v });
}
return r;
}, []);
}
// Parse nested object
if (this.conditions) {
var conditions = _.map(parseConditionObject(this.conditions), function generateSql(condition) {
// TODO: Move this postgres specific logic to a more appropriate place
return util.format("%s#>>'{%s}' = '%s'",
_.first(condition.path),
_.rest(condition.path).join(','),
condition.value);
});
return conditions.join(' and ');
} else if (this.path) {
var str;
// Allow specifying conditions using the postgres json syntax
if (_.any(['->', '->>', '#>'], _.partial(_.contains, this.path))) { // TODO: Move postgres stuff somewhere else
str = this.path;
} else {
// Also support json dot notation
var path = this.path.split('.');
str = util.format("%s#>>'{%s}'",
_.first(path),
_.rest(path).join(','));
}
if (this.value) {
str += util.format(" = %s", queryGenerator.escape(this.value));
}
return str;
}
};
Utils.CustomEventEmitter = require(__dirname + '/emitters/custom-event-emitter');
Utils.Promise = require(__dirname + '/promise');
Utils.QueryChainer = require(__dirname + '/query-chainer');
......@@ -4,6 +4,7 @@ var chai = require('chai')
, dialect = Support.getTestDialect()
, DataTypes = require(__dirname + "/../../lib/data-types")
, _ = require('lodash')
, sequelize = require(__dirname + '/../../lib/sequelize');
chai.config.includeStack = true
......@@ -16,7 +17,8 @@ if (dialect.match(/^postgres/)) {
email: { type: DataTypes.ARRAY(DataTypes.TEXT) },
settings: DataTypes.HSTORE,
document: { type: DataTypes.HSTORE, defaultValue: { default: 'value' } },
phones: DataTypes.ARRAY(DataTypes.HSTORE)
phones: DataTypes.ARRAY(DataTypes.HSTORE),
emergency_contact: DataTypes.JSON
})
this.User.sync({ force: true }).success(function() {
done()
......@@ -31,7 +33,7 @@ if (dialect.match(/^postgres/)) {
it('should be able to search within an array', function(done) {
this.User.all({where: {email: ['hello', 'world']}}).on('sql', function(sql) {
expect(sql).to.equal('SELECT "id", "username", "email", "settings", "document", "phones", "createdAt", "updatedAt" FROM "Users" AS "User" WHERE "User"."email" && ARRAY[\'hello\',\'world\']::TEXT[];')
expect(sql).to.equal('SELECT "id", "username", "email", "settings", "document", "phones", "emergency_contact", "createdAt", "updatedAt" FROM "Users" AS "User" WHERE "User"."email" && ARRAY[\'hello\',\'world\']::TEXT[];')
done()
})
})
......@@ -51,6 +53,131 @@ if (dialect.match(/^postgres/)) {
})
})
describe('json', function () {
it('should tell me that a column is json', function() {
return this.sequelize.queryInterface.describeTable('Users')
.then(function (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] }
}).on('sql', function (sql) {
var expected = 'INSERT INTO "Users" ("id","username","document","emergency_contact","createdAt","updatedAt") VALUES (DEFAULT,\'bob\',\'"default"=>"value"\',\'{"name":"joe","phones":[1337,42]}\''
expect(sql.indexOf(expected)).to.equal(0);
});
});
it('should be able retrieve json value as object', function () {
var self = this;
var emergencyContact = { name: 'kate', phone: 1337 };
return this.User.create({ username: 'swen', emergency_contact: emergencyContact })
.then(function (user) {
expect(user.emergency_contact).to.eql(emergencyContact); // .eql does deep value comparison instead of strict equal comparison
return self.User.find({ where: { username: 'swen' }, attributes: ['emergency_contact'] });
})
.then(function (user) {
expect(user.emergency_contact).to.eql(emergencyContact);
});
});
it('should be able to retrieve element of array by index', function () {
var self = this;
var emergencyContact = { name: 'kate', phones: [1337, 42] };
return this.User.create({ username: 'swen', emergency_contact: emergencyContact })
.then(function (user) {
expect(user.emergency_contact).to.eql(emergencyContact);
return self.User.find({ where: { username: 'swen' }, attributes: [[sequelize.json('emergency_contact.phones.1'), 'firstEmergencyNumber']] });
})
.then(function (user) {
expect(parseInt(user.getDataValue('firstEmergencyNumber'))).to.equal(42);
});
});
it('should be able to retrieve root level value of an object by key', function () {
var self = this;
var emergencyContact = { kate: 1337 };
return this.User.create({ username: 'swen', emergency_contact: emergencyContact })
.then(function (user) {
expect(user.emergency_contact).to.eql(emergencyContact);
return self.User.find({ where: { username: 'swen' }, attributes: [[sequelize.json('emergency_contact.kate'), 'katesNumber']] });
})
.then(function (user) {
expect(parseInt(user.getDataValue('katesNumber'))).to.equal(1337);
});
});
it('should be able to retrieve nested value of an object by path', function () {
var self = this;
var emergencyContact = { kate: { email: 'kate@kate.com', phones: [1337, 42] } };
return this.User.create({ username: 'swen', emergency_contact: emergencyContact })
.then(function (user) {
expect(user.emergency_contact).to.eql(emergencyContact);
return self.User.find({ where: { username: 'swen' }, attributes: [[sequelize.json('emergency_contact.kate.email'), 'katesEmail']] });
})
.then(function (user) {
expect(user.getDataValue('katesEmail')).to.equal('kate@kate.com');
})
.then(function () {
return self.User.find({ where: { username: 'swen' }, attributes: [[sequelize.json('emergency_contact.kate.phones.1'), 'katesFirstPhone']] });
})
.then(function (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 () {
var self = this;
return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergency_contact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergency_contact: { name: 'joe' } })])
.then(function () {
return self.User.find({ where: sequelize.json("emergency_contact->>'name'", 'kate'), attributes: ['username', 'emergency_contact'] });
})
.then(function (user) {
expect(user.emergency_contact.name).to.equal('kate');
});
});
it('should be able to query using the nested query language', function () {
var self = this;
return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergency_contact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergency_contact: { name: 'joe' } })])
.then(function () {
return self.User.find({
where: sequelize.json({ emergency_contact: { name: 'kate' } })
});
})
.then(function (user) {
expect(user.emergency_contact.name).to.equal('kate');
});
});
it('should be ablo to query using dot syntax', function () {
var self = this;
return this.sequelize.Promise.all([
this.User.create({ username: 'swen', emergency_contact: { name: 'kate' } }),
this.User.create({ username: 'anna', emergency_contact: { name: 'joe' } })])
.then(function () {
return self.User.find({ where: sequelize.json('emergency_contact.name', 'joe') });
})
.then(function (user) {
expect(user.emergency_contact.name).to.equal('joe');
});
});
});
describe('hstore', function() {
it('should tell me that a column is hstore and not USER-DEFINED', function(done) {
this.sequelize.queryInterface.describeTable('Users').success(function(table) {
......
......@@ -147,6 +147,38 @@ describe(Support.getTestDialectTeaser("Utils"), function() {
});
});
describe('json', function () {
var queryGeneratorStub = { escape: function (value) { return "'" + value + "'"; } };
it('successfully parses a complex nested condition hash', function() {
var conditions = {
metadata: {
language: 'icelandic',
pg_rating: { 'dk': 'G' }
},
another_json_field: { x: 1 }
};
var expected = "metadata#>>'{language}' = 'icelandic' and metadata#>>'{pg_rating,dk}' = 'G' and another_json_field#>>'{x}' = '1'";
expect((new Utils.json(conditions)).toString(queryGeneratorStub)).to.deep.equal(expected);
});
it('successfully parses a string using dot notation', function () {
var path = 'metadata.pg_rating.dk';
expect((new Utils.json(path)).toString(queryGeneratorStub)).to.equal("metadata#>>'{pg_rating,dk}'");
});
it('allows postgres json syntax', function () {
var path = 'metadata->pg_rating->>dk';
expect((new Utils.json(path)).toString(queryGeneratorStub)).to.equal(path);
});
it('can take a value to compare against', function () {
var path = 'metadata.pg_rating.is';
var value = 'U';
expect((new Utils.json(path, value)).toString(queryGeneratorStub)).to.equal("metadata#>>'{pg_rating,is}' = 'U'");
});
});
describe('inflection', function () {
it('works better than lingo ;)', function () {
expect(Utils.pluralize('buy')).to.equal('buys');
......
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!