diff --git a/.gitignore b/.gitignore index f6e266c..b402264 100644 --- a/.gitignore +++ b/.gitignore @@ -17,3 +17,4 @@ out .nyc_output docs/_site docs/.sass-cache +.vscode diff --git a/docs/criteria.md b/docs/criteria.md index 526562a..2ded2be 100644 --- a/docs/criteria.md +++ b/docs/criteria.md @@ -33,6 +33,8 @@ Text operators are case-insensitive. | `>` | `>` | Greater than | | `>=` | `>=` | Greater than or equal | | `BETWEEN` | `BETWEEN` | Test whether value is between the [lower, upper] bounds of a 2-element array | +| `IS` | `IS` | Explicit equality test for `NULL` and boolean values | +| `IS NOT` | `IS NOT` | Explicit inequality test for `NULL` and boolean values | | `IS DISTINCT FROM` | `IS DISTINCT FROM` | Difference test with `NULL` considered a fixed value | | `IS NOT DISTINCT FROM` | `IS NOT DISTINCT FROM` | Equality test with `NULL` considered a fixed value | diff --git a/lib/query/mutators.js b/lib/query/mutators.js index 7d00947..0679cb8 100644 --- a/lib/query/mutators.js +++ b/lib/query/mutators.js @@ -35,8 +35,10 @@ exports.buildIn = condition => { * Interpolate values into a predicate with IS/IS NOT. */ exports.buildIs = function (condition) { - condition.operation.operator = condition.operation.operator === '=' ? 'IS' : 'IS NOT'; - + if (condition.operation.operator === '=' || condition.operation.operator === 'IS') { + condition.operation.operator = 'IS'; + } else { condition.operation.operator = 'IS NOT'; } + return condition; }; diff --git a/lib/query/operations.js b/lib/query/operations.js index 9266fff..b9964a5 100644 --- a/lib/query/operations.js +++ b/lib/query/operations.js @@ -46,7 +46,9 @@ const map = { '!~': {operator: '!~'}, '~*': {operator: '~*'}, '!~*': {operator: '!~*'}, - // distinct + // comparison predicates + 'is': {operator: 'IS', mutator: mutators.buildIs}, + 'is not': {operator: 'IS NOT', mutator: mutators.buildIs}, 'is distinct from': {operator: 'IS DISTINCT FROM'}, 'is not distinct from': {operator: 'IS NOT DISTINCT FROM'} }; diff --git a/lib/query/where.js b/lib/query/where.js index da3f933..521835d 100644 --- a/lib/query/where.js +++ b/lib/query/where.js @@ -113,9 +113,14 @@ const generator = function (condition) { * Generate a predicate for a document query. */ const docGenerator = function (condition, conditions) { + //case to check if key exist or not + if (condition.operation.operator === 'IS' || condition.operation.operator === 'IS NOT') { + condition.rawField = `("body" ->> '${condition.rawField}')`; + } + //if we have an array of objects, this is a deep traversal //we'll need to use a contains query to be sure we flex the index - if(_.isArray(condition.value) && _.isPlainObject(condition.value[0])) { + else if (_.isArray(condition.value) && _.isPlainObject(condition.value[0])) { condition.rawField = '"body"'; condition.operation.operator = '@>'; condition.params.push(JSON.stringify(conditions)); diff --git a/test/query/mutators.js b/test/query/mutators.js index 068a94e..5a155cf 100644 --- a/test/query/mutators.js +++ b/test/query/mutators.js @@ -68,15 +68,15 @@ describe('mutators', function () { assert.isNull(condition.value); }); - it('interpolates values with NOT IS', function () { + it('interpolates values with IS NOT', function () { const condition = mutators.buildIs({ - operation: ops('<>'), + operation: ops('is not'), offset: 1, value: true, params: [] }); - assert.equal(condition.operation.key, '<>'); + assert.equal(condition.operation.key, 'is not'); assert.equal(condition.operation.operator, 'IS NOT'); assert.equal(condition.offset, 1); assert.deepEqual(condition.params, []); @@ -102,7 +102,7 @@ describe('mutators', function () { it('passes nulls and booleans to buildIs', function () { assert.equal(mutators.equality({ - operation: ops('='), + operation: ops('is'), offset: 1, value: null, params: [] diff --git a/test/query/where.js b/test/query/where.js index 7251160..13f31dd 100644 --- a/test/query/where.js +++ b/test/query/where.js @@ -373,6 +373,13 @@ describe('WHERE clause generation', function () { assert.equal(result.params.length, 0); }); + it('should accept IS NOT explicitly', function () { + const condition = {field: '"field"', operation: ops('is not'), value: null, offset: 1, params: []}; + const result = where.generator(condition); + assert.equal(result.predicate, '"field" IS NOT null'); + assert.equal(result.params.length, 0); + }); + it('should apply operation mutators', function () { const condition = { field: '"field"', @@ -407,6 +414,13 @@ describe('WHERE clause generation', function () { assert.equal(result.params[0], JSON.stringify(obj)); }); + it('should create IS comparison predicate', function () { + const condition = {rawField: 'field', operation: ops('is'), value: true, offset: 1, params: []}; + 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', operation: ops('='), value: 'value', offset: 1, params: []}; const result = where.docGenerator(condition, {field: 'value'}); diff --git a/test/queryable/countDoc.js b/test/queryable/countDoc.js index ea5d8b3..3c76302 100644 --- a/test/queryable/countDoc.js +++ b/test/queryable/countDoc.js @@ -1,6 +1,6 @@ 'use strict'; -describe('findDoc', function () { +describe('countDoc', function () { let db; before(function(){ diff --git a/test/queryable/find.js b/test/queryable/find.js index 530826f..3ff1d27 100644 --- a/test/queryable/find.js +++ b/test/queryable/find.js @@ -92,6 +92,18 @@ describe('find', function () { assert.equal(res[0].id, 1); }); }); + it('returns products using is null', function () { + return db.products.find({'tags is': null}).then(res => { + assert.lengthOf(res, 1); + assert.equal(res[0].id, 1); + }); + }); + it('returns products using is not null', function () { + return db.products.find({'id is not': null}).then(res => { + assert.lengthOf(res, 4); + assert.equal(res[0].id, 1); + }); +}); it('returns products using distinct from', function () { return db.products.find({'tags is distinct from': '{tag1,tag2}'}).then(res => assert.lengthOf(res, 3)); }); diff --git a/test/queryable/findDoc.js b/test/queryable/findDoc.js index 29d8c96..f8e7b04 100644 --- a/test/queryable/findDoc.js +++ b/test/queryable/findDoc.js @@ -11,29 +11,183 @@ describe('findDoc', function () { return db.instance.$pool.end(); }); - it('returns results in document format', function () { - return db.docs.findDoc().then(docs => { - assert.lengthOf(docs, 4); - assert.equal(docs[0].id, 1); - assert.equal(docs[0].title, 'Document 1'); - assert.equal(docs[0].description, 'lorem ipsum etc'); + describe('querying all documents', function () { + it('returns all documents when passed \'*\'', function () { + return db.docs.findDoc('*').then(docs => { + assert.lengthOf(docs, 4); + }); + }); + + it('returns all documents when passed an empty conditions block', function () { + return db.docs.findDoc({}).then(docs => { + assert.lengthOf(docs, 4); + }); + }); + + it('returns all documents if no parameter', function () { + return db.docs.findDoc().then(docs => { + assert.lengthOf(docs, 4); + assert.equal(docs[0].id, 1); + assert.equal(docs[0].title, 'Document 1'); + assert.equal(docs[0].description, 'lorem ipsum etc'); + }); }); }); - it('applies criteria', function () { - return db.docs.findDoc({title: 'Document 1'}).then(docs => { - assert.lengthOf(docs, 1); - assert.equal(docs[0].id, 1); - assert.equal(docs[0].title, 'Document 1'); - assert.equal(docs[0].description, 'lorem ipsum etc'); + describe('querying documents by primary key', function () { + it('finds a doc by an integer primary key', function () { + return db.docs.findDoc(1).then(doc => { + assert.equal(doc.id, 1); + }); + }); + + it('finds a doc by a uuid primary key', function () { + return db.uuid_docs.findOne().then(row => { + return db.uuid_docs.findDoc(row.id).then(doc => { + assert.equal(doc.id, row.id); + }); + }); + }); + + it('finds a doc with > comparison on primary key', function () { + return db.docs.findDoc({'id >' : 1}).then(docs => { + assert.lengthOf(docs, 3); + }); + }); + + it('finds a doc with >= comparison on primary key', function () { + return db.docs.findDoc({'id >=' : 2}).then(docs => { + assert.lengthOf(docs, 3); + }); + }); + + it('finds multiple docs with an IN on primary key', function () { + return db.docs.findDoc({'id' : [1, 2, 3]}).then(docs => { + assert.lengthOf(docs, 3); + }); + }); + }); + + describe('querying documents by fields', function () { + it('finds a doc by title', function () { + return db.docs.findDoc({title : 'Document 1'}).then(docs => { + //find will return multiple if id not specified... confusing? + assert.equal(docs[0].title, 'Document 1'); + }); + }); + + it('parses greater than with two string defs', function () { + return db.docs.findDoc({'price >' : '18'}).then(docs => { + assert.equal(docs[0].title, 'Document 1'); + }); + }); + + it('parses greater than with a numeric', function () { + return db.docs.findDoc({'price >' : 18}).then(docs => { + assert.equal(docs[0].title, 'Document 1'); + }); + }); + + it('parses less than with a numeric', function () { + return db.docs.findDoc({'price <' : 18}).then(docs => { + assert.equal(docs[0].title, 'Something Else'); + }); + }); + + it('deals with arrays using IN', function () { + return db.docs.findDoc({'title' : ['Document 1', 'Document 2']}).then(docs => { + assert.lengthOf(docs, 2); + }); + }); + + it('deals with arrays using NOT IN', function () { + return db.docs.findDoc({'title <>' : ['Document 1', 'Document 2']}).then(docs => { + assert.lengthOf(docs, 2); + }); + }); + + it('check if field exists with IS NOT', function () { + return db.docs.findDoc({'price is not' : null}).then(docs => { + assert.lengthOf(docs, 4); + }); + }); + + it('executes a contains if passed an array of objects', function () { + return db.docs.findDoc({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); + }); }); }); - it('applies options', function () { - return db.docs.findDoc({title: 'Document 1'}, {build: true}).then(query => { - assert.deepEqual(query, { - sql: 'SELECT * FROM "docs"\nWHERE "body" @> $1 ORDER BY "id"', - params: ['{"title":"Document 1"}'] + describe('querying with options', function () { + it('returns the first matching document', function () { + return db.docs.findDoc('*', {single: true}).then(doc => { + assert.equal(doc.id, 1); + }); + }); + + it('applies criteria', function () { + return db.docs.findDoc({title: 'Document 1'}).then(docs => { + assert.lengthOf(docs, 1); + assert.equal(docs[0].id, 1); + assert.equal(docs[0].title, 'Document 1'); + assert.equal(docs[0].description, 'lorem ipsum etc'); + }); + }); + + it('applies offset and limit with a fixed sort by pk', function () { + return db.docs.findDoc('*', {offset: 1, limit: 1}).then(docs => { + assert.lengthOf(docs, 1); + assert.equal(docs[0].id, 2); + }); + }); + + it('orders by fields in the table', function () { + return db.docs.findDoc('*', {order: 'id desc'}).then(docs => { + assert.lengthOf(docs, 4); + assert.equal(docs[0].id, 4); + assert.equal(docs[1].id, 3); + assert.equal(docs[2].id, 2); + assert.equal(docs[3].id, 1); + }); + }); + + it('orders by fields in the document body', function () { + // nb: no parsing the key here -- it has to be exactly as you'd paste it into psql + return db.docs.findDoc('*', {order: 'body->>\'title\' desc'}).then(docs => { + assert.lengthOf(docs, 4); + assert.equal(docs[0].title, 'Something Else'); + assert.equal(docs[1].title, 'Document 3'); + assert.equal(docs[2].title, 'Document 2'); + assert.equal(docs[3].title, 'Document 1'); + }); + }); + + it('orders by fields in the document body with criteria', function () { + return db.docs.findDoc('*', { + order: [{field: 'title', direction: 'desc', type: 'varchar'}], + orderBody: true + }).then(docs => { + assert.lengthOf(docs, 4); + assert.equal(docs[0].title, 'Something Else'); + assert.equal(docs[1].title, 'Document 3'); + assert.equal(docs[2].title, 'Document 2'); + assert.equal(docs[3].title, 'Document 1'); + }); + }); + + it('applies options', function () { + return db.docs.findDoc({title: 'Document 1'}, {build: true}).then(query => { + assert.deepEqual(query, { + sql: 'SELECT * FROM "docs"\nWHERE "body" @> $1 ORDER BY "id"', + params: ['{"title":"Document 1"}'] + }); }); }); }); diff --git a/test/queryable/search.js b/test/queryable/search.js index b0f6747..74d6d3e 100644 --- a/test/queryable/search.js +++ b/test/queryable/search.js @@ -48,8 +48,8 @@ describe('search', function () { assert.equal(one[1].id, two[0].id); }); it('returns results filtered by where', function () { - return db.docs.search({fields: ['body->>\'description\''], term: 'C:*', where: {'body->>is_good': 'true'}}).then(res => { - assert.lengthOf(res, 1); + return db.products.search({fields: ['description'], term: 'description', where: {'in_stock': true}}).then(res => { + assert.lengthOf(res, 2); }); }); });