Browse Source

Add date time interval functionality to postgres and mysql dialects (#326)

* Add date time interval functionality to postgres and mysql dialects

* Add date interval test involving years and months
master
Kevin Anthoney 8 years ago
committed by Brian C
parent
commit
72aff9012a
  1. 27
      lib/dialect/mysql.js
  2. 21
      lib/dialect/postgres.js
  3. 26
      lib/index.js
  4. 21
      lib/node/interval.js
  5. 94
      test/dialects/date-tests.js

27
lib/dialect/mysql.js

@ -2,6 +2,7 @@
var util = require('util');
var assert = require('assert');
var _ = require('lodash');
var Mysql = function(config) {
this.output = [];
@ -155,4 +156,30 @@ Mysql.prototype.visitColumn = function(columnNode) {
return Mysql.super_.prototype.visitColumn.call(this, columnNode);
};
Mysql.prototype.visitInterval = function(interval) {
var parameter;
if(_.isNumber(interval.years)) {
if(_.isNumber(interval.months)) {
parameter = "'" + interval.years + '-' + interval.months + "' YEAR_MONTH";
} else {
parameter = interval.years + ' YEAR';
}
} else if(_.isNumber(interval.months)) {
parameter = interval.months + ' MONTH';
} else if(_.isNumber(interval.days)) {
parameter = "'" + interval.days + ' ' +
(_.isNumber(interval.hours)?interval.hours:0) + ':' +
(_.isNumber(interval.minutes)?interval.minutes:0) + ':' +
(_.isNumber(interval.seconds)?interval.seconds:0) + "' DAY_SECOND";
} else {
parameter = "'" + (_.isNumber(interval.hours)?interval.hours:0) + ':' +
(_.isNumber(interval.minutes)?interval.minutes:0) + ':' +
(_.isNumber(interval.seconds)?interval.seconds:0) + "' HOUR_SECOND";
}
var result = "INTERVAL " + parameter;
return result;
};
module.exports = Mysql;

21
lib/dialect/postgres.js

@ -174,6 +174,7 @@ Postgres.prototype.visit = function(node) {
case 'FUNCTION CALL' : return this.visitFunctionCall(node);
case 'ARRAY CALL' : return this.visitArrayCall(node);
case 'CREATE VIEW' : return this.visitCreateView(node);
case 'INTERVAL' : return this.visitInterval(node);
case 'POSTFIX UNARY' : return this.visitPostfixUnary(node);
case 'PREFIX UNARY' : return this.visitPrefixUnary(node);
@ -1139,6 +1140,26 @@ Postgres.prototype.visitCreateView = function(createView) {
return result;
};
Postgres.prototype.visitInterval = function(interval) {
var parameter = '';
function _add(n, unit) {
if(!_.isNumber(n)) return;
if(parameter !== '') {
parameter += ' ';
}
parameter += n + ' ' + unit;
}
_add(interval.years, 'YEAR');
_add(interval.months, 'MONTH');
_add(interval.days, 'DAY');
_add(interval.hours, 'HOUR');
_add(interval.minutes, 'MINUTE');
_add(interval.seconds, 'SECOND');
if(parameter === '') parameter = '0 SECOND';
var result = "INTERVAL '" + parameter + "'";
return result;
};
/**
* Broken out as a separate function so that dialects that derive from this class can still use this functionality.
*

26
lib/index.js

@ -1,15 +1,15 @@
'use strict';
var _ = require('lodash');
var Column = require("./column");
var FunctionCall = require('./node/functionCall');
var ArrayCall = require('./node/arrayCall');
var functions = require('./functions');
var getDialect = require('./dialect');
var ParameterNode = require('./node/parameter');
var Query = require('./node/query');
var sliced = require('sliced');
var Table = require('./table');
var _ = require('lodash');
var Column = require("./column");
var FunctionCall = require('./node/functionCall');
var ArrayCall = require('./node/arrayCall');
var functions = require('./functions');
var getDialect = require('./dialect');
var Query = require('./node/query');
var sliced = require('sliced');
var Table = require('./table');
var Interval = require('./node/interval');
// default dialect is postgres
var DEFAULT_DIALECT = 'postgres';
@ -51,6 +51,12 @@ Sql.prototype.select = function() {
return query;
};
// Returns an interval clause
Sql.prototype.interval = function() {
var interval = new Interval(sliced(arguments));
return interval;
};
// Set the dialect
Sql.prototype.setDialect = function(dialect, config) {
this.dialect = getDialect(dialect);

21
lib/node/interval.js

@ -0,0 +1,21 @@
'use strict';
var Node = require(__dirname);
var ParameterNode = require(__dirname + '/parameter');
var IntervalNode = Node.define({
type: 'INTERVAL',
constructor: function(args) {
Node.call(this);
var interval = args[0] || {};
this.years = interval.years;
this.months = interval.months;
this.days = interval.days;
this.hours = interval.hours;
this.minutes = interval.minutes;
this.seconds = interval.seconds;
}
});
module.exports = IntervalNode;

94
test/dialects/date-tests.js

@ -133,4 +133,96 @@ Harness.test({
string: 'SELECT CURRENT_TIMESTAMP FROM "customer"'
},
params: []
});
});
Harness.test({
query: Sql.select(Sql.functions.CURRENT_TIMESTAMP().plus(Sql.interval({hours:1}))),
pg: {
text : 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'1 HOUR\')',
string: 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'1 HOUR\')'
},
mysql: {
text : 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'1:0:0\' HOUR_SECOND)',
string: 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'1:0:0\' HOUR_SECOND)'
},
params: []
});
Harness.test({
query: Sql.select(Sql.functions.CURRENT_TIMESTAMP().minus(Sql.interval({years:3}))),
pg: {
text : 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'3 YEAR\')',
string: 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'3 YEAR\')'
},
mysql: {
text : 'SELECT (CURRENT_TIMESTAMP - INTERVAL 3 YEAR)',
string: 'SELECT (CURRENT_TIMESTAMP - INTERVAL 3 YEAR)'
},
params: []
});
Harness.test({
query: Sql.select(Sql.functions.CURRENT_TIMESTAMP().minus(Sql.interval({years:3, months:2}))),
pg: {
text : 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'3 YEAR 2 MONTH\')',
string: 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'3 YEAR 2 MONTH\')'
},
mysql: {
text : 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'3-2\' YEAR_MONTH)',
string: 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'3-2\' YEAR_MONTH)'
},
params: []
});
Harness.test({
query: Sql.select(Sql.functions.CURRENT_TIMESTAMP().plus(Sql.interval({hours:1, minutes:20}))),
pg: {
text : 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'1 HOUR 20 MINUTE\')',
string: 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'1 HOUR 20 MINUTE\')'
},
mysql: {
text : 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'1:20:0\' HOUR_SECOND)',
string: 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'1:20:0\' HOUR_SECOND)'
},
params: []
});
Harness.test({
query: Sql.select(Sql.functions.CURRENT_TIMESTAMP().plus(Sql.interval({hours:'sql\'injection', minutes:20}))),
pg: {
text : 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'20 MINUTE\')',
string: 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'20 MINUTE\')'
},
mysql: {
text : 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'0:20:0\' HOUR_SECOND)',
string: 'SELECT (CURRENT_TIMESTAMP + INTERVAL \'0:20:0\' HOUR_SECOND)'
},
params: []
});
Harness.test({
query: Sql.select(Sql.functions.CURRENT_TIMESTAMP().minus(Sql.interval({days: 1, hours:5, minutes: 'sql\'injection'}))),
pg: {
text : 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'1 DAY 5 HOUR\')',
string: 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'1 DAY 5 HOUR\')'
},
mysql: {
text : 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'1 5:0:0\' DAY_SECOND)',
string: 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'1 5:0:0\' DAY_SECOND)'
},
params: []
});
Harness.test({
query: Sql.select(Sql.functions.CURRENT_TIMESTAMP().minus(Sql.interval({years: 2, months: 5}))),
pg: {
text : 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'2 YEAR 5 MONTH\')',
string: 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'2 YEAR 5 MONTH\')'
},
mysql: {
text : 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'2-5\' YEAR_MONTH)',
string: 'SELECT (CURRENT_TIMESTAMP - INTERVAL \'2-5\' YEAR_MONTH)'
},
params: []
});

Loading…
Cancel
Save