Skip to content

Commit d912164

Browse files
committed
Add basic json query support
1 parent 3b85b0a commit d912164

File tree

3 files changed

+148
-0
lines changed

3 files changed

+148
-0
lines changed

README.md

Lines changed: 31 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -369,6 +369,37 @@ See [LoopBack types](http://loopback.io/doc/en/lb3/LoopBack-types.html) for de
369369

370370
For details, see the corresponding [driver issue](https://github.com/brianc/node-pg-types/issues/28).
371371

372+
## Querying JSON fields
373+
374+
**Note** The fields you are querying should be setup to use the JSON postgresql data type - see Defining models
375+
376+
Assuming a model such as this:
377+
378+
```json
379+
{
380+
"name": "Customer",
381+
"properties": {
382+
"address": {
383+
"type": "object",
384+
"postgresql": {
385+
"dataType": "json"
386+
}
387+
}
388+
}
389+
}
390+
```
391+
392+
You can query the nested fields with dot notation:
393+
394+
```javascript
395+
Customer.find({
396+
where: {
397+
'address.state': 'California'
398+
},
399+
order: 'address.city'
400+
})
401+
```
402+
372403
## Discovery and auto-migration
373404

374405
### Model discovery

lib/postgresql.js

Lines changed: 37 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -321,6 +321,37 @@ function escapeLiteral(str) {
321321
return escaped;
322322
}
323323

324+
/*
325+
* Check if a value is attempting to use nested json keys
326+
* @param {String} property The property being queried from where clause
327+
* @returns {Boolean} True of the property contains dots for nested json
328+
*/
329+
function isNested(property) {
330+
return property.split('.').length > 1;
331+
}
332+
333+
/*
334+
* Overwrite the loopback-connector column escape
335+
* to allow querying nested json keys
336+
* @param {String} model The model name
337+
* @param {String} property The property name
338+
* @returns {String} The escaped column name, or column with nested keys for deep json columns
339+
*/
340+
PostgreSQL.prototype.columnEscaped = function(model, property) {
341+
if (isNested(property)) {
342+
// Convert column to PostgreSQL json style query: "model"->>'val'
343+
var self = this;
344+
return property
345+
.split('.')
346+
.map(function(val, idx) { return (idx === 0 ? self.columnEscaped(model, val) : escapeLiteral(val)); })
347+
.reduce(function(prev, next, idx, arr) {
348+
return idx == 0 ? next : idx < arr.length - 1 ? prev + '->' + next : prev + '->>' + next;
349+
});
350+
} else {
351+
return this.escapeName(this.column(model, property));
352+
}
353+
};
354+
324355
/*!
325356
* Escape the name for PostgreSQL DB
326357
* @param {String} name The name
@@ -499,6 +530,12 @@ PostgreSQL.prototype._buildWhere = function(model, where) {
499530
// The value is not an array, fall back to regular fields
500531
}
501532
var p = props[key];
533+
534+
if (p == null && isNested(key)) {
535+
// See if we are querying nested json
536+
p = props[key.split('.')[0]];
537+
}
538+
502539
if (p == null) {
503540
// Unknown property, ignore it
504541
debug('Unknown property %s is skipped for model %s', key, model);

test/postgresql.test.js

Lines changed: 80 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -658,6 +658,86 @@ describe('postgresql connector', function() {
658658
});
659659
});
660660
});
661+
662+
context('json data type', function() {
663+
var Customer;
664+
665+
before(function(done) {
666+
db = getDataSource();
667+
668+
Customer = db.define('Customer', {
669+
address: {
670+
type: 'object',
671+
postgresql: {
672+
dataType: 'json',
673+
},
674+
},
675+
});
676+
677+
db.automigrate(function(err) {
678+
if (err) return done(err);
679+
Customer.create([{
680+
address: {
681+
city: 'Springfield',
682+
street: {
683+
number: 42,
684+
},
685+
},
686+
}, {
687+
address: {
688+
city: 'Hill Valley',
689+
street: {
690+
number: 56,
691+
},
692+
},
693+
}], function(err, customers) {
694+
return done(err);
695+
});
696+
});
697+
});
698+
699+
it('allows querying for nested json properties', function(done) {
700+
Customer.find({
701+
where: {
702+
'address.city': 'Hill Valley',
703+
},
704+
}, function(err, results) {
705+
if (err) return done(err);
706+
results.length.should.eql(1);
707+
results[0].address.city.should.eql('Hill Valley');
708+
done();
709+
});
710+
});
711+
712+
it('queries multiple levels of nesting', function(done) {
713+
Customer.find({
714+
where: {
715+
'address.street.number': 56,
716+
},
717+
}, function(err, results) {
718+
if (err) return done(err);
719+
results.length.should.eql(1);
720+
results[0].address.city.should.eql('Hill Valley');
721+
done();
722+
});
723+
});
724+
725+
it('allows ordering by nested json properties', function(done) {
726+
Customer.find({
727+
order: ['address.city DESC'],
728+
}, function(err, results1) {
729+
if (err) return done(err);
730+
results1[0].address.city.should.eql('Springfield');
731+
Customer.find({
732+
order: ['address.city ASC'],
733+
}, function(err, results2) {
734+
if (err) return done(err);
735+
results2[0].address.city.should.eql('Hill Valley');
736+
done();
737+
});
738+
});
739+
});
740+
});
661741
});
662742

663743
describe('Serial properties', function() {

0 commit comments

Comments
 (0)