From 78f3221e30cbebf7828ef430e29ae27be0794e68 Mon Sep 17 00:00:00 2001 From: brianc Date: Sat, 23 Mar 2013 19:08:40 -0500 Subject: [PATCH] allow SELECT/FROM/WHERE in any order --- lib/dialect/postgres.js | 59 ++++++++++++++++++++------ lib/table.js | 8 +++- package.json | 2 +- test/dialects/clause-ordering-tests.js | 22 ++++++++++ test/dialects/shortcut-tests.js | 18 ++++---- 5 files changed, 84 insertions(+), 25 deletions(-) create mode 100644 test/dialects/clause-ordering-tests.js diff --git a/lib/dialect/postgres.js b/lib/dialect/postgres.js index 4f1b03d..dde76e1 100644 --- a/lib/dialect/postgres.js +++ b/lib/dialect/postgres.js @@ -3,6 +3,7 @@ var util = require('util'); var assert = require('assert'); var From = require(__dirname + '/../node/from'); +var Select = require(__dirname + '/../node/select'); var Parameter = require(__dirname + '/../node/parameter'); var Postgres = function() { this.output = []; @@ -70,7 +71,6 @@ Postgres.prototype.visitSelect = function(select) { Postgres.prototype.visitInsert = function(insert) { var self = this; - this._visitedFrom = true; //don't use table.column for inserts this._visitedInsert = true; @@ -98,7 +98,6 @@ Postgres.prototype.visitInsert = function(insert) { Postgres.prototype.visitUpdate = function(update) { //don't auto-generate from clause - this._visitedFrom = true; var params = []; /*jshint boss: true */ for(var i = 0, node; node = update.nodes[i]; i++) { @@ -124,7 +123,6 @@ Postgres.prototype.visitDelete = function() { Postgres.prototype.visitCreate = function(create) { this._visitingCreate = true; //don't auto-generate from clause - this._visitedFrom = true; var table = this._queryNode.table; var col_nodes = table.columns.map(function(col) { return col.toNode(); }); @@ -138,7 +136,6 @@ Postgres.prototype.visitCreate = function(create) { Postgres.prototype.visitDrop = function(drop) { //don't auto-generate from clause - this._visitedFrom = true; var result = ['DROP TABLE']; result = result.concat(drop.nodes.map(this.visit.bind(this))); result.push(this.visit(this._queryNode.table.toNode())); @@ -148,7 +145,6 @@ Postgres.prototype.visitDrop = function(drop) { Postgres.prototype.visitAlter = function(alter) { this._visitingAlter = true; //don't auto-generate from clause - this._visitedFrom = true; var table = this._queryNode.table; var col_nodes = table.columns.map(function(col) { return col.toNode(); }); var result = [ @@ -161,7 +157,6 @@ Postgres.prototype.visitAlter = function(alter) { }; Postgres.prototype.visitFrom = function(from) { - this._visitedFrom = true; var result = []; result.push('FROM'); for(var i = 0; i < from.nodes.length; i++) { @@ -214,17 +209,53 @@ Postgres.prototype.visitUnary = function(unary) { Postgres.prototype.visitQuery = function(queryNode) { this._queryNode = queryNode; - for(var i = 0; i < queryNode.nodes.length; i ++) { - var res = this.visit(queryNode.nodes[i]); + //need to sort the top level query nodes on visitation priority + //so select/insert/update/delete comes before from comes before where + var sortedNodes = []; + var missingFrom = true; + var actions = []; + var targets = []; + var filters = []; + for(var i = 0; i < queryNode.nodes.length; i++) { + var node = queryNode.nodes[i]; + switch(node.type) { + case "SELECT": + case "DELETE": + actions.push(node); + break; + case "INSERT": + case "UPDATE": + case "CREATE": + case "DROP": + case "ALTER": + actions.push(node); + missingFrom = false; + break; + case "FROM": + missingFrom = false; + targets.push(node); + break; + default: + filters.push(node); + break; + } + } + if(!actions.length) { + console.log('missing select') + //if no actions are given, guess it's a select + actions.push(new Select().add('*')); + } + if(missingFrom) { + console.log('missing from') + targets.push(new From().add(queryNode.table)); + } + //lazy-man sorting + var sortedNodes = actions.concat(targets).concat(filters); + for(var i = 0; i < sortedNodes.length; i++) { + var res = this.visit(sortedNodes[i]); this.output = this.output.concat(res); } //implicit 'from' - if(!this._visitedFrom) { - var select = this.output.slice(0, this._selectOrDeleteEndIndex); - var from = this.visitFrom(new From().add(queryNode.table.toNode())); - var rest = this.output.slice(this._selectOrDeleteEndIndex); - this.output = select.concat(from).concat(rest); - } return this; }; diff --git a/lib/table.js b/lib/table.js index 4d35348..0e821f8 100644 --- a/lib/table.js +++ b/lib/table.js @@ -70,6 +70,12 @@ Table.prototype.select = function() { return query; }; +Table.prototype.from = function() { + var query = new Query(this); + query.from.apply(query, arguments); + return query; +} + Table.prototype.subQuery = function(alias) { //create the query and pass it off var query = new Query(this); @@ -139,7 +145,7 @@ Table.prototype.__defineGetter__("nodes", function() { }); Table.prototype.where = function() { - var query = this.select(this.star()); + var query = new Query(this); query.where.apply(query, arguments); return query; }; diff --git a/package.json b/package.json index 9d8e170..1d88a34 100644 --- a/package.json +++ b/package.json @@ -2,7 +2,7 @@ "author": "brianc ", "name": "sql", "description": "sql builder", - "version": "0.7.1", + "version": "0.8.0", "homepage": "https://github.com/brianc/node-sql", "repository": { "type": "git", diff --git a/test/dialects/clause-ordering-tests.js b/test/dialects/clause-ordering-tests.js new file mode 100644 index 0000000..05a7518 --- /dev/null +++ b/test/dialects/clause-ordering-tests.js @@ -0,0 +1,22 @@ +'use strict'; + +var Harness = require('./support'); +var user = Harness.defineUserTable(); +var post = Harness.definePostTable(); + +//FROM - SELECT +Harness.test({ + query : user.from(user.join(post).on(user.id.equals(post.userId))).select(user.name, post.content), + pg : 'SELECT "user"."name", "post"."content" FROM "user" INNER JOIN "post" ON ("user"."id" = "post"."userId")', + sqlite: 'SELECT "user"."name", "post"."content" FROM "user" INNER JOIN "post" ON ("user"."id" = "post"."userId")', + mysql : 'SELECT `user`.`name`, `post`.`content` FROM `user` INNER JOIN `post` ON (`user`.`id` = `post`.`userId`)' +}); + +//WHERE - FROM - SELECT +Harness.test({ + query : user.where({name: ''}).from(user).select(user.id), + pg : 'SELECT "user"."id" FROM "user" WHERE ("user"."name" = $1)', + sqlite: 'SELECT "user"."id" FROM "user" WHERE ("user"."name" = $1)', + mysql : 'SELECT `user`.`id` FROM `user` WHERE (`user`.`name` = ?)', + params: [''] +}); diff --git a/test/dialects/shortcut-tests.js b/test/dialects/shortcut-tests.js index 6d87cfc..98952ed 100644 --- a/test/dialects/shortcut-tests.js +++ b/test/dialects/shortcut-tests.js @@ -14,17 +14,17 @@ Harness.test({ Harness.test({ query : user.where(user.name.equals(3)), - pg : 'SELECT "user".* FROM "user" WHERE ("user"."name" = $1)', - sqlite: 'SELECT "user".* FROM "user" WHERE ("user"."name" = $1)', - mysql : 'SELECT `user`.* FROM `user` WHERE (`user`.`name` = ?)', + pg : 'SELECT * FROM "user" WHERE ("user"."name" = $1)', + sqlite: 'SELECT * FROM "user" WHERE ("user"."name" = $1)', + mysql : 'SELECT * FROM `user` WHERE (`user`.`name` = ?)', params : [3] }); Harness.test({ query : user.where(user.name.equals(3)).where(user.id.equals(1)), - pg : 'SELECT "user".* FROM "user" WHERE (("user"."name" = $1) AND ("user"."id" = $2))', - sqlite: 'SELECT "user".* FROM "user" WHERE (("user"."name" = $1) AND ("user"."id" = $2))', - mysql : 'SELECT `user`.* FROM `user` WHERE ((`user`.`name` = ?) AND (`user`.`id` = ?))', + pg : 'SELECT * FROM "user" WHERE (("user"."name" = $1) AND ("user"."id" = $2))', + sqlite: 'SELECT * FROM "user" WHERE (("user"."name" = $1) AND ("user"."id" = $2))', + mysql : 'SELECT * FROM `user` WHERE ((`user`.`name` = ?) AND (`user`.`id` = ?))', params: [3,1] }); @@ -46,8 +46,8 @@ Harness.test({ Harness.test({ query : post.where(post.content.isNull()).or({content: ''}).and({userId: 1}), - pg : 'SELECT "post".* FROM "post" WHERE ((("post"."content" IS NULL) OR ("post"."content" = $1)) AND ("post"."userId" = $2))', - sqlite: 'SELECT "post".* FROM "post" WHERE ((("post"."content" IS NULL) OR ("post"."content" = $1)) AND ("post"."userId" = $2))', - mysql : 'SELECT `post`.* FROM `post` WHERE (((`post`.`content` IS NULL) OR (`post`.`content` = ?)) AND (`post`.`userId` = ?))', + pg : 'SELECT * FROM "post" WHERE ((("post"."content" IS NULL) OR ("post"."content" = $1)) AND ("post"."userId" = $2))', + sqlite: 'SELECT * FROM "post" WHERE ((("post"."content" IS NULL) OR ("post"."content" = $1)) AND ("post"."userId" = $2))', + mysql : 'SELECT * FROM `post` WHERE (((`post`.`content` IS NULL) OR (`post`.`content` = ?)) AND (`post`.`userId` = ?))', params: ['', 1] });