Skip to content

Commit

Permalink
optimized version of range and page for postgresql using window f…
Browse files Browse the repository at this point in the history
…unction. closes #62
  • Loading branch information
koskimas committed Mar 13, 2017
1 parent 12cdde1 commit 73edf6d
Show file tree
Hide file tree
Showing 14 changed files with 174 additions and 56 deletions.
27 changes: 27 additions & 0 deletions doc/includes/API.md
Original file line number Diff line number Diff line change
Expand Up @@ -3779,6 +3779,12 @@ Person

Only returns the given page of results.

On postgresql a window function is used and only one query is executed. On Mysql and other databases two queries
(the query itself, and a separate count query) are executed. Mysql has the `SQL_CALC_FOUND_ROWS` option and
`FOUND_ROWS()` function that can be used to calculate the result size, but according to my tests and
[the interwebs](http://www.google.com/search?q=SQL_CALC_FOUND_ROWS+performance) the performance is significantly worse
than just executing a separate count query.

##### Arguments

Argument|Type|Description
Expand Down Expand Up @@ -3813,8 +3819,29 @@ Person
});
```

> `range` can be called without arguments if you want to specify the limit and offset explicitly:
```js
Person
.query()
.where('age', '>', 20)
.limit(10)
.range()
.then(function (result) {
console.log(result.results.length); // --> 101
console.log(result.total); // --> 3341
});
```

Only returns the given range of results.


On postgresql a window function is used and only one query is executed. On Mysql and other databases two queries
(the query itself, and a separate count query) are executed. Mysql has the `SQL_CALC_FOUND_ROWS` option and
`FOUND_ROWS()` function that can be used to calculate the result size, but according to my tests and
[the interwebs](http://www.google.com/search?q=SQL_CALC_FOUND_ROWS+performance) the performance is significantly worse
than just executing a separate count query.

##### Arguments

Argument|Type|Description
Expand Down
68 changes: 29 additions & 39 deletions src/queryBuilder/QueryBuilder.js
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,9 @@ import OnBuildOperation from './operations/OnBuildOperation';
import SelectOperation from './operations/SelectOperation';
import EagerOperation from './operations/EagerOperation';

import RangePostgresOperation from './operations/range/RangePostgresOperation';
import RangeOperation from './operations/range/RangeOperation';

export default class QueryBuilder extends QueryBuilderBase {

constructor(modelClass) {
Expand Down Expand Up @@ -487,48 +490,13 @@ export default class QueryBuilder extends QueryBuilderBase {
let rawQuery = knex.raw(query).wrap('(', ') as temp');
let countQuery = knex.count('* as count').from(rawQuery);

return countQuery.then(result => result[0] ? result[0].count : 0);
}
if (this.internalContext().debug) {
countQuery.debug();
}

/**
* @param {number} page
* @param {number} pageSize
* @returns {QueryBuilder}
*/
page(page, pageSize) {
return this.range(page * pageSize, (page + 1) * pageSize - 1);
return countQuery.then(result => result[0] ? result[0].count : 0);
}

/**
* @param {number} start
* @param {number} end
* @returns {QueryBuilder}
*/
range(start, end) {
let resultSizePromise;

return this
.limit(end - start + 1)
.offset(start)
.runBefore(() => {
// Don't return the promise so that it is executed
// in parallel with the actual query.
resultSizePromise = this.resultSize();
return null;
})
.runAfter(results => {
// Now that the actual query is finished, wait until the
// result size has been calculated.
return Promise.all([results, resultSizePromise]);
})
.runAfter(arr => {
return {
results: arr[0],
total: _.parseInt(arr[1])
};
});
};

/**
* @returns {knex.QueryBuilder}
*/
Expand Down Expand Up @@ -749,6 +717,7 @@ export default class QueryBuilder extends QueryBuilderBase {
modelClass = null;
}

// Turn the properties into a hash for performance.
properties = _.reduce(properties, (obj, prop) => {
obj[prop] = true;
return obj;
Expand Down Expand Up @@ -781,6 +750,26 @@ export default class QueryBuilder extends QueryBuilderBase {
});
}

/**
* @param {number} page
* @param {number} pageSize
* @returns {QueryBuilder}
*/
page(page, pageSize) {
return this.range(page * pageSize, (page + 1) * pageSize - 1);
}

/**
* @param {number} start
* @param {number} end
* @returns {QueryBuilder}
*/
@queryBuilderOperation({
default: RangeOperation,
postgresql: RangePostgresOperation
})
range(start, end) {}

/**
* @param {string} relationName
* @returns {QueryBuilder}
Expand Down Expand Up @@ -864,6 +853,7 @@ export default class QueryBuilder extends QueryBuilderBase {
* @returns {QueryBuilder}
*/
debug() {
this.internalContext().debug = true;
this.internalContext().onBuild.push(builder => {
builder.callKnexQueryBuilderOperation('debug', []);
});
Expand Down
4 changes: 2 additions & 2 deletions src/queryBuilder/QueryBuilderBase.js
Original file line number Diff line number Diff line change
Expand Up @@ -5,8 +5,8 @@ import KnexOperation from './operations/KnexOperation';
import SelectOperation from './operations/SelectOperation';
import WhereRefOperation from './operations/WhereRefOperation';
import WhereCompositeOperation from './operations/WhereCompositeOperation';
import WhereInCompositeOperation from './operations/WhereInCompositeOperation';
import WhereInCompositeSqliteOperation from './operations/WhereInCompositeSqliteOperation';
import WhereInCompositeOperation from './operations/whereInComposite/WhereInCompositeOperation';
import WhereInCompositeSqliteOperation from './operations/whereInComposite/WhereInCompositeSqliteOperation';

import WhereJsonPostgresOperation from './operations/jsonApi/WhereJsonPostgresOperation';
import WhereJsonHasPostgresOperation from './operations/jsonApi/WhereJsonHasPostgresOperation';
Expand Down
2 changes: 2 additions & 0 deletions src/queryBuilder/QueryBuilderContextBase.js
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ export default class QueryBuilderContextBase {
this.userContext = userContext;
this.skipUndefined = false;
this.options = {};
this.debug = false;
this.knex = null;
}

Expand All @@ -13,6 +14,7 @@ export default class QueryBuilderContextBase {
ctx.userContext = this.userContext;
ctx.skipUndefined = this.skipUndefined;
ctx.options = Object.assign({}, this.options);
ctx.debug = this.debug;
ctx.knex = this.knex;

return ctx;
Expand Down
4 changes: 2 additions & 2 deletions src/queryBuilder/operations/QueryBuilderOperation.js
Original file line number Diff line number Diff line change
Expand Up @@ -83,10 +83,10 @@ export default class QueryBuilderOperation {

/**
* @param {QueryBuilder} builder
* @param {*} result
* @param {*} rows
* @returns {*}
*/
onRawResult(builder, result) {
onRawResult(builder, rows) {
return rows;
}

Expand Down
38 changes: 38 additions & 0 deletions src/queryBuilder/operations/range/RangeOperation.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@
import QueryBuilderOperation from '../QueryBuilderOperation';

export default class RangeOperation extends QueryBuilderOperation {

constructor(name, opt) {
super(name, opt);
this.resultSizePromise = null;
}

call(builder, args) {
if (args.length === 2) {
const start = args[0];
const end = args[1];

// Need to set these here instead of `onBuild` so that they
// don't end up in the resultSize query.
builder.limit(end - start + 1).offset(start);
}

return true;
}

onBefore(builder) {
// Don't return the promise so that it is executed
// in parallel with the actual query.
this.resultSizePromise = builder.resultSize();
return null;
}

onAfterInternal(builder, result) {
return this.resultSizePromise.then(count => {
return {
results: result,
total: parseInt(count, 10)
};
});
}
}
42 changes: 42 additions & 0 deletions src/queryBuilder/operations/range/RangePostgresOperation.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
import RangeOperation from './RangeOperation'

const totalCountCol = 'objectiontmptotalcount';

export default class RangePostgresOperation extends RangeOperation {

constructor(name, opt) {
super(name, opt);
this.count = 0;
}

onBefore(knexBuilder, builder) {
// Do nothing.
}

onBuild(knexBuilder, builder) {
const knex = builder.knex();
knexBuilder.select(knex.raw(`count(*) over () as ${totalCountCol}`));
}

onRawResult(builder, rows) {
if (Array.isArray(rows) && rows.length && typeof rows[0] === 'object') {
this.count = rows[0][totalCountCol];

for (let i = 0, l = rows.length; i < l; ++i) {
delete rows[i][totalCountCol];
}
} else if (rows && typeof rows === 'object') {
this.count = rows[totalCountCol];
delete rows[totalCountCol];
}

return rows;
}

onAfterInternal(builder, result) {
return {
results: result,
total: parseInt(this.count, 10)
};
}
}
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
import WrappingQueryBuilderOperation from './WrappingQueryBuilderOperation';
import WrappingQueryBuilderOperation from '../WrappingQueryBuilderOperation';

export default class WhereInCompositeOperation extends WrappingQueryBuilderOperation {

Expand Down
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
import WrappingQueryBuilderOperation from './WrappingQueryBuilderOperation';
import WrappingQueryBuilderOperation from '../WrappingQueryBuilderOperation';

export default class WhereInCompositeSqliteOperation extends WrappingQueryBuilderOperation {

Expand Down
2 changes: 1 addition & 1 deletion src/transaction.js
Original file line number Diff line number Diff line change
Expand Up @@ -74,7 +74,7 @@ transaction.start = function (modelClassOrKnex) {
knex = modelClassOrKnex.knex();
}

if (!_.isFunction(knex.transaction)) {
if (!knex || !_.isFunction(knex.transaction)) {
return Promise.reject(new Error('objection.transaction.start: first argument must be a model class or a knex instance'));
}

Expand Down
4 changes: 4 additions & 0 deletions src/utils/knexUtils.js
Original file line number Diff line number Diff line change
Expand Up @@ -29,3 +29,7 @@ export function isKnexJoinBuilder(value) {
export function isKnexRaw(value) {
return value instanceof KnexRaw;
}

export function isKnexTransaction(knex) {
return !!getDialect(knex) && typeof knex.commit === 'function' && typeof knex.rollback === 'function';
}
15 changes: 15 additions & 0 deletions tests/integration/find.js
Original file line number Diff line number Diff line change
Expand Up @@ -69,6 +69,21 @@ module.exports = function (session) {
});
});

it('should return the given range and total count when range() is called without arguments', function () {
return Model2
.query()
.offset(1)
.limit(2)
.range()
.orderBy('model_2_prop_2', 'desc')
.then(function (result) {
expect(result.results[0]).to.be.a(Model2);
expect(result.results[1]).to.be.a(Model2);
expect(result.total === 3).to.equal(true);
expect(_.map(result.results, 'model2Prop2')).to.eql([20, 10]);
});
});

it('should return the given page and total count when page() is called', function () {
return Model2
.query()
Expand Down
1 change: 1 addition & 0 deletions tests/integration/transactions.js
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ var _ = require('lodash');
var expect = require('expect.js');
var Promise = require('bluebird');
var transaction = require('../../').transaction;
var knexUtils = require('../../lib/utils/knexUtils');

module.exports = function (session) {
var Model1 = session.models.Model1;
Expand Down
19 changes: 9 additions & 10 deletions tests/unit/queryBuilder/QueryBuilder.js
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@ var _ = require('lodash')
, expect = require('expect.js')
, Promise = require('bluebird')
, objection = require('../../../')
, knexUtils = require('../../../lib/utils/knexUtils')
, knexMocker = require('../../../testUtils/mockKnex')
, Model = objection.Model
, QueryBuilder = objection.QueryBuilder
Expand Down Expand Up @@ -665,36 +666,34 @@ describe('QueryBuilder', function () {
});

it('range should return a range and the total count', function (done) {
mockKnexQueryResults = [[{count: 123}], [{a: 1}]];
mockKnexQueryResults = [[{objectiontmptotalcount: 123, a: 1}]];
QueryBuilder
.forClass(TestModel)
.where('test', 100)
.orderBy('order')
.range(100, 200)
.then(function (res) {
expect(executedQueries).to.have.length(2);
expect(executedQueries[0]).to.equal('select count(*) as "count" from (select "Model".* from "Model" where "test" = 100) as temp');
expect(executedQueries[1]).to.equal('select "Model".* from "Model" where "test" = 100 order by "order" asc limit 101 offset 100');
expect(executedQueries).to.have.length(1);
expect(executedQueries[0]).to.equal('select count(*) over () as objectiontmptotalcount, "Model".* from "Model" where "test" = 100 order by "order" asc limit 101 offset 100');
expect(res.total).to.equal(123);
expect(res.results).to.eql(mockKnexQueryResults[1]);
expect(res.results).to.eql([{a: 1}]);
done();
})
.catch(done);
});

it('page should return a page and the total count', function (done) {
mockKnexQueryResults = [[{count: 123}], [{a: 1}]];
mockKnexQueryResults = [[{objectiontmptotalcount: 123, a: 1}]];
QueryBuilder
.forClass(TestModel)
.where('test', 100)
.orderBy('order')
.page(10, 100)
.then(function (res) {
expect(executedQueries).to.have.length(2);
expect(executedQueries[0]).to.equal('select count(*) as "count" from (select "Model".* from "Model" where "test" = 100) as temp');
expect(executedQueries[1]).to.equal('select "Model".* from "Model" where "test" = 100 order by "order" asc limit 100 offset 1000');
expect(executedQueries).to.have.length(1);
expect(executedQueries[0]).to.equal('select count(*) over () as objectiontmptotalcount, "Model".* from "Model" where "test" = 100 order by "order" asc limit 100 offset 1000');
expect(res.total).to.equal(123);
expect(res.results).to.eql(mockKnexQueryResults[1]);
expect(res.results).to.eql([{a: 1}]);
done();
})
.catch(done);
Expand Down

0 comments on commit 73edf6d

Please sign in to comment.