Skip to content
This repository has been archived by the owner on Mar 4, 2019. It is now read-only.

Commit

Permalink
fix: support traversal properly inside documents (fixes #594)
Browse files Browse the repository at this point in the history
  • Loading branch information
dmfay committed May 12, 2018
1 parent 09ad206 commit 8b49661
Show file tree
Hide file tree
Showing 7 changed files with 145 additions and 40 deletions.
37 changes: 37 additions & 0 deletions docs/documents.md
Expand Up @@ -16,6 +16,43 @@ Standard table functions still work on document tables, and can be quite useful

`findDoc` **is still preferred** to JSON queries if at all possible since it uses the `@>` "contains" operator to leverage indexing on the document body to improve performance.

### A Note About Criteria

Document criteria can be a little more complex to work with. When possible, Massive tries to use a "contains" (`@>`) operator in order to leverage the index on the document body. Example criteria objects are below.

```javascript
// A criteria object testing top-level keys uses the index
db.docs.findDoc({
field1: 'value',
'field2 !=': value
});

// Matching nested values exactly also uses the index, although
// combining multiple top-level conditions like this is less
// efficient. Note that operations cannot be used with the
// inner values -- only equality!
db.docs.findDoc({
objectfield: {
innervalue: 123
},
arrayfield: [
{'return': 'all docs where arrayfield contains this pair'}
]
});

// Testing values with IN does _not_ use the index
db.docs.findDoc({
'field1 IN': [1, 2, 3]
});

// Traversal for operations does _not_ use the index
db.docs.findDoc({
'outer.inner <>': 'nested value'
});
```

Be careful with criteria which cannot use the index since they may result in poorly-performing queries with sufficiently large tables.

### db.saveDoc

The connected database instance has a `saveDoc` function. Passed a collection name (which can include a non-public schema) and a JavaScript object, this will create the table if it doesn't already exist and write the object to it.
Expand Down
22 changes: 18 additions & 4 deletions lib/statement/where.js
Expand Up @@ -44,16 +44,26 @@ const docGenerator = function (condition, conditions) {
condition.appended.operator = '@>';
condition.params.push(JSON.stringify(conditions));
condition.value = `$${condition.offset}`;
} else if (condition.appended.operator === '=' && !_.isArray(condition.value)) {
// if we have equality here, just use a JSON contains
} else if (
condition.appended.operator === '=' &&
condition.elements.length === 0 &&
!_.isArray(condition.value)
) {
// if we have equality here and no traversal, just use a JSON contains
const param = {};
param[condition.rawField] = condition.value;
condition.params.push(JSON.stringify(param));
condition.rawField = '"body"';
condition.appended.operator = '@>';
condition.value = `$${condition.offset}`;
} else {
// we're querying a key on the document body
// we're querying a key on the document body!
// first build the full path; because the rawField is actually the
// outermost JSON key, prepend it to the rest of the elements.
const elements = condition.elements.slice();

elements.unshift(condition.rawField);

let cast = '';

// comparison stuff - same as method above but this time
Expand All @@ -74,7 +84,11 @@ const docGenerator = function (condition, conditions) {
condition.value = `$${condition.offset}`;
}

condition.rawField = `("body" ->> '${condition.rawField}')${cast}`;
if (elements.length === 1) {
condition.rawField = `("body" ->> '${elements[0]}')${cast}`;
} else {
condition.rawField = `("body" #>> '{${elements.join(',')}}')${cast}`;
}
}

return {
Expand Down
12 changes: 8 additions & 4 deletions lib/util/parse-key.js
Expand Up @@ -15,6 +15,7 @@ exports = module.exports = function (key, appendix) {
key = key.trim();

const jsonShape = []; // describe a JSON path: true is a field, false an array index
let elements = []; // collect actual JSON path elements (for document queries)
let parsed = [[]]; // we're going to collect token arrays
let buffer = parsed[0]; // start with the first token
let inQuotedField = false; // ensure we pick up everything in quotes
Expand Down Expand Up @@ -94,17 +95,19 @@ exports = module.exports = function (key, appendix) {
let quotedField = `"${field}"`;

if (jsonShape.length === 1) {
elements.push(parsed.shift());

if (jsonShape[0]) {
// object key
quotedField = `${quotedField}->>'${parsed.shift()}'`;
quotedField = `${quotedField}->>'${elements[0]}'`;
} else {
// array index
quotedField = `${quotedField}->>${parsed.shift()}`;
quotedField = `${quotedField}->>${elements[0]}`;
}
} else if (jsonShape.length > 0) {
const tokens = parsed.splice(0, jsonShape.length);
elements = parsed.splice(0, jsonShape.length);

quotedField = `${quotedField}#>>'{${tokens.join(',')}}'`;
quotedField = `${quotedField}#>>'{${elements.join(',')}}'`;
}

if (hasCast) {
Expand All @@ -131,6 +134,7 @@ exports = module.exports = function (key, appendix) {
return {
rawField: field,
field: quotedField,
elements,
appended,
isJSON: jsonShape.length > 0
};
Expand Down
2 changes: 1 addition & 1 deletion test/helpers/scripts/data-docs/schema.sql
Expand Up @@ -21,4 +21,4 @@ insert into docs(body)
values('{"title":"Document 1","price":22,"description":"lorem ipsum etc","is_good":true,"created_at":"2015-03-04T09:43:41.643Z"}'),
('{"title":"Document 2","price":18,"description":"Macaroni and Cheese","is_good":true,"created_at":"2015-03-04T15:43:41.643+06:00"}'),
('{"title":"Document 3","price":18,"description":"something or other","is_good":true,"created_at":"2015-03-04T06:43:41.643-03:00"}'),
('{"title":"Something Else","price":6,"description":"Two buddies fighting crime","is_good":false,"created_at":"1977-03-04T09:43:41.643Z","studios": [{"name" : "Warner"}, {"name" : "Universal"}]}');
('{"title":"Something Else","price":6,"description":"Two buddies fighting crime","is_good":false,"created_at":"1977-03-04T09:43:41.643Z","studios": [{"name" : "Warner"}, {"name" : "Universal"}], "nested": { "id": 1 }}');
20 changes: 20 additions & 0 deletions test/queryable/findDoc.js
Expand Up @@ -118,6 +118,12 @@ describe('findDoc', function () {
});
});

it('gets results from dual contains criteria', function () {
return db.docs.findDoc({nested: {id: 1}, studios: [{name: 'Warner'}]}).then(docs => {
assert.lengthOf(docs, 1);
});
});

it('works properly with dates', function () {
return db.docs.findDoc({'created_at <': new Date(1980, 1, 1)}).then(docs => {
assert.lengthOf(docs, 1);
Expand All @@ -129,6 +135,20 @@ describe('findDoc', function () {
assert.lengthOf(docs, 3);
});
});

it('finds by nested fields', function () {
return db.docs.findDoc({'nested.id': 1}).then(docs => {
assert.lengthOf(docs, 1);
assert.equal(docs[0].title, 'Something Else');
});
});

it('finds by nested fields with operations', function () {
return db.docs.findDoc({'nested.id >': 0}).then(docs => {
assert.lengthOf(docs, 1);
assert.equal(docs[0].title, 'Something Else');
});
});
});

describe('querying with options', function () {
Expand Down
84 changes: 53 additions & 31 deletions test/statement/where.js
Expand Up @@ -2,8 +2,27 @@

const where = require('../../lib/statement/where');
const ops = require('../../lib/statement/operations');
const parseKey = require('../../lib/util/parse-key');

describe('WHERE clause generation', function () {
/**
* Helper for generating conditions in WHERE clause testing.
*
* @param {String} key - The key and optional operation.
* @param {Any} value - The value being tested in the predicate.
* @param {Integer} offset - The condition offset.
* @param {Array} params - This may not be needed TODO
* @returns {Object} A condition object.
*/
function getCondition (key, value, offset, params) {
const condition = parseKey(key, ops);
condition.value = value;
condition.offset = offset;
condition.params = params;

return condition;
}

describe('module', function () {
it('should return a safe value for empty criteria', function () {
const result = where({});
Expand Down Expand Up @@ -150,36 +169,21 @@ describe('WHERE clause generation', function () {

describe('tableGenerator', function () {
it('should add values to params', function () {
const condition = {
field: '"field"',
appended: {
operator: '='
},
value: 'value',
offset: 1,
params: []
};
const condition = getCondition('field', 'value', 1, []);
const result = where.tableGenerator(condition);
assert.equal(result.predicate, '"field" = $1');
assert.equal(result.params.length, 1);
assert.equal(result.params[0], 'value');
});

it('should apply mutators', function () {
const condition = {
field: '"field"',
appended: {
operator: '=',
mutator: cond => {
cond.value = 'hi!';

return cond;
}
},
value: 'value',
offset: 1,
params: []
const condition = getCondition('field', 'value', 1, []);
condition.appended.mutator = cond => {
cond.value = 'hi!';

return cond;
};

const result = where.tableGenerator(condition);
assert.equal(result.predicate, '"field" = hi!');
assert.equal(result.params.length, 0);
Expand All @@ -189,66 +193,84 @@ describe('WHERE clause generation', function () {
describe('docGenerator', function () {
it('should build deep traversals', function () {
const obj = {field: [{one: 'two'}]};
const condition = {rawField: 'field', appended: ops('='), value: [{one: 'two'}], offset: 1, params: []};
const condition = getCondition('field', [{one: 'two'}], 1, []);
const result = where.docGenerator(condition, obj);
assert.equal(result.predicate, '"body" @> $1');
assert.equal(result.params.length, 1);
assert.equal(result.params[0], JSON.stringify(obj));
});

it('should create IS comparison predicate', function () {
const condition = {rawField: 'field', appended: ops('is'), value: true, offset: 1, params: []};
it('should create an IS comparison predicate', function () {
const condition = getCondition('field is', true, 1, []);
const result = where.docGenerator(condition, {'field is': true});
assert.equal(result.predicate, '("body" ->> \'field\') IS true');
assert.equal(result.params.length, 0);
});

it('should build an equality predicate using the JSON contains op', function () {
const condition = {rawField: 'field', appended: ops('='), value: 'value', offset: 1, params: []};
const condition = getCondition('field', 'value', 1, []);
const result = where.docGenerator(condition, {field: 'value'});
assert.equal(result.predicate, '"body" @> $1');
assert.equal(result.params.length, 1);
assert.equal(result.params[0], JSON.stringify({field: 'value'}));
});

it('should build a non-equality predicate', function () {
const condition = {rawField: 'field', appended: ops('<>'), value: 'value', offset: 1, params: []};
const condition = getCondition('field <>', 'value', 1, []);
const result = where.docGenerator(condition, {'field <>': 'value'});
assert.equal(result.predicate, '("body" ->> \'field\') <> $1');
assert.equal(result.params.length, 1);
assert.equal(result.params[0], 'value');
});

it('should cast booleans in non-equality predicates', function () {
const condition = {rawField: 'field', appended: ops('<>'), value: true, offset: 1, params: []};
const condition = getCondition('field <>', true, 1, []);
const result = where.docGenerator(condition, {'field <>': true});
assert.equal(result.predicate, '("body" ->> \'field\')::boolean <> true');
assert.equal(result.params.length, 0);
});

it('should cast numbers in non-equality predicates', function () {
const condition = {rawField: 'field', appended: ops('<>'), value: 123.45, offset: 1, params: []};
const condition = getCondition('field <>', 123.45, 1, []);
const result = where.docGenerator(condition, {'field <>': 123.45});
assert.equal(result.predicate, '("body" ->> \'field\')::decimal <> 123.45');
assert.equal(result.params.length, 0);
});

it('should cast dates in non-equality predicates', function () {
const date = new Date();
const condition = {rawField: 'field', appended: ops('<>'), value: date, offset: 1, params: []};
const condition = getCondition('field <>', date, 1, []);
const result = where.docGenerator(condition, {'field <>': date});
assert.equal(result.predicate, '("body" ->> \'field\')::timestamptz <> $1');
assert.equal(result.params.length, 1);
assert.equal(result.params[0], date);
});

it('should create IN clauses for array parameters', function () {
const condition = {rawField: 'field', appended: ops('='), value: ['value1', 'value2'], offset: 1, params: []};
const condition = getCondition('field', ['value1', 'value2'], 1, []);
const result = where.docGenerator(condition, {field: ['value1', 'value2']});
assert.equal(result.predicate, '("body" ->> \'field\') IN ($1,$2)');
assert.equal(result.params.length, 2);
assert.equal(result.params[0], 'value1');
assert.equal(result.params[1], 'value2');
});

it('should traverse JSON with ->>', function () {
const condition = getCondition('field', ['value1', 'value2'], 1, []);
const result = where.docGenerator(condition, {field: ['value1', 'value2']});
assert.equal(result.predicate, '("body" ->> \'field\') IN ($1,$2)');
assert.equal(result.params.length, 2);
assert.equal(result.params[0], 'value1');
assert.equal(result.params[1], 'value2');
});

it('should use pathing operator #>> for nested values', function () {
const condition = getCondition('field.one.two', ['value1', 'value2'], 1, []);
const result = where.docGenerator(condition, {field: ['value1', 'value2']});
assert.equal(result.predicate, '("body" #>> \'{field,one,two}\') IN ($1,$2)');
assert.equal(result.params.length, 2);
assert.equal(result.params[0], 'value1');
assert.equal(result.params[1], 'value2');
});
});
});
8 changes: 8 additions & 0 deletions test/util/parse-key.js
Expand Up @@ -23,48 +23,56 @@ describe('parseKey', function () {
const result = parseKey('json.property');
assert.equal(result.rawField, 'json');
assert.equal(result.field, '"json"->>\'property\'');
assert.deepEqual(result.elements, ['property']);
});

it('should format a shallow JSON path with a numeric key', function () {
const result = parseKey('json.123');
assert.equal(result.rawField, 'json');
assert.equal(result.field, '"json"->>\'123\'');
assert.deepEqual(result.elements, ['123']);
});

it('should format a JSON array path', function () {
const result = parseKey('json[123]');
assert.equal(result.rawField, 'json');
assert.equal(result.field, '"json"->>123');
assert.deepEqual(result.elements, ['123']);
});

it('should format a deep JSON path', function () {
const result = parseKey('json.outer.inner');
assert.equal(result.rawField, 'json');
assert.equal(result.field, '"json"#>>\'{outer,inner}\'');
assert.deepEqual(result.elements, ['outer', 'inner']);
});

it('should format a JSON path with a quoted field', function () {
const result = parseKey('"json field".outer.inner');
assert.equal(result.rawField, 'json field');
assert.equal(result.field, '"json field"#>>\'{outer,inner}\'');
assert.deepEqual(result.elements, ['outer', 'inner']);
});

it('should format a JSON path with a quoted field containing special characters', function () {
const result = parseKey('"json.fiel[d]".outer.inner');
assert.equal(result.rawField, 'json.fiel[d]');
assert.equal(result.field, '"json.fiel[d]"#>>\'{outer,inner}\'');
assert.deepEqual(result.elements, ['outer', 'inner']);
});

it('should format a deep JSON path with numeric keys', function () {
const result = parseKey('json.123.456');
assert.equal(result.rawField, 'json');
assert.equal(result.field, '"json"#>>\'{123,456}\'');
assert.deepEqual(result.elements, ['123', '456']);
});

it('should format mixed JSON paths', function () {
const result = parseKey('json.array[1].field.array[2]');
assert.equal(result.rawField, 'json');
assert.equal(result.field, '"json"#>>\'{array,1,field,array,2}\'');
assert.deepEqual(result.elements, ['array', '1', 'field', 'array', '2']);
});
});

Expand Down

0 comments on commit 8b49661

Please sign in to comment.