-
Notifications
You must be signed in to change notification settings - Fork 181
/
postgresql.js
710 lines (658 loc) · 20.6 KB
/
postgresql.js
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
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
// Copyright IBM Corp. 2013,2018. All Rights Reserved.
// Node module: loopback-connector-postgresql
// This file is licensed under the Artistic License 2.0.
// License text available at https://opensource.org/licenses/Artistic-2.0
/*!
* PostgreSQL connector for LoopBack
*/
'use strict';
var SG = require('strong-globalize');
var g = SG();
var postgresql = require('pg');
var SqlConnector = require('loopback-connector').SqlConnector;
var ParameterizedSQL = SqlConnector.ParameterizedSQL;
var util = require('util');
var debug = require('debug')('loopback:connector:postgresql');
var debugData = require('debug')('loopback:connector:postgresql:data');
var Promise = require('bluebird');
/**
*
* Initialize the PostgreSQL connector against the given data source
*
* @param {DataSource} dataSource The loopback-datasource-juggler dataSource
* @callback {Function} [callback] The callback function
* @param {String|Error} err The error string or object
* @header PostgreSQL.initialize(dataSource, [callback])
*/
exports.initialize = function initializeDataSource(dataSource, callback) {
if (!postgresql) {
return;
}
var dbSettings = dataSource.settings || {};
dbSettings.host = dbSettings.host || dbSettings.hostname || 'localhost';
dbSettings.user = dbSettings.user || dbSettings.username;
dataSource.connector = new PostgreSQL(postgresql, dbSettings);
dataSource.connector.dataSource = dataSource;
if (callback) {
if (dbSettings.lazyConnect) {
process.nextTick(function() {
callback();
});
} else {
dataSource.connecting = true;
dataSource.connector.connect(callback);
}
}
};
/**
* PostgreSQL connector constructor
*
* @param {PostgreSQL} postgresql PostgreSQL node.js binding
* @options {Object} settings An object for the data source settings.
* See [node-postgres documentation](https://github.com/brianc/node-postgres/wiki/Client#parameters).
* @property {String} url URL to the database, such as 'postgres://test:mypassword@localhost:5432/devdb'.
* Other parameters can be defined as query string of the url
* @property {String} hostname The host name or ip address of the PostgreSQL DB server
* @property {Number} port The port number of the PostgreSQL DB Server
* @property {String} user The user name
* @property {String} password The password
* @property {String} database The database name
* @property {Boolean} ssl Whether to try SSL/TLS to connect to server
*
* @constructor
*/
function PostgreSQL(postgresql, settings) {
// this.name = 'postgresql';
// this._models = {};
// this.settings = settings;
this.constructor.super_.call(this, 'postgresql', settings);
this.clientConfig = settings;
if (settings.url) {
// pg-pool doesn't handle string config correctly
this.clientConfig.connectionString = settings.url;
}
this.clientConfig.Promise = Promise;
this.pg = new postgresql.Pool(this.clientConfig);
this.settings = settings;
debug('Settings %j', settings);
}
// Inherit from loopback-datasource-juggler BaseSQL
util.inherits(PostgreSQL, SqlConnector);
PostgreSQL.prototype.getDefaultSchemaName = function() {
return 'public';
};
/**
* Connect to PostgreSQL
* @callback {Function} [callback] The callback after the connection is established
*/
PostgreSQL.prototype.connect = function(callback) {
var self = this;
self.pg.connect(function(err, client, done) {
self.client = client;
process.nextTick(done);
callback && callback(err, client);
});
};
/**
* Execute the sql statement
*
* @param {String} sql The SQL statement
* @param {String[]} params The parameter values for the SQL statement
* @param {Object} [options] Options object
* @callback {Function} [callback] The callback after the SQL statement is executed
* @param {String|Error} err The error string or object
* @param {Object[]) data The result from the SQL
*/
PostgreSQL.prototype.executeSQL = function(sql, params, options, callback) {
var self = this;
if (params && params.length > 0) {
debug('SQL: %s\nParameters: %j', sql, params);
} else {
debug('SQL: %s', sql);
}
function executeWithConnection(connection, done) {
connection.query(sql, params, function(err, data) {
// if(err) console.error(err);
if (err) debug(err);
if (data) debugData('%j', data);
if (done) {
process.nextTick(function() {
// Release the connection in next tick
done(err);
});
}
var result = null;
if (data) {
switch (data.command) {
case 'DELETE':
case 'UPDATE':
result = {affectedRows: data.rowCount, count: data.rowCount};
if (data.rows)
result.rows = data.rows;
break;
default:
result = data.rows;
}
}
callback(err ? err : null, result);
});
}
var transaction = options.transaction;
if (transaction && transaction.connector === this) {
if (!transaction.connection) {
return process.nextTick(function() {
callback(new Error(g.f('Connection does not exist')));
});
}
if (transaction.txId !== transaction.connection.txId) {
return process.nextTick(function() {
callback(new Error(g.f('Transaction is not active')));
});
}
debug('Execute SQL within a transaction');
// Do not release the connection
executeWithConnection(transaction.connection, null);
} else {
self.pg.connect(function(err, connection, done) {
if (err) return callback(err);
executeWithConnection(connection, done);
});
}
};
PostgreSQL.prototype.buildInsertReturning = function(model, data, options) {
var idColumnNames = [];
var idNames = this.idNames(model);
for (var i = 0, n = idNames.length; i < n; i++) {
idColumnNames.push(this.columnEscaped(model, idNames[i]));
}
return 'RETURNING ' + idColumnNames.join(',');
};
PostgreSQL.prototype.buildInsertDefaultValues = function(model, data, options) {
return 'DEFAULT VALUES';
};
// FIXME: [rfeng] The native implementation of upsert only works with
// postgresql 9.1 or later as it requres writable CTE
// See https://github.com/strongloop/loopback-connector-postgresql/issues/27
/**
* Update if the model instance exists with the same id or create a new instance
*
* @param {String} model The model name
* @param {Object} data The model instance data
* @callback {Function} [callback] The callback function
* @param {String|Error} err The error string or object
* @param {Object} The updated model instance
*/
/*
PostgreSQL.prototype.updateOrCreate = function (model, data, callback) {
var self = this;
data = self.mapToDB(model, data);
var props = self._categorizeProperties(model, data);
var idColumns = props.ids.map(function(key) {
return self.columnEscaped(model, key); }
);
var nonIdsInData = props.nonIdsInData;
var query = [];
query.push('WITH update_outcome AS (UPDATE ', self.tableEscaped(model), ' SET ');
query.push(self.toFields(model, data, false));
query.push(' WHERE ');
query.push(idColumns.map(function (key, i) {
return ((i > 0) ? ' AND ' : ' ') + key + '=$' + (nonIdsInData.length + i + 1);
}).join(','));
query.push(' RETURNING ', idColumns.join(','), ')');
query.push(', insert_outcome AS (INSERT INTO ', self.tableEscaped(model), ' ');
query.push(self.toFields(model, data, true));
query.push(' WHERE NOT EXISTS (SELECT * FROM update_outcome) RETURNING ', idColumns.join(','), ')');
query.push(' SELECT * FROM update_outcome UNION ALL SELECT * FROM insert_outcome');
var queryParams = [];
nonIdsInData.forEach(function(key) {
queryParams.push(data[key]);
});
props.ids.forEach(function(key) {
queryParams.push(data[key] || null);
});
var idColName = self.idColumn(model);
self.query(query.join(''), queryParams, function(err, info) {
if (err) {
return callback(err);
}
var idValue = null;
if (info && info[0]) {
idValue = info[0][idColName];
}
callback(err, idValue);
});
};
*/
PostgreSQL.prototype.fromColumnValue = function(prop, val) {
if (val == null) {
return val;
}
var type = prop.type && prop.type.name;
if (prop && type === 'Boolean') {
if (typeof val === 'boolean') {
return val;
} else {
return (val === 'Y' || val === 'y' || val === 'T' ||
val === 't' || val === '1');
}
} else if (prop && type === 'GeoPoint' || type === 'Point') {
if (typeof val === 'string') {
// The point format is (x,y)
var point = val.split(/[\(\)\s,]+/).filter(Boolean);
return {
lat: +point[0],
lng: +point[1],
};
} else if (typeof val === 'object' && val !== null) {
// Now pg driver converts point to {x: lng, y: lat}
return {
lng: val.x,
lat: val.y,
};
} else {
return val;
}
} else {
return val;
}
};
/*!
* Convert to the Database name
* @param {String} name The name
* @returns {String} The converted name
*/
PostgreSQL.prototype.dbName = function(name) {
if (!name) {
return name;
}
// PostgreSQL default to lowercase names
return name.toLowerCase();
};
function escapeIdentifier(str) {
var escaped = '"';
for (var i = 0; i < str.length; i++) {
var c = str[i];
if (c === '"') {
escaped += c + c;
} else {
escaped += c;
}
}
escaped += '"';
return escaped;
}
function escapeLiteral(str) {
var hasBackslash = false;
var escaped = '\'';
for (var i = 0; i < str.length; i++) {
var c = str[i];
if (c === '\'') {
escaped += c + c;
} else if (c === '\\') {
escaped += c + c;
hasBackslash = true;
} else {
escaped += c;
}
}
escaped += '\'';
if (hasBackslash === true) {
escaped = ' E' + escaped;
}
return escaped;
}
/*
* Check if a value is attempting to use nested json keys
* @param {String} property The property being queried from where clause
* @returns {Boolean} True of the property contains dots for nested json
*/
function isNested(property) {
return property.split('.').length > 1;
}
/*
* Overwrite the loopback-connector column escape
* to allow querying nested json keys
* @param {String} model The model name
* @param {String} property The property name
* @returns {String} The escaped column name, or column with nested keys for deep json columns
*/
PostgreSQL.prototype.columnEscaped = function(model, property) {
if (isNested(property)) {
// Convert column to PostgreSQL json style query: "model"->>'val'
var self = this;
return property
.split('.')
.map(function(val, idx) { return (idx === 0 ? self.columnEscaped(model, val) : escapeLiteral(val)); })
.reduce(function(prev, next, idx, arr) {
return idx == 0 ? next : idx < arr.length - 1 ? prev + '->' + next : prev + '->>' + next;
});
} else {
return this.escapeName(this.column(model, property));
}
};
/*!
* Escape the name for PostgreSQL DB
* @param {String} name The name
* @returns {String} The escaped name
*/
PostgreSQL.prototype.escapeName = function(name) {
if (!name) {
return name;
}
return escapeIdentifier(name);
};
PostgreSQL.prototype.escapeValue = function(value) {
if (typeof value === 'string') {
return escapeLiteral(value);
}
if (typeof value === 'number' || typeof value === 'boolean') {
return value;
}
// Can't send functions, objects, arrays
if (typeof value === 'object' || typeof value === 'function') {
return null;
}
return value;
};
PostgreSQL.prototype.tableEscaped = function(model) {
var schema = this.schema(model) || 'public';
return this.escapeName(schema) + '.' +
this.escapeName(this.table(model));
};
function buildLimit(limit, offset) {
var clause = [];
if (isNaN(limit)) {
limit = 0;
}
if (isNaN(offset)) {
offset = 0;
}
if (!limit && !offset) {
return '';
}
if (limit) {
clause.push('LIMIT ' + limit);
}
if (offset) {
clause.push('OFFSET ' + offset);
}
return clause.join(' ');
}
PostgreSQL.prototype.applyPagination = function(model, stmt, filter) {
var limitClause = buildLimit(filter.limit, filter.offset || filter.skip);
return stmt.merge(limitClause);
};
PostgreSQL.prototype.buildExpression = function(columnName, operator,
operatorValue, propertyDefinition) {
switch (operator) {
case 'like':
return new ParameterizedSQL(columnName + "::TEXT LIKE ? ESCAPE E'\\\\'",
[operatorValue]);
case 'ilike':
return new ParameterizedSQL(columnName + "::TEXT ILIKE ? ESCAPE E'\\\\'",
[operatorValue]);
case 'nlike':
return new ParameterizedSQL(columnName + "::TEXT NOT LIKE ? ESCAPE E'\\\\'",
[operatorValue]);
case 'nilike':
return new ParameterizedSQL(columnName + "::TEXT NOT ILIKE ? ESCAPE E'\\\\'",
[operatorValue]);
case 'regexp':
if (operatorValue.global)
g.warn('{{PostgreSQL}} regex syntax does not respect the {{`g`}} flag');
if (operatorValue.multiline)
g.warn('{{PostgreSQL}} regex syntax does not respect the {{`m`}} flag');
var regexOperator = operatorValue.ignoreCase ? ' ~* ?' : ' ~ ?';
return new ParameterizedSQL(columnName + regexOperator,
[operatorValue.source]);
default:
// invoke the base implementation of `buildExpression`
return this.invokeSuper('buildExpression', columnName, operator,
operatorValue, propertyDefinition);
}
};
/**
* Disconnect from PostgreSQL
* @param {Function} [cb] The callback function
*/
PostgreSQL.prototype.disconnect = function disconnect(cb) {
if (this.pg) {
debug('Disconnecting from ' + this.settings.hostname);
var pg = this.pg;
this.pg = null;
pg.end(); // This is sync
}
if (cb) {
process.nextTick(cb);
}
};
PostgreSQL.prototype.ping = function(cb) {
this.execute('SELECT 1 AS result', [], cb);
};
PostgreSQL.prototype.getInsertedId = function(model, info) {
var idColName = this.idColumn(model);
var idValue;
if (info && info[0]) {
idValue = info[0][idColName];
}
return idValue;
};
/**
* Build the SQL WHERE clause for the where object
* @param {string} model Model name
* @param {object} where An object for the where conditions
* @returns {ParameterizedSQL} The SQL WHERE clause
*/
PostgreSQL.prototype.buildWhere = function(model, where) {
var whereClause = this._buildWhere(model, where);
if (whereClause.sql) {
whereClause.sql = 'WHERE ' + whereClause.sql;
}
return whereClause;
};
/**
* @private
* @param model
* @param where
* @returns {ParameterizedSQL}
*/
PostgreSQL.prototype._buildWhere = function(model, where) {
var columnValue, sqlExp;
if (!where) {
return new ParameterizedSQL('');
}
if (typeof where !== 'object' || Array.isArray(where)) {
debug('Invalid value for where: %j', where);
return new ParameterizedSQL('');
}
var self = this;
var props = self.getModelDefinition(model).properties;
var whereStmts = [];
for (var key in where) {
var stmt = new ParameterizedSQL('', []);
// Handle and/or operators
if (key === 'and' || key === 'or') {
var branches = [];
var branchParams = [];
var clauses = where[key];
if (Array.isArray(clauses)) {
for (var i = 0, n = clauses.length; i < n; i++) {
var stmtForClause = self._buildWhere(model, clauses[i]);
if (stmtForClause.sql) {
stmtForClause.sql = '(' + stmtForClause.sql + ')';
branchParams = branchParams.concat(stmtForClause.params);
branches.push(stmtForClause.sql);
}
}
stmt.merge({
sql: branches.join(' ' + key.toUpperCase() + ' '),
params: branchParams,
});
whereStmts.push(stmt);
continue;
}
// The value is not an array, fall back to regular fields
}
var p = props[key];
if (p == null && isNested(key)) {
// See if we are querying nested json
p = props[key.split('.')[0]];
}
if (p == null) {
// Unknown property, ignore it
debug('Unknown property %s is skipped for model %s', key, model);
continue;
}
// eslint-disable one-var
var expression = where[key];
var columnName = self.columnEscaped(model, key);
// eslint-enable one-var
if (expression === null || expression === undefined) {
stmt.merge(columnName + ' IS NULL');
} else if (expression && expression.constructor === Object) {
var operator = Object.keys(expression)[0];
// Get the expression without the operator
expression = expression[operator];
if (operator === 'inq' || operator === 'nin' || operator === 'between') {
columnValue = [];
if (Array.isArray(expression)) {
// Column value is a list
for (var j = 0, m = expression.length; j < m; j++) {
columnValue.push(this.toColumnValue(p, expression[j]));
}
} else {
columnValue.push(this.toColumnValue(p, expression));
}
if (operator === 'between') {
// BETWEEN v1 AND v2
var v1 = columnValue[0] === undefined ? null : columnValue[0];
var v2 = columnValue[1] === undefined ? null : columnValue[1];
columnValue = [v1, v2];
} else {
// IN (v1,v2,v3) or NOT IN (v1,v2,v3)
if (columnValue.length === 0) {
if (operator === 'inq') {
columnValue = [null];
} else {
// nin () is true
continue;
}
}
}
} else if (operator === 'regexp' && expression instanceof RegExp) {
// do not coerce RegExp based on property definitions
columnValue = expression;
} else {
columnValue = this.toColumnValue(p, expression);
}
sqlExp = self.buildExpression(columnName, operator, columnValue, p);
stmt.merge(sqlExp);
} else {
// The expression is the field value, not a condition
columnValue = self.toColumnValue(p, expression);
if (columnValue === null) {
stmt.merge(columnName + ' IS NULL');
} else {
if (columnValue instanceof ParameterizedSQL) {
if (p.type.name === 'GeoPoint')
stmt.merge(columnName + '~=').merge(columnValue);
else
stmt.merge(columnName + '=').merge(columnValue);
} else {
stmt.merge({
sql: columnName + '=?',
params: [columnValue],
});
}
}
}
whereStmts.push(stmt);
}
var params = [];
var sqls = [];
for (var k = 0, s = whereStmts.length; k < s; k++) {
sqls.push(whereStmts[k].sql);
params = params.concat(whereStmts[k].params);
}
var whereStmt = new ParameterizedSQL({
sql: sqls.join(' AND '),
params: params,
});
return whereStmt;
};
/*!
* Convert property name/value to an escaped DB column value
* @param {Object} prop Property descriptor
* @param {*} val Property value
* @returns {*} The escaped value of DB column
*/
PostgreSQL.prototype.toColumnValue = function(prop, val) {
if (val == null) {
// PostgreSQL complains with NULLs in not null columns
// If we have an autoincrement value, return DEFAULT instead
if (prop.autoIncrement || prop.id) {
return new ParameterizedSQL('DEFAULT');
} else {
return null;
}
}
if (prop.type === String) {
return String(val);
}
if (prop.type === Number) {
if (isNaN(val)) {
// Map NaN to NULL
return val;
}
return val;
}
if (prop.type === Date || prop.type.name === 'Timestamp') {
if (!val.toISOString) {
val = new Date(val);
}
var iso = val.toISOString();
// Pass in date as UTC and make sure Postgresql stores using UTC timezone
return new ParameterizedSQL({
sql: '?::TIMESTAMP WITH TIME ZONE',
params: [iso],
});
}
// PostgreSQL support char(1) Y/N
if (prop.type === Boolean) {
if (val) {
return true;
} else {
return false;
}
}
if (prop.type.name === 'GeoPoint' || prop.type.name === 'Point') {
return new ParameterizedSQL({
sql: 'point(?,?)',
// Postgres point is point(lng, lat)
params: [val.lng, val.lat],
});
}
return val;
};
/**
* Get the place holder in SQL for identifiers, such as ??
* @param {String} key Optional key, such as 1 or id
* @returns {String} The place holder
*/
PostgreSQL.prototype.getPlaceholderForIdentifier = function(key) {
throw new Error(g.f('{{Placeholder}} for identifiers is not supported'));
};
/**
* Get the place holder in SQL for values, such as :1 or ?
* @param {String} key Optional key, such as 1 or id
* @returns {String} The place holder
*/
PostgreSQL.prototype.getPlaceholderForValue = function(key) {
return '$' + key;
};
PostgreSQL.prototype.getCountForAffectedRows = function(model, info) {
return info && info.affectedRows;
};
require('./discovery')(PostgreSQL);
require('./migration')(PostgreSQL);
require('./transaction')(PostgreSQL);