├── .gitignore ├── README.md ├── showcase.js ├── sql.js └── sql.ts /.gitignore: -------------------------------------------------------------------------------- 1 | *~ 2 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Sqlata 2 | ====== 3 | 4 | I was looking for an SQL builder for Node.js, but I couldn't find something that suited my needs (that's usual to hear in this world, right?). 5 | 6 | If you know anything that is similar to this project, please let me know. 7 | Otherwise I'll keep developing this one for my (yet) pet project. 8 | 9 | So these are the rules: 10 | 11 | - A table, alias, query, or in general *relations* (as in relational algebra) are **Buildable**. 12 | - A relation field or an applied SQL function/operator are **Expression** (which are **Buildable**) 13 | - Everything else is a **Parameter** (which are **Expression**) 14 | - It must read almost like SQL. 15 | - It must be very easy to expand. 16 | 17 | All of the examples below are in `showcase.js`. 18 | 19 | Tables 20 | ------ 21 | 22 | Start defining a couple of tables: 23 | 24 | ```javascript 25 | var Sql = require('./sql'); 26 | var user = Sql.table("user"); 27 | var article = Sql.table("article"); 28 | console.log(user.build()); 29 | ``` 30 | 31 | ```javascript 32 | { params: [], text: 'user' } 33 | ``` 34 | 35 | The `build()` method returns an object with the SQL (not necessarily correct) `text` and its `params`. 36 | 37 | Select from 38 | ----------- 39 | 40 | ```javascript 41 | var q = Sql.query().SELECT(user.star()).FROM(user); 42 | console.log(q.build().text); 43 | ``` 44 | 45 | ```sql 46 | (SELECT (user.*) FROM user) 47 | ``` 48 | 49 | Ok that's valid SQL, even with the extra parenthesis. 50 | 51 | Aliases 52 | ------- 53 | 54 | ```javascript 55 | var a = article.alias(); 56 | var q = Sql.query().DISTINCT().SELECT(a.f("user_id")).FROM(a); 57 | console.log(q.build().text); 58 | ``` 59 | 60 | ```sql 61 | (SELECT DISTINCT (t1.user_id) FROM article AS t1) 62 | ``` 63 | 64 | I really **don't** want to care about alias names. 65 | 66 | Join 67 | ---- 68 | 69 | ```javascript 70 | var u1 = user.alias(); 71 | var u2 = user.alias(); 72 | var q = Sql.query() 73 | .SELECT(u1.f("id"), u2.f("id")) 74 | .FROM(u1) 75 | .JOIN(u2, u1.f("name").EQ(u2.f("name")), "LEFT"); 76 | console.log(q.build().text); 77 | ``` 78 | 79 | ```sql 80 | (SELECT (t1.id), (t2.id) FROM user AS t1 81 | LEFT JOIN user AS t2 ON ((t1.name) = (t2.name))) 82 | ``` 83 | 84 | Params 85 | ------ 86 | 87 | ```javascript 88 | var a = article.alias(); 89 | var q = Sql.query().SELECT(a.f("title")).FROM(a).WHERE(a.f("user_id").EQ(123)); 90 | console.log(q.build()); 91 | ``` 92 | 93 | ```javascript 94 | { params: [ 123 ], 95 | text: '(SELECT (t1.title) FROM article AS t1 WHERE ((t1.user_id) = $1))' } 96 | ``` 97 | 98 | I really want to use parameters like that. 99 | 100 | Literals 101 | -------- 102 | 103 | When you don't want a parameter: 104 | 105 | ```javascript 106 | var a = article.alias(); 107 | var q = Sql.query().FROM(a).WHERE(a.f("id").EQ(Sql.literal(123))); 108 | console.log(q.build().text); 109 | ``` 110 | 111 | ```sql 112 | (SELECT * FROM article AS t1 WHERE ((t1.id) = 123)) 113 | ``` 114 | 115 | Literals are usually necessary only to extend SQL syntax. 116 | 117 | Functions 118 | --------- 119 | 120 | ```javascript 121 | var a = article.alias(); 122 | var q = Sql.query().SELECT(Sql.count(a.f("user_id").DISTINCT())).FROM(a); 123 | console.log(q.build().text); 124 | ``` 125 | 126 | ```sql 127 | (SELECT COUNT(DISTINCT (t1.user_id)) FROM article AS t1) 128 | ``` 129 | 130 | That method `distinct` is not proper but it's quite convenient. 131 | 132 | Lists 133 | ----- 134 | 135 | ```javascript 136 | var u = user.alias(); 137 | var q = Sql.query().FROM(u).WHERE(u.f("id").IN([2,4,6])); 138 | console.log(q.build()); 139 | ``` 140 | 141 | ```javascript 142 | { params: [ 2, 4, 6 ], text: '(SELECT * FROM user AS t1 WHERE ((t1.id) IN ($1,$2,$3)))' } 143 | ``` 144 | 145 | Composing 146 | --------- 147 | 148 | ```javascript 149 | var joinArticles = function(q, u) { 150 | var a = article.alias(); 151 | q.JOIN(a, a.f("user_id").EQ(u.f("id"))); 152 | return a; 153 | }; 154 | var fooArticles = a => a.f("title").LIKE("%foo%"); 155 | 156 | var u = user.alias(); 157 | var q = Sql.query().DISTINCT().FROM(u); 158 | var a = joinArticles(q, u); 159 | q.WHERE(fooArticles(a)); 160 | console.log(q.build().text); 161 | ``` 162 | 163 | ```sql 164 | (SELECT DISTINCT * FROM user AS t1 165 | INNER JOIN article AS t2 ON ((t2.user_id) = (t1.id)) 166 | WHERE ((t2.title) LIKE $1)) 167 | 168 | ``` 169 | 170 | You may have more useful plans though. 171 | 172 | Sharing parameters 173 | ------------------ 174 | 175 | In case you use the same parameter in more than one place: 176 | 177 | ```javascript 178 | var u = user.alias(); 179 | var email = Sql.param("foo@foo"); 180 | var q = Sql.query().FROM(u).WHERE(u.f("login").EQ(email).OR(u.f("contact").EQ(email))); 181 | console.log(q.build()); 182 | ``` 183 | 184 | ```javascript 185 | { params: [ 'foo@foo' ], 186 | text: '(SELECT * FROM user AS t1 WHERE (((t1.login) = $1) OR ((t1.contact) = $1)))' } 187 | ``` 188 | 189 | Complex example with custom functions 190 | ------------------------------------- 191 | 192 | Users within 200 meters from a point, and json aggregate of their articles. Works with PostgreSQL. 193 | 194 | ```javascript 195 | Sql.ST_Distance = Sql.func("ST_Distance"); 196 | Sql.ST_SetSRID = Sql.func("ST_SetSRID"); 197 | Sql.ST_POINT = Sql.func("ST_POINT"); 198 | Sql.COALESCE = Sql.func("COALESCE"); 199 | Sql.NULLIF = Sql.func("NULLIF"); 200 | Sql.json_agg = Sql.func("json_agg"); 201 | Sql.fixed_json_agg = e => Sql.COALESCE(Sql.NULLIF(Sql.json_agg(e).cast("TEXT"), 202 | Sql.literal("'[null]'")), 203 | Sql.literal("'[]'")).cast("JSON"); 204 | 205 | var loc = { lat: 41.90278, lng: 12.49636 }; 206 | 207 | var u = user.alias(); 208 | var a = article.alias(); 209 | var q = Sql.query() 210 | .SELECT(u.star(), Sql.fixed_json_agg(a.star()).alias("articles")) 211 | .FROM(u) 212 | .JOIN(a, a.f("user_id").EQ(u.f("id"))) 213 | .GROUP(u.f("id")) 214 | .ORDER(u.f("name")) 215 | .LIMIT(10); 216 | 217 | var distance = Sql.ST_Distance(Sql.ST_SetSRID(Sql.ST_POINT(loc.lng, loc.lat), 4326), 218 | u.f("address"), true); 219 | q 220 | .SELECT(distance.alias("distance")) 221 | .WHERE(distance.LE(200)); 222 | console.log(q.build().text); 223 | ``` 224 | 225 | ```sql 226 | (SELECT (t1.*), (CAST (COALESCE(NULLIF((CAST (json_agg((t2.*)) AS TEXT)), '[null]'), '[]') AS JSON)) AS articles, 227 | ST_Distance(ST_SetSRID(ST_POINT($1, $2), $3), (t1.address), $4) AS distance 228 | FROM user AS t1 229 | INNER JOIN article AS t2 ON ((t2.user_id) = (t1.id)) 230 | WHERE (ST_Distance(ST_SetSRID(ST_POINT($1, $2), $3), (t1.address), $4) <= $5) 231 | GROUP BY (t1.id) ORDER BY (t1.name) ASC LIMIT 10) 232 | ``` 233 | 234 | Simple concepts, powerful tool. 235 | 236 | Note: the `fixed_json_agg` is because of this [annoying bug](http://stackoverflow.com/a/27179265/471622). 237 | 238 | Insert/Update 239 | ------------- 240 | 241 | ```javascript 242 | var ins = Sql.insert(user).set({ name: "foo" }).set("bio", "some info ehre").returning("id"); 243 | var upd = Sql.update(user).set("bio", "some info here").where(user.f("id").EQ(321)); 244 | console.log(ins.build()); 245 | console.log(upd.build()); 246 | ``` 247 | 248 | ```javascript 249 | { params: [ 'foo', 'some info ehre' ], 250 | text: 'INSERT INTO user (name, bio) VALUES ($1, $2) RETURNING id' } 251 | { params: [ 'some info here', 321 ], 252 | text: 'UPDATE user SET bio=$1 WHERE ((user.id) = $2)' } 253 | ``` 254 | 255 | TODO 256 | ==== 257 | 258 | More ANSI functions and operators. Support UNION, INTERSECT and anything else. Everything else. 259 | 260 | Packaging 261 | ========= 262 | 263 | I never packaged something for npm or bower, if you like to please file a PR. I will accept whatever. 264 | -------------------------------------------------------------------------------- /showcase.js: -------------------------------------------------------------------------------- 1 | // Tables 2 | var Sql = require('./sql'); 3 | var user = Sql.table("user"); 4 | var article = Sql.table("article"); 5 | console.log(user.build()); 6 | 7 | // Select from 8 | var q = Sql.query().SELECT(user.star()).FROM(user); 9 | console.log(q.build().text); 10 | 11 | // Aliases 12 | var a = article.alias(); 13 | var q = Sql.query().DISTINCT().SELECT(a.f("user_id")).FROM(a); 14 | console.log(q.build().text); 15 | 16 | // Join 17 | var u1 = user.alias(); 18 | var u2 = user.alias(); 19 | var q = Sql.query().SELECT(u1.f("id"), u2.f("id")).FROM(u1).JOIN(u2, u1.f("name").EQ(u2.f("name")), "LEFT"); 20 | console.log(q.build().text); 21 | 22 | // Params 23 | var a = article.alias(); 24 | var q = Sql.query().SELECT(a.f("title")).FROM(a).WHERE(a.f("user_id").EQ(123)); 25 | console.log(q.build()); 26 | 27 | // Literals 28 | var a = article.alias(); 29 | var q = Sql.query().FROM(a).WHERE(a.f("id").EQ(Sql.literal(123))); 30 | console.log(q.build().text); 31 | 32 | // Functions 33 | var a = article.alias(); 34 | var q = Sql.query().SELECT(Sql.count(a.f("user_id").DISTINCT())).FROM(a); 35 | console.log(q.build().text); 36 | 37 | // Lists 38 | var u = user.alias(); 39 | var q = Sql.query().FROM(u).WHERE(u.f("id").IN([2,4,6])); 40 | console.log(q.build()); 41 | 42 | // Composing 43 | var joinArticles = function(q, u) { 44 | var a = article.alias(); 45 | q.JOIN(a, a.f("user_id").EQ(u.f("id"))); 46 | return a; 47 | }; 48 | var fooArticles = a => a.f("title").LIKE("%foo%"); 49 | var u = user.alias(); 50 | var q = Sql.query().DISTINCT().FROM(u); 51 | var a = joinArticles(q, u); 52 | q.WHERE(fooArticles(a)); 53 | console.log(q.build().text); 54 | 55 | // Sharing parameters 56 | var u = user.alias(); 57 | var email = Sql.param("foo@foo"); 58 | var q = Sql.query().FROM(u).WHERE(u.f("login").EQ(email).OR(u.f("contact").EQ(email))); 59 | console.log(q.build()); 60 | 61 | // Complex example with custom functions 62 | Sql.ST_Distance = Sql.func("ST_Distance"); 63 | Sql.ST_SetSRID = Sql.func("ST_SetSRID"); 64 | Sql.ST_POINT = Sql.func("ST_POINT"); 65 | Sql.COALESCE = Sql.func("COALESCE"); 66 | Sql.NULLIF = Sql.func("NULLIF"); 67 | Sql.json_agg = Sql.func("json_agg"); 68 | Sql.fixed_json_agg = e => Sql.COALESCE(Sql.NULLIF(Sql.json_agg(e).cast("TEXT"), Sql.literal("'[null]'")), Sql.literal("'[]'")).cast("JSON"); 69 | 70 | var loc = { lat: 41.90278, lng: 12.49636 }; 71 | 72 | var u = user.alias(); 73 | var a = article.alias(); 74 | var q = Sql.query() 75 | .SELECT(u.star(), Sql.fixed_json_agg(a.star()).alias("articles")) 76 | .FROM(u) 77 | .JOIN(a, a.f("user_id").EQ(u.f("id"))) 78 | .GROUP(u.f("id")) 79 | .ORDER(u.f("name")) 80 | .LIMIT(10); 81 | 82 | var distance = Sql.ST_Distance(Sql.ST_SetSRID(Sql.ST_POINT(loc.lng, loc.lat), 4326), u.f("address"), true); 83 | q 84 | .SELECT(distance.alias("distance")) 85 | .WHERE(distance.LE(200)); 86 | console.log(q.build().text); 87 | 88 | // Insert/Update 89 | var ins = Sql.insert(user).set({ name: "foo" }).set("bio", "some info ehre").returning("id"); 90 | var upd = Sql.update(user).set("bio", "some info here").where(user.f("id").EQ(321)); 91 | console.log(ins.build()); 92 | console.log(upd.build()); 93 | -------------------------------------------------------------------------------- /sql.js: -------------------------------------------------------------------------------- 1 | /* UTILS */ 2 | "use strict"; 3 | function extendProto(o1, o2) { 4 | for (var k in o2) { 5 | if (!o1[k]) { 6 | o1[k] = o2[k]; 7 | } 8 | } 9 | } 10 | function uppercaseProto(proto) { 11 | for (var k in proto) { 12 | if (k != "toString" && k != "build") { 13 | proto[k.toUpperCase()] = proto[k]; 14 | } 15 | } 16 | } 17 | function argsToArray(args) { 18 | return Array.prototype.slice.call(args); 19 | } 20 | function pushMany(a, list) { 21 | Array.prototype.push.apply(a, list); 22 | } 23 | /* SQL BUILDER */ 24 | var BuildableProto = { 25 | _sql_buildable: true, 26 | alias: function (name) { 27 | return Sql.alias(this, name); 28 | }, 29 | build: function (startPos) { 30 | var state = { params: [], nextAlias: 1, nextPos: 1, text: undefined }; 31 | this.buildStep(state); 32 | state.text = this.toString(); 33 | return state; 34 | }, 35 | buildStep: function (state) { 36 | if (this.buildApply) { 37 | this.buildApply(state); 38 | } 39 | this.buildChildren(state); 40 | }, 41 | buildChildren: function (state) { 42 | this._children.forEach(function (child) { 43 | child.buildStep(state); 44 | }); 45 | } 46 | }; 47 | /* TABLE*/ 48 | var Table = function (name) { 49 | this.name = name; 50 | this.literal = Sql.literal(name); 51 | }; 52 | Table.prototype = { 53 | _children: [], 54 | f: function (field) { 55 | return this.literal.f(Sql.literal(field)); 56 | }, 57 | star: function () { 58 | return this.f("*"); 59 | }, 60 | toString: function () { 61 | return this.name; 62 | } 63 | }; 64 | extendProto(Table.prototype, BuildableProto); 65 | var Alias = function (rel, name) { 66 | this.rel = rel; 67 | this._children = [rel]; 68 | this._applied = !!name; 69 | if (!name) { 70 | name = "a?"; 71 | } 72 | this.alias = Sql.literal(name); 73 | }; 74 | Alias.prototype = { 75 | f: function (field) { 76 | return this.alias.f(Sql.literal(field)); 77 | }, 78 | star: function () { 79 | return this.f("*"); 80 | }, 81 | buildApply: function (state) { 82 | if (this._applied) { 83 | return; 84 | } 85 | this.alias.literal = "t" + (state.nextAlias++); 86 | this._applied = true; 87 | }, 88 | toString: function () { 89 | return `${this.rel} AS ${this.alias}`; 90 | } 91 | }; 92 | extendProto(Alias.prototype, BuildableProto); 93 | /* QUERY */ 94 | var Join = function (expr, cond, type) { 95 | this.expr = expr; 96 | this.cond = cond; 97 | this.type = type || "INNER"; 98 | }; 99 | Join.prototype = { 100 | toString: function () { 101 | return `${this.type} JOIN ${this.expr} ON ${this.cond}`; 102 | } 103 | }; 104 | var Order = function (expr, dir) { 105 | this.expr = expr; 106 | this.dir = dir || "ASC"; 107 | }; 108 | Order.prototype = { 109 | toString: function () { 110 | return `${this.expr} ${this.dir}`; 111 | } 112 | }; 113 | var Query = function () { 114 | this._children = []; 115 | this._distinct = false; 116 | this._select = []; 117 | this._from = []; 118 | this._join = []; 119 | this._offset = null; 120 | this._limit = null; 121 | this._order = []; 122 | this._group = []; 123 | this._where = []; 124 | }; 125 | Query.prototype = { 126 | select: function () { 127 | var exprs = makeChildren(argsToArray(arguments)); 128 | pushMany(this._select, exprs); 129 | pushMany(this._children, exprs); 130 | return this; 131 | }, 132 | from: function () { 133 | var exprs = makeChildren(argsToArray(arguments)); 134 | pushMany(this._from, exprs); 135 | pushMany(this._children, exprs); 136 | return this; 137 | }, 138 | join: function (expr, cond, type) { 139 | this._join.push(new Join(expr, cond, type)); 140 | this._children.push(expr); 141 | this._children.push(cond); 142 | return this; 143 | }, 144 | order: function (expr, dir) { 145 | expr = makeChild(expr); 146 | this._order.push(new Order(expr, dir)); 147 | this._children.push(expr); 148 | return this; 149 | }, 150 | group: function () { 151 | var exprs = makeChildren(argsToArray(arguments)); 152 | pushMany(this._group, exprs); 153 | pushMany(this._children, exprs); 154 | return this; 155 | }, 156 | where: function (expr) { 157 | expr = makeChild(expr); 158 | this._where.push(expr); 159 | this._children.push(expr); 160 | return this; 161 | }, 162 | limit: function (lit) { 163 | this._limit = Sql.literal(lit); 164 | return this; 165 | }, 166 | offset: function (lit) { 167 | this._offset = Sql.literal(lit); 168 | return this; 169 | }, 170 | toString: function () { 171 | var select = this._select.length ? 'SELECT ' + this._select.join(', ') : 'SELECT *'; 172 | var from = this._from.length ? ' FROM ' + this._from.join(', ') : ''; 173 | var join = this._join.length ? ' ' + this._join.join(' ') : ''; 174 | var where = this._where.length ? ' WHERE ' + this._where.join(' AND ') : ''; 175 | var group = this._group.length ? ' GROUP BY ' + this._group.join(', ') : ''; 176 | var order = this._order.length ? ' ORDER BY ' + this._order.join(', ') : ''; 177 | var limit = this._limit !== null ? ' LIMIT ' + this._limit : ''; 178 | var offset = this._offset !== null ? ' OFFSET ' + this._offset : ''; 179 | return `(${select}${from}${join}${where}${group}${order}${limit}${offset})`; 180 | }, 181 | }; 182 | uppercaseProto(Query.prototype); 183 | extendProto(Query.prototype, BuildableProto); 184 | /* INSERT */ 185 | var Insert = function (rel) { 186 | this._children = [rel]; 187 | this.rel = rel; 188 | this._data = {}; 189 | this._returning = []; 190 | }; 191 | Insert.prototype = { 192 | set: function (col, val) { 193 | if (typeof col == "string") { 194 | val = makeChild(val); 195 | this._data[col] = val; 196 | this._children.push(val); 197 | } 198 | else { 199 | for (var k in col) { 200 | val = makeChild(col[k]); 201 | this._data[k] = val; 202 | this._children.push(val); 203 | } 204 | } 205 | return this; 206 | }, 207 | returning: function () { 208 | var args = argsToArray(arguments); 209 | this._returning = args; 210 | return this; 211 | }, 212 | toString: function () { 213 | var cols = []; 214 | var values = []; 215 | for (var k in this._data) { 216 | cols.push(k); 217 | values.push(this._data[k]); 218 | } 219 | var colstr = cols.join(', '); 220 | var valuestr = values.join(', '); 221 | var returning = this._returning.length ? ' RETURNING ' + (this._returning.join(', ')) : ''; 222 | return `INSERT INTO ${this.rel} (${colstr}) VALUES (${valuestr})${returning}`; 223 | }, 224 | }; 225 | uppercaseProto(Insert.prototype); 226 | extendProto(Insert.prototype, BuildableProto); 227 | /* UPDATE */ 228 | var Update = function (rel) { 229 | this._children = [rel]; 230 | this.rel = rel; 231 | this._data = {}; 232 | this._where = []; 233 | this._returning = []; 234 | }; 235 | Update.prototype = { 236 | set: Insert.prototype.set, 237 | returning: Insert.prototype.returning, 238 | where: Query.prototype.where, 239 | toString: function () { 240 | var updates = []; 241 | for (var k in this._data) { 242 | updates.push(k + '=' + this._data[k]); 243 | } 244 | var updatestr = updates.join(', '); 245 | var where = this._where.length ? ' WHERE ' + this._where.join(' AND ') : ''; 246 | var returning = this._returning.length ? ' RETURNING ' + (this._returning.join(', ')) : ''; 247 | return `UPDATE ${this.rel} SET ${updatestr}${where}${returning}`; 248 | }, 249 | }; 250 | uppercaseProto(Update.prototype); 251 | extendProto(Update.prototype, BuildableProto); 252 | /* DELETE */ 253 | var Delete = function (rel) { 254 | this._children = [rel]; 255 | this.rel = rel; 256 | this._where = []; 257 | }; 258 | Delete.prototype = { 259 | where: Query.prototype.where, 260 | toString: function () { 261 | if (!this._where.length) { 262 | throw new Error("Mass delete forbidden"); 263 | } 264 | var where = this._where.length ? ' WHERE ' + this._where.join(' AND ') : ''; 265 | return `DELETE FROM ${this.rel}${where}`; 266 | }, 267 | }; 268 | uppercaseProto(Delete.prototype); 269 | extendProto(Delete.prototype, BuildableProto); 270 | /* EXPRESSIONS */ 271 | function makeChild(child, literalArgs) { 272 | if (Array.isArray(child)) { 273 | var list = { _children: makeChildren(child) }; 274 | list.__proto__ = { 275 | toString: () => `(${list._children.join(',')})` 276 | }; 277 | extendProto(list.__proto__, ExpressionProto); 278 | return list; 279 | } 280 | if (!child || !child._sql_buildable) { 281 | if (literalArgs) { 282 | return Sql.literal(child); 283 | } 284 | else { 285 | return Sql.param(child); 286 | } 287 | } 288 | return child; 289 | } 290 | function makeChildren(children, literalArgs) { 291 | return children.map(function (child) { 292 | return makeChild(child, literalArgs); 293 | }); 294 | } 295 | function metaExpr(f, literalArgs) { 296 | return function () { 297 | var self = this; 298 | var args = Array.prototype.slice.call(arguments); 299 | args = makeChildren(args, literalArgs); 300 | var o = { _children: [self].concat(args) }; 301 | o.__proto__ = { 302 | toString: function () { 303 | return f.apply(null, o._children); 304 | } 305 | }; 306 | extendProto(o.__proto__, ExpressionProto); 307 | return o; 308 | }; 309 | } 310 | var ExpressionProto = { 311 | not: metaExpr(e => `(NOT ${e})`), 312 | and: metaExpr((l, r) => `(${l} AND ${r})`), 313 | or: metaExpr((l, r) => `(${l} OR ${r})`), 314 | between: metaExpr((e, l, r) => `(${e} BETWEEN ${l} AND ${r})`), 315 | lt: metaExpr((l, r) => `(${l} < ${r})`), 316 | le: metaExpr((l, r) => `(${l} <= ${r})`), 317 | gt: metaExpr((l, r) => `(${l} > ${r})`), 318 | ge: metaExpr((l, r) => `(${l} >= ${r})`), 319 | eq: metaExpr((l, r) => `(${l} = ${r})`), 320 | ne: metaExpr((l, r) => `(${l} != ${r})`), 321 | in: metaExpr((l, r) => `(${l} IN ${r})`), 322 | plus: metaExpr((l, r) => `(${l} + ${r})`), 323 | minus: metaExpr((l, r) => `(${l} - ${r})`), 324 | mult: metaExpr((l, r) => `(${l} * ${r})`), 325 | extract: metaExpr((d, f) => `(EXTRACT (${f} FROM ${d}))`, true), 326 | cast: metaExpr((e, t) => `(CAST (${e} AS ${t}))`, true), 327 | isnull: metaExpr(e => `(${e} IS NULL)`), 328 | notnull: metaExpr(e => `(${e} IS NOT NULL)`), 329 | exists: metaExpr(e => `(EXISTS ${e})`), 330 | notexists: metaExpr(e => `(NOT EXISTS ${e})`), 331 | distinct: metaExpr(e => `DISTINCT ${e}`), 332 | f: metaExpr((e, f) => `(${e}.${f})`) 333 | }; 334 | uppercaseProto(ExpressionProto); 335 | extendProto(ExpressionProto, BuildableProto); 336 | /* CASE */ 337 | var When = function (cond, then) { 338 | this.cond = cond; 339 | this.then = then; 340 | }; 341 | When.prototype = { 342 | toString: function () { 343 | return `WHEN ${this.cond} THEN ${this.then}`; 344 | } 345 | }; 346 | var Case = function () { 347 | this._children = []; 348 | this._when = []; 349 | this._else = null; 350 | }; 351 | Case.prototype = { 352 | when: function (cond, then) { 353 | cond = makeChild(cond); 354 | then = makeChild(then); 355 | this._when.push(new When(cond, then)); 356 | this._children.push(cond); 357 | this._children.push(then); 358 | return this; 359 | }, 360 | otherwise: function (expr) { 361 | expr = makeChild(expr); 362 | this._else = expr; 363 | this._children.push(expr); 364 | return this; 365 | }, 366 | toString: function () { 367 | var when = this._when.join(" "); 368 | var otherwise = this._else ? ' ELSE ' + this._else : ''; 369 | return `CASE ${when}${otherwise} END`; 370 | } 371 | }; 372 | extendProto(Case.prototype, ExpressionProto); 373 | /* PARAMETER */ 374 | var Param = function (value) { 375 | this.param = "p?"; 376 | this.value = value; 377 | }; 378 | Param.prototype = { 379 | _children: [], 380 | buildApply: function (state) { 381 | if (!this._applied) { 382 | this.param = '$' + (state.nextPos++); 383 | state.params.push(this.value); 384 | } 385 | this._applied = true; 386 | }, 387 | toString: function () { 388 | return this.param; 389 | } 390 | }; 391 | extendProto(Param.prototype, ExpressionProto); 392 | /* LITERAL */ 393 | var Literal = function (lit) { 394 | this.literal = lit; 395 | }; 396 | Literal.prototype = { 397 | _children: [], 398 | toString: function () { return this.literal; } 399 | }; 400 | extendProto(Literal.prototype, ExpressionProto); 401 | /* FUNCTION CALL */ 402 | var Funcall = function (name, args) { 403 | this.name = name; 404 | this._children = makeChildren(args); 405 | }; 406 | Funcall.prototype = { 407 | toString: function () { 408 | var args = this._children.join(', '); 409 | return `${this.name}(${args})`; 410 | } 411 | }; 412 | extendProto(Funcall.prototype, ExpressionProto); 413 | var Sql = { 414 | query: function () { 415 | return new Query(); 416 | }, 417 | insert: function (rel) { 418 | return new Insert(rel); 419 | }, 420 | update: function (rel) { 421 | return new Update(rel); 422 | }, 423 | deleteFrom: function (rel) { 424 | return new Delete(rel); 425 | }, 426 | alias: function (rel, name) { 427 | return new Alias(rel, name); 428 | }, 429 | table: function (name) { 430 | return new Table(name); 431 | }, 432 | param: function (val) { 433 | return new Param(val); 434 | }, 435 | literal: function (lit) { 436 | return new Literal(lit); 437 | }, 438 | func: function (name) { 439 | return function () { 440 | return new Funcall(name, Array.prototype.slice.call(arguments)); 441 | }; 442 | }, 443 | when: function (cond, then) { 444 | return new Case().when(cond, then); 445 | }, 446 | metaExpr: metaExpr 447 | }; 448 | /* COMMON FUNCTIONS */ 449 | Sql.now = Sql.func("now"); 450 | Sql.count = Sql.func("count"); 451 | module.exports = Sql; 452 | //# sourceMappingURL=sql.js.map -------------------------------------------------------------------------------- /sql.ts: -------------------------------------------------------------------------------- 1 | /* UTILS */ 2 | 3 | function extendProto(o1, o2) { 4 | for (var k in o2) { 5 | if (!o1[k]) { 6 | o1[k] = o2[k]; 7 | } 8 | } 9 | } 10 | 11 | function uppercaseProto(proto) { 12 | for (var k in proto) { 13 | if (k != "toString" && k != "build") { 14 | proto[k.toUpperCase()] = proto[k]; 15 | } 16 | } 17 | } 18 | 19 | function argsToArray(args) { 20 | return Array.prototype.slice.call(args); 21 | } 22 | 23 | function pushMany(a, list) { 24 | Array.prototype.push.apply(a, list); 25 | } 26 | 27 | /* SQL BUILDER */ 28 | 29 | var BuildableProto = { 30 | _sql_buildable: true, 31 | 32 | alias: function(name) { 33 | return Sql.alias(this, name); 34 | }, 35 | 36 | build: function(startPos) { 37 | var state = { params: [], nextAlias: 1, nextPos: 1, text: undefined }; 38 | this.buildStep(state); 39 | state.text = this.toString(); 40 | return state; 41 | }, 42 | 43 | buildStep: function(state) { 44 | if (this.buildApply) { 45 | this.buildApply(state); 46 | } 47 | this.buildChildren(state); 48 | }, 49 | 50 | buildChildren: function(state) { 51 | this._children.forEach(function(child) { 52 | child.buildStep(state); 53 | }); 54 | } 55 | }; 56 | 57 | /* TABLE*/ 58 | 59 | var Table = function(name) { 60 | this.name = name; 61 | this.literal = Sql.literal(name); 62 | }; 63 | 64 | Table.prototype = { 65 | _children: [], 66 | 67 | f: function(field) { 68 | return this.literal.f(Sql.literal(field)); 69 | }, 70 | 71 | star: function() { 72 | return this.f("*"); 73 | }, 74 | 75 | toString: function() { 76 | return this.name; 77 | } 78 | }; 79 | 80 | extendProto(Table.prototype, BuildableProto); 81 | 82 | var Alias = function(rel, name) { 83 | this.rel = rel; 84 | this._children = [rel]; 85 | this._applied = !!name; 86 | if (!name) { 87 | name = "a?"; 88 | } 89 | this.alias = Sql.literal(name); 90 | }; 91 | 92 | Alias.prototype = { 93 | f: function(field) { 94 | return this.alias.f(Sql.literal(field)); 95 | }, 96 | 97 | star: function() { 98 | return this.f("*"); 99 | }, 100 | 101 | buildApply: function(state) { 102 | if (this._applied) { 103 | return; 104 | } 105 | 106 | this.alias.literal = "t"+(state.nextAlias++); 107 | this._applied = true; 108 | }, 109 | 110 | toString: function() { 111 | return `${this.rel} AS ${this.alias}`; 112 | } 113 | }; 114 | 115 | extendProto(Alias.prototype, BuildableProto); 116 | 117 | /* QUERY */ 118 | 119 | var Join = function(expr, cond, type) { 120 | this.expr = expr; 121 | this.cond = cond; 122 | this.type = type || "INNER"; 123 | }; 124 | 125 | Join.prototype = { 126 | toString: function() { 127 | return `${this.type} JOIN ${this.expr} ON ${this.cond}`; 128 | } 129 | }; 130 | 131 | var Order = function(expr, dir) { 132 | this.expr = expr; 133 | this.dir = dir || "ASC"; 134 | }; 135 | 136 | Order.prototype = { 137 | toString: function() { 138 | return `${this.expr} ${this.dir}`; 139 | } 140 | }; 141 | 142 | var Query = function() { 143 | this._children = []; 144 | 145 | this._distinct = false; 146 | this._select = []; 147 | this._from = []; 148 | this._join = []; 149 | this._offset = null; 150 | this._limit = null; 151 | this._order = []; 152 | this._group = []; 153 | this._where = []; 154 | }; 155 | 156 | Query.prototype = { 157 | select: function() { 158 | var exprs = makeChildren(argsToArray(arguments)); 159 | pushMany(this._select, exprs); 160 | pushMany(this._children, exprs); 161 | return this; 162 | }, 163 | 164 | from: function() { 165 | var exprs = makeChildren(argsToArray(arguments)); 166 | pushMany(this._from, exprs); 167 | pushMany(this._children, exprs); 168 | return this; 169 | }, 170 | 171 | join: function(expr, cond, type) { 172 | this._join.push(new Join(expr, cond, type)); 173 | this._children.push(expr); 174 | this._children.push(cond); 175 | return this; 176 | }, 177 | 178 | order: function(expr, dir) { 179 | expr = makeChild(expr); 180 | this._order.push(new Order(expr, dir)); 181 | this._children.push(expr); 182 | return this; 183 | }, 184 | 185 | group: function() { 186 | var exprs = makeChildren(argsToArray(arguments)); 187 | pushMany(this._group, exprs); 188 | pushMany(this._children, exprs); 189 | return this; 190 | }, 191 | 192 | where: function(expr) { 193 | expr = makeChild(expr); 194 | this._where.push(expr); 195 | this._children.push(expr); 196 | return this; 197 | }, 198 | 199 | limit: function(lit) { 200 | this._limit = Sql.literal(lit); 201 | return this; 202 | }, 203 | 204 | offset: function(lit) { 205 | this._offset = Sql.literal(lit); 206 | return this; 207 | }, 208 | 209 | toString: function() { 210 | var select = this._select.length ? 'SELECT '+this._select.join(', ') : 'SELECT *'; 211 | var from = this._from.length ? ' FROM '+this._from.join(', ') : ''; 212 | var join = this._join.length ? ' '+this._join.join(' ') : ''; 213 | var where = this._where.length ? ' WHERE '+this._where.join(' AND ') : ''; 214 | var group = this._group.length ? ' GROUP BY '+this._group.join(', ') : ''; 215 | var order = this._order.length ? ' ORDER BY '+this._order.join(', ') : ''; 216 | var limit = this._limit !== null ? ' LIMIT '+this._limit : ''; 217 | var offset = this._offset !== null ? ' OFFSET '+this._offset : ''; 218 | 219 | return `(${select}${from}${join}${where}${group}${order}${limit}${offset})`; 220 | }, 221 | }; 222 | 223 | uppercaseProto(Query.prototype); 224 | extendProto(Query.prototype, BuildableProto); 225 | 226 | /* INSERT */ 227 | 228 | var Insert = function(rel) { 229 | this._children = [rel]; 230 | 231 | this.rel = rel; 232 | this._data = {}; 233 | this._returning = []; 234 | }; 235 | 236 | Insert.prototype = { 237 | set: function(col, val) { 238 | if (typeof col == "string") { 239 | val = makeChild(val); 240 | this._data[col] = val; 241 | this._children.push(val); 242 | } else { 243 | for (var k in col) { 244 | val = makeChild(col[k]); 245 | this._data[k] = val; 246 | this._children.push(val); 247 | } 248 | } 249 | 250 | return this; 251 | }, 252 | 253 | returning: function() { 254 | var args = argsToArray(arguments); 255 | this._returning = args; 256 | return this; 257 | }, 258 | 259 | toString: function() { 260 | var cols = []; 261 | var values = []; 262 | 263 | for (var k in this._data) { 264 | cols.push(k); 265 | values.push(this._data[k]); 266 | } 267 | 268 | var colstr = cols.join(', '); 269 | var valuestr = values.join(', '); 270 | var returning = this._returning.length ? ' RETURNING '+(this._returning.join(', ')) : ''; 271 | 272 | return `INSERT INTO ${this.rel} (${colstr}) VALUES (${valuestr})${returning}`; 273 | }, 274 | }; 275 | 276 | uppercaseProto(Insert.prototype); 277 | extendProto(Insert.prototype, BuildableProto); 278 | 279 | /* UPDATE */ 280 | 281 | var Update = function(rel) { 282 | this._children = [rel]; 283 | 284 | this.rel = rel; 285 | this._data = {}; 286 | this._where = []; 287 | this._returning = []; 288 | }; 289 | 290 | Update.prototype = { 291 | set: Insert.prototype.set, 292 | returning: Insert.prototype.returning, 293 | where: Query.prototype.where, 294 | 295 | toString: function() { 296 | var updates = []; 297 | 298 | for (var k in this._data) { 299 | updates.push(k+'='+this._data[k]); 300 | } 301 | 302 | var updatestr = updates.join(', '); 303 | var where = this._where.length ? ' WHERE '+this._where.join(' AND ') : ''; 304 | var returning = this._returning.length ? ' RETURNING '+(this._returning.join(', ')) : ''; 305 | 306 | return `UPDATE ${this.rel} SET ${updatestr}${where}${returning}`; 307 | }, 308 | }; 309 | 310 | uppercaseProto(Update.prototype); 311 | extendProto(Update.prototype, BuildableProto); 312 | 313 | /* DELETE */ 314 | 315 | var Delete = function(rel) { 316 | this._children = [rel]; 317 | 318 | this.rel = rel; 319 | this._where = []; 320 | }; 321 | 322 | Delete.prototype = { 323 | where: Query.prototype.where, 324 | 325 | toString: function() { 326 | if (!this._where.length) { 327 | throw new Error("Mass delete forbidden"); 328 | } 329 | 330 | var where = this._where.length ? ' WHERE '+this._where.join(' AND ') : ''; 331 | return `DELETE FROM ${this.rel}${where}`; 332 | }, 333 | }; 334 | 335 | uppercaseProto(Delete.prototype); 336 | extendProto(Delete.prototype, BuildableProto); 337 | 338 | /* EXPRESSIONS */ 339 | 340 | function makeChild(child, literalArgs?) { 341 | if (Array.isArray(child)) { 342 | var list = { _children: makeChildren(child) } as any; 343 | list.__proto__ = { 344 | toString: () => `(${list._children.join(',')})` 345 | } 346 | extendProto(list.__proto__, ExpressionProto); 347 | return list; 348 | } 349 | 350 | if (!child || !child._sql_buildable) { 351 | if (literalArgs) { 352 | return Sql.literal(child); 353 | } else { 354 | return Sql.param(child); 355 | } 356 | } 357 | 358 | return child; 359 | } 360 | 361 | function makeChildren(children, literalArgs?) { 362 | return children.map(function(child) { 363 | return makeChild(child, literalArgs); 364 | }); 365 | } 366 | 367 | function metaExpr(f, literalArgs?) { 368 | return function() { 369 | var self = this; 370 | var args = Array.prototype.slice.call(arguments); 371 | args = makeChildren(args, literalArgs); 372 | 373 | var o = { _children: [self].concat(args) } as any; 374 | o.__proto__ = { 375 | toString: function() { 376 | return f.apply(null, o._children); 377 | } 378 | }; 379 | extendProto(o.__proto__, ExpressionProto); 380 | return o; 381 | } 382 | } 383 | 384 | var ExpressionProto = { 385 | not: metaExpr(e => `(NOT ${e})`), 386 | and: metaExpr((l,r) => `(${l} AND ${r})`), 387 | or: metaExpr((l,r) => `(${l} OR ${r})`), 388 | between: metaExpr((e,l,r) => `(${e} BETWEEN ${l} AND ${r})`), 389 | lt: metaExpr((l,r) => `(${l} < ${r})`), 390 | le: metaExpr((l,r) => `(${l} <= ${r})`), 391 | gt: metaExpr((l,r) => `(${l} > ${r})`), 392 | ge: metaExpr((l,r) => `(${l} >= ${r})`), 393 | eq: metaExpr((l,r) => `(${l} = ${r})`), 394 | ne: metaExpr((l,r) => `(${l} != ${r})`), 395 | in: metaExpr((l,r) => `(${l} IN ${r})`), 396 | plus: metaExpr((l,r) => `(${l} + ${r})`), 397 | minus: metaExpr((l,r) => `(${l} - ${r})`), 398 | mult: metaExpr((l,r) => `(${l} * ${r})`), 399 | extract: metaExpr((d,f) => `(EXTRACT (${f} FROM ${d}))`, true), 400 | cast: metaExpr((e,t) => `(CAST (${e} AS ${t}))`, true), 401 | isnull: metaExpr(e => `(${e} IS NULL)`), 402 | notnull: metaExpr(e => `(${e} IS NOT NULL)`), 403 | exists: metaExpr(e => `(EXISTS ${e})`), 404 | notexists: metaExpr(e => `(NOT EXISTS ${e})`), 405 | distinct: metaExpr(e => `DISTINCT ${e}`), 406 | f: metaExpr((e,f) => `(${e}.${f})`) 407 | }; 408 | 409 | uppercaseProto(ExpressionProto); 410 | extendProto(ExpressionProto, BuildableProto); 411 | 412 | /* CASE */ 413 | 414 | var When = function(cond, then) { 415 | this.cond = cond; 416 | this.then = then; 417 | }; 418 | 419 | When.prototype = { 420 | toString: function() { 421 | return `WHEN ${this.cond} THEN ${this.then}`; 422 | } 423 | }; 424 | 425 | var Case = function() { 426 | this._children = []; 427 | 428 | this._when = []; 429 | this._else = null; 430 | }; 431 | 432 | Case.prototype = { 433 | when: function(cond, then) { 434 | cond = makeChild(cond); 435 | then = makeChild(then); 436 | this._when.push(new When(cond, then)); 437 | this._children.push(cond); 438 | this._children.push(then); 439 | return this; 440 | }, 441 | 442 | otherwise: function(expr) { 443 | expr = makeChild(expr); 444 | this._else = expr; 445 | this._children.push(expr); 446 | return this; 447 | }, 448 | 449 | toString: function() { 450 | var when = this._when.join(" "); 451 | var otherwise = this._else ? ' ELSE '+this._else : ''; 452 | 453 | return `CASE ${when}${otherwise} END`; 454 | } 455 | }; 456 | 457 | extendProto(Case.prototype, ExpressionProto); 458 | 459 | /* PARAMETER */ 460 | 461 | var Param = function(value) { 462 | this.param = "p?"; 463 | this.value = value; 464 | }; 465 | 466 | Param.prototype = { 467 | _children: [], 468 | 469 | buildApply: function(state) { 470 | if (!this._applied) { 471 | this.param = '$'+(state.nextPos++); 472 | state.params.push(this.value); 473 | } 474 | 475 | this._applied = true; 476 | }, 477 | 478 | toString: function() { 479 | return this.param; 480 | } 481 | }; 482 | 483 | extendProto(Param.prototype, ExpressionProto); 484 | 485 | /* LITERAL */ 486 | 487 | var Literal = function(lit) { 488 | this.literal = lit; 489 | }; 490 | 491 | Literal.prototype = { 492 | _children: [], 493 | toString: function() { return this.literal; } 494 | }; 495 | 496 | extendProto(Literal.prototype, ExpressionProto); 497 | 498 | /* FUNCTION CALL */ 499 | 500 | var Funcall = function(name, args) { 501 | this.name = name; 502 | this._children = makeChildren(args); 503 | }; 504 | 505 | Funcall.prototype = { 506 | toString: function() { 507 | var args = this._children.join(', '); 508 | return `${this.name}(${args})`; 509 | } 510 | }; 511 | 512 | extendProto(Funcall.prototype, ExpressionProto); 513 | 514 | var Sql = { 515 | query: function() { 516 | return new Query(); 517 | }, 518 | 519 | insert: function(rel) { 520 | return new Insert(rel); 521 | }, 522 | 523 | update: function(rel) { 524 | return new Update(rel); 525 | }, 526 | 527 | deleteFrom: function(rel) { 528 | return new Delete(rel); 529 | }, 530 | 531 | alias: function(rel, name) { 532 | return new Alias(rel, name); 533 | }, 534 | 535 | table: function(name) { 536 | return new Table(name); 537 | }, 538 | 539 | param: function(val) { 540 | return new Param(val); 541 | }, 542 | 543 | literal: function(lit) { 544 | return new Literal(lit); 545 | }, 546 | 547 | func: function(name) { 548 | return function() { 549 | return new Funcall(name, Array.prototype.slice.call(arguments)); 550 | } 551 | }, 552 | 553 | when: function(cond, then) { 554 | return new Case().when(cond, then); 555 | }, 556 | 557 | metaExpr: metaExpr 558 | } as any; 559 | 560 | /* COMMON FUNCTIONS */ 561 | 562 | Sql.now = Sql.func("now"); 563 | Sql.count = Sql.func("count"); 564 | 565 | export = Sql; 566 | --------------------------------------------------------------------------------