Advanced queries for sql-s and mongodb

This commit is contained in:
Anatoliy Chakkaev 2012-02-01 21:33:08 +04:00
parent e9f35fd7fd
commit fb79ca2bf8
5 changed files with 166 additions and 5 deletions

View File

@ -120,7 +120,21 @@ MongooseAdapter.prototype.all = function all(model, filter, callback) {
var query = this._models[model].find({});
if (filter.where) {
Object.keys(filter.where).forEach(function (k) {
query.where(k, filter.where[k]);
var cond = filter.where[k];
var spec = false;
if (cond && cond.constructor.name === 'Object') {
spec = Object.keys(cond)[0];
cond = cond[spec];
}
if (spec) {
if (spec === 'between') {
query.where(k).gte(cond[0]).lte(cond[1]);
} else {
query.where(k)[spec](cond);
}
} else {
query.where(k, cond);
}
});
}
if (filter.order) {

View File

@ -96,8 +96,17 @@ function dateToMysql(val) {
}
MySQL.prototype.toDatabase = function (prop, val) {
if (prop.type.name === 'Number') return val;
if (val === null) return 'NULL';
if (val.constructor.name === 'Object') {
var operator = Object.keys(val)[0]
val = val[operator];
if (operator === 'between') {
return this.toDatabase(prop, val[0]) +
' AND ' +
this.toDatabase(prop, val[1]);
}
}
if (prop.type.name === 'Number') return val;
if (prop.type.name === 'Date') {
if (!val) return 'NULL';
if (!val.toUTCString) {
@ -188,10 +197,33 @@ MySQL.prototype.all = function all(model, filter, callback) {
var cs = [];
Object.keys(conds).forEach(function (key) {
var keyEscaped = '`' + key.replace(/\./g, '`.`') + '`'
var val = self.toDatabase(props[key], conds[key]);
if (conds[key] === null) {
cs.push(keyEscaped + ' IS NULL');
} else if (conds[key].constructor.name === 'Object') {
var condType = Object.keys(conds[key])[0];
var sqlCond = keyEscaped;
switch (condType) {
case 'gt':
sqlCond += ' > ';
break;
case 'gte':
sqlCond += ' >= ';
break;
case 'lt':
sqlCond += ' < ';
break;
case 'lte':
sqlCond += ' <= ';
break;
case 'between':
sqlCond += ' BETWEEN ';
break;
}
sqlCond += val;
cs.push(sqlCond);
} else {
cs.push(keyEscaped + ' = ' + self.toDatabase(props[key], conds[key]));
cs.push(keyEscaped + ' = ' + val);
}
});
return 'WHERE ' + cs.join(' AND ');

View File

@ -116,6 +116,13 @@ function dateToPostgres(val) {
PG.prototype.toDatabase = function (prop, val) {
if (val === null) return 'NULL';
if (val.constructor.name === 'Object') {
var operator = Object.keys(val)[0]
val = val[operator];
if (operator === 'between') {
return this.toDatabase(prop, val[0]) + ' AND ' + this.toDatabase(prop, val[1]);
}
}
if (prop.type.name === 'Number') return val;
if (prop.type.name === 'Date') {
if (!val) return 'NULL';
@ -187,7 +194,8 @@ PG.prototype.toFilter = function (model, filter) {
var out = '';
if (filter.where) {
var fields = [];
Object.keys(filter.where).forEach(function (key) {
var conds = filter.where;
Object.keys(conds).forEach(function (key) {
if (filter.where[key] && filter.where[key].constructor.name === 'RegExp') {
return;
}
@ -195,6 +203,28 @@ PG.prototype.toFilter = function (model, filter) {
var filterValue = this.toDatabase(props[key], filter.where[key]);
if (filterValue === 'NULL') {
fields.push('"' + key + '" IS ' + filterValue);
} else if (conds[key].constructor.name === 'Object') {
var condType = Object.keys(conds[key])[0];
var sqlCond = key;
switch (condType) {
case 'gt':
sqlCond += ' > ';
break;
case 'gte':
sqlCond += ' >= ';
break;
case 'lt':
sqlCond += ' < ';
break;
case 'lte':
sqlCond += ' <= ';
break;
case 'between':
sqlCond += ' BETWEEN ';
break;
}
sqlCond += filterValue;
fields.push(sqlCond);
} else {
fields.push('"' + key + '" = ' + filterValue);
}

View File

@ -211,6 +211,33 @@ SQLite3.prototype.all = function all(model, filter, callback) {
var keyEscaped = '`' + key.replace(/\./g, '`.`') + '`'
if (conds[key] === null) {
cs.push(keyEscaped + ' IS NULL');
} else if (conds[key].constructor.name === 'Object') {
var condType = Object.keys(conds[key])[0];
var sqlCond = keyEscaped;
switch (condType) {
case 'gt':
sqlCond += ' > ';
break;
case 'gte':
sqlCond += ' >= ';
break;
case 'lt':
sqlCond += ' < ';
break;
case 'lte':
sqlCond += ' <= ';
break;
case 'between':
sqlCond += ' BETWEEN ? AND ?';
queryParams.push(conds[key][condType][0]);
queryParams.push(conds[key][condType][1]);
break;
}
if (condType !== 'between') {
sqlCond += '?';
queryParams.push(conds[key][condType]);
}
cs.push(sqlCond);
} else {
cs.push(keyEscaped + ' = ?');
queryParams.push(self.toDatabase(props[key], conds[key]));

View File

@ -36,7 +36,9 @@ Object.keys(schemas).forEach(function (schemaName) {
if (process.env.EXCEPT && ~process.env.EXCEPT.indexOf(schemaName)) return;
context(schemaName, function () {
var schema = new Schema(schemaName, schemas[schemaName]);
// schema.log = console.log;
schema.log = function (a) {
console.log(a);
};
testOrm(schema);
if (specificTest[schemaName]) specificTest[schemaName](schema);
});
@ -525,6 +527,62 @@ function testOrm(schema) {
});
it('should allow advanced queying: lt, gt, lte, gte, between', function (test) {
Post.destroyAll(function () {
Post.create({date: new Date('Wed, 01 Feb 2012 13:56:12 GMT')}, done);
Post.create({date: new Date('Thu, 02 Feb 2012 13:56:12 GMT')}, done);
Post.create({date: new Date('Fri, 03 Feb 2012 13:56:12 GMT')}, done);
Post.create({date: new Date('Sat, 04 Feb 2012 13:56:12 GMT')}, done);
Post.create({date: new Date('Sun, 05 Feb 2012 13:56:12 GMT')}, done);
Post.create({date: new Date('Mon, 06 Feb 2012 13:56:12 GMT')}, done);
Post.create({date: new Date('Tue, 07 Feb 2012 13:56:12 GMT')}, done);
Post.create({date: new Date('Wed, 08 Feb 2012 13:56:12 GMT')}, done);
Post.create({date: new Date('Thu, 09 Feb 2012 13:56:12 GMT')}, done);
});
var posts = 9;
function done() {
if (--posts === 0) makeTest();
}
function makeTest() {
// gt
Post.all({where: {date: {gt: new Date('Tue, 07 Feb 2012 13:56:12 GMT')}}}, function (err, posts) {
test.equal(posts.length, 2);
ok();
});
// gte
Post.all({where: {date: {gte: new Date('Tue, 07 Feb 2012 13:56:12 GMT')}}}, function (err, posts) {
test.equal(posts.length, 3);
ok();
});
// lte
Post.all({where: {date: {lte: new Date('Tue, 07 Feb 2012 13:56:12 GMT')}}}, function (err, posts) {
test.equal(posts.length, 7);
ok();
});
// lt
Post.all({where: {date: {lt: new Date('Tue, 07 Feb 2012 13:56:12 GMT')}}}, function (err, posts) {
test.equal(posts.length, 6);
ok();
});
// between
Post.all({where: {date: {between: [new Date('Tue, 05 Feb 2012 13:56:12 GMT'), new Date('Tue, 09 Feb 2012 13:56:12 GMT')]}}}, function (err, posts) {
test.equal(posts.length, 5);
ok();
});
}
var tests = 5;
function ok() {
if (--tests === 0) test.done();
}
});
it('all tests done', function (test) {
test.done();
process.nextTick(allTestsDone);