query-generator.js
14.2 KB
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
var Utils = require("../../utils")
, util = require("util")
, tables = {}
, primaryKeys = {};
function removeQuotes(s, quoteChar) {
quoteChar = quoteChar || '"'
return s.replace(new RegExp(quoteChar, 'g'), '')
}
function addQuotes(s, quoteChar) {
quoteChar = quoteChar || '"'
return quoteChar + removeQuotes(s) + quoteChar
}
function pgEscape(s) {
s = Utils.escape(s)
if (typeof s == 'string') s = s.replace(/\\"/g, '"')
return s
}
function padInt(i) {
return (i < 10) ? '0' + i.toString() : i.toString()
}
function pgSqlDate(dt) {
var date = [ dt.getUTCFullYear(), padInt(dt.getUTCMonth()+1), padInt(dt.getUTCDate()) ].join('-')
var time = [ dt.getUTCHours(), padInt(dt.getUTCMinutes()), padInt(dt.getUTCSeconds())].join(':')
return date + ' ' + time + '.' + ((dt.getTime() % 1000) * 1000)
}
function pgDataTypeMapping(tableName, attr, dataType) {
if (Utils._.includes(dataType, 'PRIMARY KEY')) {
primaryKeys[tableName].push(attr)
dataType = dataType.replace(/PRIMARY KEY/, '')
}
if (Utils._.includes(dataType, 'TINYINT(1)')) {
dataType = dataType.replace(/TINYINT\(1\)/, 'BOOLEAN')
}
if (Utils._.includes(dataType, 'DATETIME')) {
dataType = dataType.replace(/DATETIME/, 'TIMESTAMP')
}
if (Utils._.includes(dataType, 'SERIAL')) {
dataType = dataType.replace(/INTEGER/, '')
dataType = dataType.replace(/NOT NULL/, '')
tables[tableName][attr] = 'serial'
}
return dataType
}
module.exports = (function() {
var QueryGenerator = {
options: {},
createTableQuery: function(tableName, attributes, options) {
options = Utils._.extend({
}, options || {})
primaryKeys[tableName] = []
tables[tableName] = {}
var query = "CREATE TABLE IF NOT EXISTS <%= table %> (<%= attributes%>)"
, attrStr = Utils._.map(attributes, function(dataType, attr) {
dataType = pgDataTypeMapping(tableName, attr, dataType)
return addQuotes(attr) + " " + dataType
}).join(", ")
, values = {
table: addQuotes(tableName),
attributes: attrStr,
}
var pks = primaryKeys[tableName].map(function(pk){return addQuotes(pk)}).join(",")
if (pks.length > 0) values.attributes += ", PRIMARY KEY (" + pks + ")"
return Utils._.template(query)(values).trim() + ";"
},
dropTableQuery: function(tableName, options) {
options = options || {}
var query = "DROP TABLE IF EXISTS <%= table %>;"
return Utils._.template(query)({table: addQuotes(tableName)})
},
renameTableQuery: function(before, after) {
var query = "ALTER TABLE <%= before %> RENAME TO <%= after %>;"
return Utils._.template(query)({ before: addQuotes(before), after: addQuotes(after) })
},
showTablesQuery: function() {
return "SELECT table_name FROM information_schema.tables WHERE table_schema = 'public';"
},
describeTableQuery: function(tableName) {
var query = 'SELECT column_name as "Field", column_default as "Default", is_nullable as "Null", data_type as "Type" FROM information_schema.columns WHERE table_name = <%= table %>;'
return Utils._.template(query)({ table: addQuotes(tableName, "'") })
},
addColumnQuery: function(tableName, attributes) {
var query = "ALTER TABLE <%= tableName %> ADD COLUMN <%= attributes %>;"
, attrString = Utils._.map(attributes, function(definition, attributeName) {
return Utils._.template('<%= attributeName %> <%= definition %>')({
attributeName: addQuotes(attributeName),
definition: pgDataTypeMapping(tableName, attributeName, definition)
})
}).join(', ')
return Utils._.template(query)({ tableName: addQuotes(tableName), attributes: attrString })
},
removeColumnQuery: function(tableName, attributeName) {
var query = "ALTER TABLE <%= tableName %> DROP COLUMN <%= attributeName %>;"
return Utils._.template(query)({ tableName: addQuotes(tableName), attributeName: addQuotes(attributeName) })
},
changeColumnQuery: function(tableName, attributes) {
var query = "ALTER TABLE <%= tableName %> ALTER COLUMN <%= query %>;"
var sql = Utils._.map(attributes, function(definition, attributeName) {
var attrSql = ''
if (definition.indexOf('NOT NULL') > 0) {
attrSql += Utils._.template(query)({
tableName: addQuotes(tableName),
query: addQuotes(attributeName) + ' SET NOT NULL'
})
definition = definition.replace('NOT NULL', '').trim()
} else {
attrSql += Utils._.template(query)({
tableName: addQuotes(tableName),
query: addQuotes(attributeName) + ' DROP NOT NULL'
})
}
attrSql += Utils._.template(query)({
tableName: addQuotes(tableName),
query: addQuotes(attributeName) + ' TYPE ' + definition
})
return attrSql;
}).join('')
return sql
},
renameColumnQuery: function(tableName, attrBefore, attributes) {
var query = "ALTER TABLE <%= tableName %> RENAME COLUMN <%= attributes %>;"
var attrString = Utils._.map(attributes, function(definition, attributeName) {
return Utils._.template('<%= before %> TO <%= after %>')({
before: addQuotes(attrBefore),
after: addQuotes(attributeName),
})
}).join(', ')
return Utils._.template(query)({ tableName: addQuotes(tableName), attributes: attrString })
},
selectQuery: function(tableName, options) {
options = options || {}
options.table = Array.isArray(tableName) ? tableName.map(function(t){return addQuotes(t);}).join(", ") : addQuotes(tableName)
options.attributes = options.attributes && options.attributes.map(function(attr){
if(Array.isArray(attr) && attr.length == 2) {
return [attr[0], addQuotes(removeQuotes(attr[1], '`'))].join(' as ')
} else if (attr.indexOf('`') >= 0) {
return attr.replace(/`/g, '"')
} else {
return addQuotes(attr)
}
}).join(", ")
options.attributes = options.attributes || '*'
var query = "SELECT <%= attributes %> FROM <%= table %>"
if(options.where) {
options.where = QueryGenerator.getWhereConditions(options.where)
query += " WHERE <%= where %>"
}
if(options.order) {
options.order = options.order.replace(/([^ ]+)(.*)/, function(m, g1, g2) { return addQuotes(g1)+g2 })
query += " ORDER BY <%= order %>"
}
if(options.group) {
options.group = addQuotes(options.group)
query += " GROUP BY <%= group %>"
}
if(options.limit) query += " LIMIT <%= limit %>"
if(options.offset) query += " OFFSET <%= offset %>"
query += ";"
return Utils._.template(query)(options)
},
insertQuery: function(tableName, attrValueHash) {
attrValueHash = Utils.removeNullValuesFromHash(attrValueHash, this.options.omitNull)
var query = "INSERT INTO <%= table %> (<%= attributes %>) VALUES (<%= values %>) RETURNING *;"
, returning = []
Utils._.forEach(attrValueHash, function(value, key, hash) {
if (tables[tableName] && tables[tableName][key]) {
switch (tables[tableName][key]) {
case 'serial':
delete hash[key]
returning.push(key)
break
}
}
});
var replacements = {
table: addQuotes(tableName),
attributes: Utils._.keys(attrValueHash).map(function(attr){return addQuotes(attr)}).join(","),
values: Utils._.values(attrValueHash).map(function(value){
return pgEscape((value instanceof Date) ? pgSqlDate(value) : value)
}).join(",")
}
return Utils._.template(query)(replacements)
},
updateQuery: function(tableName, attrValueHash, where) {
attrValueHash = Utils.removeNullValuesFromHash(attrValueHash, this.options.omitNull)
var query = "UPDATE <%= table %> SET <%= values %> WHERE <%= where %>"
var replacements = {
table: addQuotes(tableName),
values: Utils._.map(attrValueHash, function(value, key){
return addQuotes(key) + "=" + pgEscape((value instanceof Date) ? pgSqlDate(value) : value)
}).join(","),
where: QueryGenerator.getWhereConditions(where)
}
return Utils._.template(query)(replacements)
},
deleteQuery: function(tableName, where, options) {
options = options || {}
options.limit = options.limit || 1
var query = "DELETE FROM <%= table %> WHERE <%= primaryKeys %> IN (SELECT <%= primaryKeysSelection %> FROM <%= table %> WHERE <%= where %> LIMIT <%= limit %>)"
var pks;
if (primaryKeys[tableName] && primaryKeys[tableName].length > 0) {
pks = primaryKeys[tableName].map(function(pk) { return addQuotes(pk) }).join(',')
} else {
pks = addQuotes('id')
}
var replacements = {
table: addQuotes(tableName),
where: QueryGenerator.getWhereConditions(where),
limit: pgEscape(options.limit),
primaryKeys: primaryKeys[tableName].length > 1 ? '(' + pks + ')' : pks,
primaryKeysSelection: pks
}
return Utils._.template(query)(replacements)
},
addIndexQuery: function(tableName, attributes, options) {
var transformedAttributes = attributes.map(function(attribute) {
if(typeof attribute == 'string')
return addQuotes(attribute)
else {
var result = ""
if(!attribute.attribute)
throw new Error('The following index attribute has no attribute: ' + util.inspect(attribute))
result += addQuotes(attribute.attribute)
if(attribute.length)
result += '(' + attribute.length + ')'
if(attribute.order)
result += ' ' + attribute.order
return result
}
})
var onlyAttributeNames = attributes.map(function(attribute) {
return (typeof attribute == 'string') ? attribute : attribute.attribute
})
options = Utils._.extend({
indicesType: null,
indexName: Utils._.underscored(tableName + '_' + onlyAttributeNames.join('_')),
parser: null
}, options || {})
return Utils._.compact([
"CREATE", options.indicesType, "INDEX", addQuotes(options.indexName),
(options.indexType ? ('USING ' + options.indexType) : undefined),
"ON", addQuotes(tableName), '(' + transformedAttributes.join(', ') + ')'
]).join(' ')
},
showIndexQuery: function(tableName, options) {
var query = "SELECT relname FROM pg_class WHERE oid IN ( SELECT indexrelid FROM pg_index, pg_class WHERE pg_class.relname='<%= tableName %>' AND pg_class.oid=pg_index.indrelid);"
return Utils._.template(query)({ tableName: tableName });
},
removeIndexQuery: function(tableName, indexNameOrAttributes) {
var sql = "DROP INDEX IF EXISTS <%= indexName %>"
, indexName = indexNameOrAttributes
if(typeof indexName != 'string')
indexName = Utils._.underscored(tableName + '_' + indexNameOrAttributes.join('_'))
return Utils._.template(sql)({ tableName: addQuotes(tableName), indexName: addQuotes(indexName) })
},
getWhereConditions: function(smth) {
var result = null
if(Utils.isHash(smth))
result = QueryGenerator.hashToWhereConditions(smth)
else if(typeof smth == 'number')
result = '\"id\"' + "=" + pgEscape(smth)
else if(typeof smth == "string")
result = smth
else if(Array.isArray(smth))
result = Utils.format(smth)
return result
},
hashToWhereConditions: function(hash) {
return Utils._.map(hash, function(value, key) {
//handle qualified key names
var _key = key.split('.').map(function(col){return addQuotes(col)}).join(".")
, _value = null
if(Array.isArray(value)) {
_value = "(" + Utils._.map(value, function(subvalue) {
return pgEscape(subvalue);
}).join(',') + ")"
return [_key, _value].join(" IN ")
}
else if ((value) && (typeof value == 'object')) {
//using as sentinel for join column => value
_value = value.join.split('.').map(function(col){return addQuotes(col)}).join(".")
return [_key, _value].join("=")
} else {
_value = pgEscape(value)
return (_value == 'NULL') ? _key + " IS NULL" : [_key, _value].join("=")
}
}).join(" AND ")
},
attributesToSQL: function(attributes) {
var result = {}
Utils._.map(attributes, function(dataType, name) {
if(Utils.isHash(dataType)) {
var template = "<%= type %>"
, replacements = { type: dataType.type }
if(dataType.type == 'TINYINT(1)') dataType.type = 'BOOLEAN'
if(dataType.type == 'DATETIME') dataType.type = 'TIMESTAMP'
if(dataType.hasOwnProperty('allowNull') && (!dataType.allowNull)) template += " NOT NULL"
if(dataType.autoIncrement) template +=" SERIAL"
if(dataType.defaultValue != undefined) {
template += " DEFAULT <%= defaultValue %>"
replacements.defaultValue = pgEscape(dataType.defaultValue)
}
if(dataType.unique) template += " UNIQUE"
if(dataType.primaryKey) template += " PRIMARY KEY"
result[name] = Utils._.template(template)(replacements)
} else {
result[name] = dataType
}
})
return result
},
findAutoIncrementField: function(factory) {
var fields = Utils._.map(factory.attributes, function(definition, name) {
var isAutoIncrementField = (definition && (definition.indexOf('SERIAL') > -1))
return isAutoIncrementField ? name : null
})
return Utils._.compact(fields)
},
databaseConnectionUri: function(config) {
var template = '<%= protocol %>://<%= user %>:<%= password %>@<%= host %><% if(port) { %>:<%= port %><% } %>/<%= database %>';
return Utils._.template(template)({
user: config.username,
password: config.password,
database: config.database,
host: config.host,
port: config.port,
protocol: config.protocol
})
}
}
return Utils._.extend(Utils._.clone(require("../query-generator")), QueryGenerator)
})()