diff --git a/lib/Dialects/mysql.js b/lib/Dialects/mysql.js index c3970a0..c3de763 100644 --- a/lib/Dialects/mysql.js +++ b/lib/Dialects/mysql.js @@ -1,5 +1,7 @@ var util = require("util"); +exports.name = 'mysql'; + exports.escapeId = function () { return Array.prototype.slice.apply(arguments).map(function (el) { if (typeof el == "object") { diff --git a/lib/Dialects/postgresql.js b/lib/Dialects/postgresql.js index b5b3bc9..2231bf2 100644 --- a/lib/Dialects/postgresql.js +++ b/lib/Dialects/postgresql.js @@ -1,5 +1,7 @@ var util = require("util"); +exports.name = 'postgresql'; + exports.escapeId = function () { return Array.prototype.slice.apply(arguments).map(function (el) { if (typeof el == "object") { diff --git a/lib/Dialects/sqlite.js b/lib/Dialects/sqlite.js index f3eeb75..71e3048 100644 --- a/lib/Dialects/sqlite.js +++ b/lib/Dialects/sqlite.js @@ -1,5 +1,6 @@ var util = require("util"); +exports.name = 'sqlite'; exports.escapeId = require("./mysql").escapeId; exports.escapeVal = function (val, timeZone) { diff --git a/lib/Dialects/tds.js b/lib/Dialects/tds.js new file mode 100644 index 0000000..c91560a --- /dev/null +++ b/lib/Dialects/tds.js @@ -0,0 +1,136 @@ +var util = require("util"); + +exports.name = 'tds'; + +exports.escapeId = function () { + return Array.prototype.slice.apply(arguments).map(function (el) { + if (typeof el == "object") { + return el.str.replace(/\?:(id|value)/g, function (m) { + if (m == "?:id") { + return exports.escapeId(el.escapes.shift()); + } + // ?:value + return exports.escapeVal(el.escapes.shift()); + }); + } + return "[" + el.replace(/\[/g, '[[]').replace(/(^|[^\[])\]/g, '[]]') + "]"; + }).join("."); +}; + +exports.escapeVal = function (val, timeZone) { + if (val === undefined || val === null) { + return 'NULL'; + } + + if (Buffer.isBuffer(val)) { + return bufferToString(val); + } + + if (Array.isArray(val)) { + return arrayToList(val, timeZone || "Z"); + } + + if (util.isDate(val)) { + val = dateToString(val, timeZone || "Z"); + } else { + switch (typeof val) { + case 'boolean': + return (val) ? '1' : '0'; + case 'number': + return val + ''; + case "object": + return objectToValues(val, timeZone || "Z"); + case "function": + return val(exports); + } + } + + val = val.replace(/[\0\n\r\b\t\\\'\"\x1a]/g, function(s) { + switch(s) { + case "\0": return "\\0"; + case "\n": return "\\n"; + case "\r": return "\\r"; + case "\b": return "\\b"; + case "\t": return "\\t"; + case "\x1a": return "\\Z"; + case "\'": return "'"; + default: return "\\" + s; + } + }); + + return "'" + val.replace("'", "''") + "'"; +}; + +function objectToValues(object, timeZone) { + var values = []; + for (var key in object) { + var value = object[key]; + + if(typeof value === 'function') { + continue; + } + + values.push(exports.escapeId(key) + ' = ' + exports.escapeVal(value, timeZone)); + } + + return values.join(', '); +} + +function arrayToList(array, timeZone) { + return "(" + array.map(function(v) { + if (Array.isArray(v)) return arrayToList(v); + return exports.escapeVal(v, timeZone); + }).join(', ') + ")"; +} + +function bufferToString(buffer) { + var hex = ''; + + try { + hex = buffer.toString('hex'); + } catch (err) { + // node v0.4.x does not support hex / throws unknown encoding error + for (var i = 0; i < buffer.length; i++) { + var b = buffer[i]; + hex += zeroPad(b.toString(16)); + } + } + + return "0x" + hex; +} + +function dateToString(date, timeZone) { + var dt = new Date(date); + + if (timeZone != 'local') { + var tz = convertTimezone(timeZone); + + dt.setTime(dt.getTime() + (dt.getTimezoneOffset() * 60000)); + if (tz !== false) { + dt.setTime(dt.getTime() + (tz * 60000)); + } + } + + var year = dt.getFullYear(); + var month = zeroPad(dt.getMonth() + 1); + var day = zeroPad(dt.getDate()); + var hour = zeroPad(dt.getHours()); + var minute = zeroPad(dt.getMinutes()); + var second = zeroPad(dt.getSeconds()); + + return year + '-' + month + '-' + day + ' ' + hour + ':' + minute + ':' + second; +} + +function zeroPad(number) { + return (number < 10) ? '0' + number : number; +} + +function convertTimezone(tz) { + if (tz == "Z") return 0; + + var m = tz.match(/([\+\-\s])(\d\d):?(\d\d)?/); + if (m) { + return (m[1] == '-' ? -1 : 1) * (parseInt(m[2], 10) + ((m[3] ? parseInt(m[3], 10) : 0) / 60)) * 60; + } + return false; +} diff --git a/lib/Remove.js b/lib/Remove.js index a063a14..574ae96 100644 --- a/lib/Remove.js +++ b/lib/Remove.js @@ -5,7 +5,9 @@ exports.RemoveQuery = RemoveQuery; function RemoveQuery(Dialect) { var sql = { where : [], - order : [] + order : [], + use_top: (Dialect.name === 'tds'), + can_use_order_by: (Dialect.name !== 'tds') }; return { @@ -25,7 +27,14 @@ function RemoveQuery(Dialect) { build: function () { var query = [], tmp; - query.push("DELETE FROM"); + query.push("DELETE"); + + // TDS only! + if (sql.use_top && sql.hasOwnProperty("limit")) { + query.push("TOP (" + sql.limit + ")"); + } + + query.push("FROM"); query.push(Dialect.escapeId(sql.table)); query = query.concat(Where.build(Dialect, sql.where)); @@ -41,20 +50,22 @@ function RemoveQuery(Dialect) { } } - if (tmp.length > 0) { + if (tmp.length > 0 && sql.can_use_order_by) { query.push("ORDER BY " + tmp.join(", ")); } } // limit - if (sql.hasOwnProperty("limit")) { - if (sql.hasOwnProperty("offset")) { - query.push("LIMIT " + sql.limit + " OFFSET " + sql.offset); - } else { - query.push("LIMIT " + sql.limit); + if (!sql.use_top) { + if (sql.hasOwnProperty("limit")) { + if (sql.hasOwnProperty("offset")) { + query.push("LIMIT " + sql.limit + " OFFSET " + sql.offset); + } else { + query.push("LIMIT " + sql.limit); + } + } else if (sql.hasOwnProperty("offset")) { + query.push("OFFSET " + sql.offset); } - } else if (sql.hasOwnProperty("offset")) { - query.push("OFFSET " + sql.offset); } return query.join(" "); diff --git a/lib/Select.js b/lib/Select.js index 3e9a8dc..7f2879f 100644 --- a/lib/Select.js +++ b/lib/Select.js @@ -17,7 +17,9 @@ function SelectQuery(Dialect) { order : [], group_by : null, found_rows : false, - where_exists : false + where_exists : false, + use_top : (Dialect.name === 'tds'), + manual_offset : (Dialect.name === 'tds') }; var get_table_alias = function (table) { for (var i = 0; i < sql.from.length; i++) { @@ -194,8 +196,44 @@ function SelectQuery(Dialect) { this.fun(fun_stack.pop()); } + // Calculate ORDER BY early, in case we need it for + // manual offset. + // + if (sql.group_by) { + sql.group_by.forEach(function (column) { + if (column[0] == "-") { + sql.order.unshift({ c: column.substr(1), d: "DESC" }); + } + }); + } + + order_by = []; + + if (sql.order.length > 0) { + for (i = 0; i < sql.order.length; i++) { + if (Array.isArray(sql.order[i].c)) { + order_by.push(Dialect.escapeId.apply(Dialect, sql.order[i].c) + " " + sql.order[i].d); + } else { + order_by.push(Dialect.escapeId(sql.order[i].c) + " " + sql.order[i].d); + } + } + } + + // TDS only - Manual Offset Workaround + if (sql.manual_offset && sql.hasOwnProperty("offset")) { + if (sql.use_top && sql.hasOwnProperty("limit")) + query.push("SELECT TOP " + sql.limit + " * FROM ("); + else + query.push("SELECT * FROM ("); + } + query.push("SELECT"); + // TDS only - TOP instead of LIMIT + if (sql.use_top && sql.hasOwnProperty("limit") && !sql.hasOwnProperty("offset")) { + query.push("TOP " + sql.limit); + } + for (i = 0; i < sql.from.length; i++) { sql.from[i].a = "t" + (i + 1); } @@ -288,8 +326,23 @@ function SelectQuery(Dialect) { query.push("SQL_CALC_FOUND_ROWS"); } + // Need to allow for TDS' manual offset, if necessary. Otherwise, + // we can just proceed with an unaltered SELECT stanza. + // + var row_number_clause; + + if (sql.manual_offset && sql.hasOwnProperty('offset')) { + row_number_clause = order_by.length > 0 ? order_by.join(", ") : "id ASC"; + } + if (tmp.length) { + if (sql.manual_offset && sql.hasOwnProperty('offset')) { + tmp.unshift("ROW_NUMBER() OVER (ORDER BY " + row_number_clause + ") AS p_RN") + } + query.push(tmp.join(", ")); + } else if (sql.manual_offset && sql.hasOwnProperty('offset')) { + query.push("ROW_NUMBER() OVER (ORDER BY " + row_number_clause + ") AS p_RN, *"); } else { query.push("*"); } @@ -349,31 +402,27 @@ function SelectQuery(Dialect) { }).join(", ")); } - // order - if (sql.order.length > 0) { - tmp = []; - for (i = 0; i < sql.order.length; i++) { - if (Array.isArray(sql.order[i].c)) { - tmp.push(Dialect.escapeId.apply(Dialect, sql.order[i].c) + " " + sql.order[i].d); - } else { - tmp.push(Dialect.escapeId(sql.order[i].c) + " " + sql.order[i].d); - } - } + // TDS only - Manual Offset Workaround + if (sql.manual_offset && sql.hasOwnProperty("offset")) { + query.push(") SQ WHERE p_RN > " + sql.offset); + } - if (tmp.length > 0) { - query.push("ORDER BY " + tmp.join(", ")); - } + // order + if (order_by.length > 0) { + query.push("ORDER BY " + order_by.join(", ")); } - // limit - if (sql.hasOwnProperty("limit")) { - if (sql.hasOwnProperty("offset")) { - query.push("LIMIT " + sql.limit + " OFFSET " + sql.offset); - } else { - query.push("LIMIT " + sql.limit); + // limit (non-TDS only!) + if (!sql.use_top) { + if (sql.hasOwnProperty("limit")) { + if (!sql.manual_offset && sql.hasOwnProperty("offset")) { + query.push("LIMIT " + sql.limit + " OFFSET " + sql.offset); + } else { + query.push("LIMIT " + sql.limit); + } + } else if (!sql.manual_offset && sql.hasOwnProperty("offset")) { + query.push("OFFSET " + sql.offset); } - } else if (sql.hasOwnProperty("offset")) { - query.push("OFFSET " + sql.offset); } return query.join(" "); diff --git a/lib/Where.js b/lib/Where.js index 1e2c7bb..b8deb91 100644 --- a/lib/Where.js +++ b/lib/Where.js @@ -154,7 +154,11 @@ function buildOrGroup(Dialect, where) { if (Array.isArray(where.w[k])) { if (where.w[k].length === 0) { // #274: IN with empty arrays should be a false sentence - query.push("FALSE"); + // + // "1=0" will still evaluate to false and plays nice with + // TDS. + // + query.push("1=0"); } else { query.push(buildComparisonKey(Dialect, where.t, k) + " IN " + Dialect.escapeVal(where.w[k])); } diff --git a/test/common.js b/test/common.js index 04a9ea6..e79b355 100644 --- a/test/common.js +++ b/test/common.js @@ -4,26 +4,26 @@ var Query = require('../'); common.Query = Query; common.Text = Query.Text; -common.Select = function () { - var q = new (Query.Query)(); +common.Select = function (dialect) { + var q = new (Query.Query)(dialect); return q.select(); }; -common.Insert = function () { - var q = new (Query.Query)(); +common.Insert = function (dialect) { + var q = new (Query.Query)(dialect); return q.insert(); }; -common.Update = function () { - var q = new (Query.Query)(); +common.Update = function (dialect) { + var q = new (Query.Query)(dialect); return q.update(); }; -common.Remove = function () { - var q = new (Query.Query)(); +common.Remove = function (dialect) { + var q = new (Query.Query)(dialect); return q.remove(); }; diff --git a/test/integration/test-dialect-tds.js b/test/integration/test-dialect-tds.js new file mode 100644 index 0000000..d869842 --- /dev/null +++ b/test/integration/test-dialect-tds.js @@ -0,0 +1,58 @@ +var common = require('../common'); +var assert = require('assert'); +var dialect = common.getDialect('tds'); + +assert.equal( + dialect.escapeId('col'), + "[col]" +); + +assert.equal( + dialect.escapeId('table', 'col'), + "[table].[col]" +); + +assert.equal( + dialect.escapeId('table', 'co[l'), + "[table].[co[[]l]" +); + +assert.equal( + dialect.escapeVal(undefined), + 'NULL' +); + +assert.equal( + dialect.escapeVal(null), + 'NULL' +); + +assert.equal( + dialect.escapeVal(123), + "123" +); + +assert.equal( + dialect.escapeVal('abc'), + "'abc'" +); + +assert.equal( + dialect.escapeVal('ab\'c'), + "'ab''c'" +); + +assert.equal( + dialect.escapeVal([ 1, 'abc', 'a\'' ]), + "(1, 'abc', 'a''')" +); + +assert.equal( + dialect.escapeVal(true), + "1" +); + +assert.equal( + dialect.escapeVal(false), + "0" +); diff --git a/test/integration/test-limit-offset-tds.js b/test/integration/test-limit-offset-tds.js new file mode 100644 index 0000000..4e9a7bb --- /dev/null +++ b/test/integration/test-limit-offset-tds.js @@ -0,0 +1,12 @@ +var common = require('../common'); +var assert = require('assert'); + +assert.equal( + common.Select('tds').from('table1').offset('123').limit('456').build(), + "SELECT TOP 456 * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY id ASC) AS p_RN, * FROM [table1] ) SQ WHERE p_RN > 123" +); + +assert.equal( + common.Select('tds').from('table1').offset('123').limit('456').order('col1').order('col2', 'Z').build(), + "SELECT TOP 456 * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY [col1] ASC, [col2] DESC) AS p_RN, * FROM [table1] ) SQ WHERE p_RN > 123 ORDER BY [col1] ASC, [col2] DESC" +); diff --git a/test/integration/test-limit.js b/test/integration/test-limit.js index 88c6fad..fa6c4d9 100644 --- a/test/integration/test-limit.js +++ b/test/integration/test-limit.js @@ -6,7 +6,17 @@ assert.equal( "SELECT * FROM `table1` LIMIT 123" ); +assert.equal( + common.Select('tds').from('table1').limit(123).build(), + "SELECT TOP 123 * FROM [table1]" +); + assert.equal( common.Select().from('table1').limit('123456789').build(), "SELECT * FROM `table1` LIMIT 123456789" ); + +assert.equal( + common.Select('tds').from('table1').limit('123456789').build(), + "SELECT TOP 123456789 * FROM [table1]" +); diff --git a/test/integration/test-offset.js b/test/integration/test-offset.js index 076d819..5eedb55 100644 --- a/test/integration/test-offset.js +++ b/test/integration/test-offset.js @@ -6,7 +6,17 @@ assert.equal( "SELECT * FROM `table1` OFFSET 3" ); +assert.equal( + common.Select('tds').from('table1').offset(3).build(), + "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY id ASC) AS p_RN, * FROM [table1] ) SQ WHERE p_RN > 3" +); + assert.equal( common.Select().from('table1').offset('123456789').build(), "SELECT * FROM `table1` OFFSET 123456789" ); + +assert.equal( + common.Select('tds').from('table1').offset('123456789').build(), + "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY id ASC) AS p_RN, * FROM [table1] ) SQ WHERE p_RN > 123456789" +); diff --git a/test/integration/test-remove.js b/test/integration/test-remove.js index af43856..aba1dd3 100644 --- a/test/integration/test-remove.js +++ b/test/integration/test-remove.js @@ -26,17 +26,37 @@ assert.equal( "DELETE FROM `table1` LIMIT 10" ); +assert.equal( + common.Remove('tds').from('table1').limit(10).build(), + "DELETE TOP (10) FROM [table1]" +); + assert.equal( common.Remove().from('table1').limit(10).offset(3).build(), "DELETE FROM `table1` LIMIT 10 OFFSET 3" ); +assert.equal( + common.Remove('tds').from('table1').limit(10).offset(3).build(), + "DELETE TOP (10) FROM [table1]" +); + assert.equal( common.Remove().from('table1').order('col').limit(5).build(), "DELETE FROM `table1` ORDER BY `col` ASC LIMIT 5" ); +assert.equal( + common.Remove('tds').from('table1').order('col').limit(5).build(), + "DELETE TOP (5) FROM [table1]" +); + assert.equal( common.Remove().from('table1').order('col1', 'A').order('col2', 'Z').limit(5).build(), "DELETE FROM `table1` ORDER BY `col1` ASC, `col2` DESC LIMIT 5" ); + +assert.equal( + common.Remove('tds').from('table1').order('col1', 'A').order('col2', 'Z').limit(5).build(), + "DELETE TOP (5) FROM [table1]" +); diff --git a/test/integration/test-where.js b/test/integration/test-where.js index c199ffd..a110fd6 100644 --- a/test/integration/test-where.js +++ b/test/integration/test-where.js @@ -73,7 +73,7 @@ assert.equal( assert.equal( common.Select().from('table1').where({ col: [] }).build(), - "SELECT * FROM `table1` WHERE FALSE" + "SELECT * FROM `table1` WHERE 1=0" ); assert.equal(