├── .babelrc ├── .gitignore ├── LICENSE ├── README.md ├── package.json ├── src ├── escape.js └── index.js └── test └── test.js /.babelrc: -------------------------------------------------------------------------------- 1 | { 2 | "presets": ["es2015"], 3 | "plugins": ["syntax-async-functions", "transform-regenerator"] 4 | } 5 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | built-test 2 | node_modules 3 | coverage 4 | .idea 5 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2016 Tristan Davies 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # simple-postgres 2 | 3 | simple-postgres is a small and powerful PostgreSQL interface for Node.js 4 | 5 | Replace all of your database boilerplate with `import db from 'simple-postgres'` 6 | and never look back. 7 | 8 | ### Getting started 9 | 10 | ```console 11 | npm install simple-postgres 12 | ``` 13 | 14 | ```js 15 | import db from 'simple-postgres' 16 | 17 | let accountName = 'ACME\'; DELETE FROM accounts; --' 18 | 19 | // this is totally safe 20 | await db.query('INSERT INTO accounts (name) VALUES ($1)', [accountName]) 21 | 22 | // this is also totally safe 23 | let account = await db.row` 24 | SELECT * 25 | FROM accounts 26 | WHERE name = ${accountName} 27 | ` 28 | 29 | console.log(account.name) // => 'ACME\'; DELETE FROM accounts; --' 30 | ``` 31 | 32 | ### Why? 33 | 34 | Many other postgres modules are bad. This one is good. Here's why: 35 | 36 | #### simple-postgres has everything you need 37 | * connects using the DATABASE_URL environment variable 38 | * runs queries and returns the results 39 | * automatic query parameterization 40 | * escaping literals, identifiers, arrays 41 | * transactions 42 | * async/await ready 43 | * sets application_name using package.json 44 | * good test coverage 45 | * trusted in production by my boss who trusts nothing 46 | 47 | #### simple-postgres doesn't have anything you don't need 48 | * no ORM 49 | * no query builder 50 | * no connect function 51 | * no disconnect function 52 | * no connection pool manager 53 | * no configuration 54 | * no initialization 55 | * no callbacks 56 | 57 | ### API 58 | 59 | ##### db.query(sql, params = []) 60 | run a query 61 | 62 | returns a promise, which resolves with a pg [Result](https://node-postgres.com/api/result) object 63 | 64 | This is best for INSERT/UPDATE/DELETE/etc queries which will not return any rows. If you are doing a SELECT, you probably want one of the functions below. 65 | 66 | ```js 67 | let result = await db.query('UPDATE accounts SET enabled = true') 68 | console.log(result.command + ' ' + result.rowCount) // => UPDATE 2 69 | ``` 70 | 71 | ##### db.rows(sql, params = []) 72 | run a query 73 | 74 | returns a promise, which resolves with an array of row objects 75 | 76 | ```js 77 | let accounts = await db.rows('SELECT * FROM accounts') 78 | for (let account of accounts) { 79 | console.log(account.id + ': ' + account.name) // => "1: ACME" 80 | } 81 | ``` 82 | 83 | ##### db.row(sql, params = []) 84 | run a query 85 | 86 | returns a promise, which resolves with the first row object 87 | 88 | This will **not** automatically add `LIMIT 1` to the end of the query. 89 | 90 | ```js 91 | let account = await db.row('SELECT * FROM accounts WHERE id = 1') 92 | console.log(account.name) // => "ACME" 93 | ``` 94 | 95 | ##### db.value(sql, params = []) 96 | run a query 97 | 98 | returns a promise, which resolves with the first column of the first row 99 | 100 | This is useful for things like counts. 101 | 102 | ```js 103 | let accountName = await db.value('SELECT name FROM accounts WHERE id = 1') 104 | console.log(accountName) // => "ACME" 105 | ``` 106 | 107 | ##### db.column(sql, params = []) 108 | run a query 109 | 110 | returns a promise, which resolves with an array of the first values in each row 111 | 112 | Example: 113 | ```js 114 | let oneThroughFive = await db.column('SELECT * FROM generate_series(1, 5)') 115 | console.log(oneThroughFive) // => [1, 2, 3, 4, 5] 116 | ``` 117 | 118 | ##### template string mode 119 | 120 | Any of the above functions can be used with template string literals to make 121 | long queries more readable. Interpolated values will be moved to the `params` 122 | array and replaced with $1, $2, etc. 123 | 124 | Example: 125 | ```js 126 | let type = 'pancake' 127 | // the following two calls are identical: 128 | db.value` 129 | SELECT COUNT(*) 130 | FROM breakfast 131 | WHERE type = ${type} 132 | ` 133 | db.value('SELECT COUNT(*) FROM breakfast WHERE type = $1', [type]) 134 | ``` 135 | 136 | **Do not use parentheses around your 137 | template string or you will open yourself up to SQL injection attacks and you 138 | will have a bad day.** 139 | 140 | ```js 141 | let type = 'pancake \'; DELETE FROM accounts; --' 142 | // NOTE THE PARENTHESES AROUND THE BACKTICKS - DO NOT DO THIS 143 | db.value(` 144 | SELECT COUNT(*) 145 | FROM breakfast 146 | WHERE type = ${type} 147 | `) 148 | ``` 149 | 150 | If you need to interpolate an identifier such as a table name, the normal 151 | escaping will wrap your value in single quotes. Use the `db.identifier` function 152 | instead. 153 | 154 | Example: 155 | ```js 156 | let table = 'breakfast' 157 | let type = 'pancake' 158 | 159 | db.value` 160 | SELECT COUNT(*) 161 | FROM ${db.identifier(table)} 162 | WHERE type = ${type} 163 | ` 164 | ``` 165 | 166 | ##### db.template\`SELECT ${a}...\` 167 | 168 | Prepare a statement for later execution. This is good for testing functions that 169 | dynamically generate SQL. 170 | 171 | ```js 172 | let accountName = 'ACME' 173 | let tableName = 'users' 174 | 175 | let subquery = db.template` 176 | SELECT id 177 | FROM accounts 178 | WHERE name = ${accountName} 179 | ` 180 | let query = db.template` 181 | SELECT a, b 182 | FROM ${db.identifier(tableName)} 183 | WHERE account_id IN (${subquery}) 184 | ` 185 | 186 | let results = await db.rows(query) 187 | // [{a: , b: }, {a: , b: }, ...] 188 | 189 | let rawSql = query.__unsafelyGetRawSql() 190 | // SELECT a, b FROM "users" WHERE account_id IN (SELECT id FROM accounts WHERE name='ACME') 191 | ``` 192 | 193 | ##### db.transaction(block) 194 | perform a [database transaction](https://www.postgresql.org/docs/current/static/tutorial-transactions.html) 195 | 196 | **block**: should be a function which will perform work inside the transaction and return a promise. If the promise rejects, the transaction will be rolled back. 197 | 198 | returns a promise, which should resolve with the return value of **block** or reject if the transaction failed 199 | 200 | Example: 201 | ```js 202 | // process one order 203 | db.transaction(async function (trx) { 204 | let orderId = await trx.value('SELECT id FROM orders WHERE NOT shipped LIMIT 1 FOR UPDATE') 205 | 206 | await db.query('INSERT INTO shipments (order_id) VALUES ($1)', [orderId]) 207 | 208 | // if this update fails, the above insert will be rolled back! 209 | await db.query('UPDATE orders SET fulfilled = true WHERE id = $1', [orderId]) 210 | 211 | return orderId 212 | }) 213 | ``` 214 | 215 | ##### db.connection(block) 216 | perform multiple queries sequentially on a single connection 217 | 218 | **block**: should be a function which will perform work inside the connection 219 | and return a promise. When the promise resolves or rejects, the connection will 220 | be returned to the pool. 221 | 222 | Example: 223 | ```js 224 | let cookies = await db.connection(async function ({ query, value }) { 225 | // count the number of cookies, or timeout if it takes more than a minute 226 | await query('SET statement_timeout=60000') 227 | return value('SELECT COUNT(*) FROM cookies') 228 | }) 229 | ``` 230 | 231 | ##### Query cancellation 232 | The promises returned by `db.query`, `db.rows`, etc all have a `cancel` method 233 | which will kill the query on the backend. 234 | 235 | Example: 236 | ```js 237 | let query = db.query('SELECT COUNT(*) FROM slow_table') 238 | 239 | query.catch(err => { 240 | if (err instanceof db.Cancel) { 241 | console.log('query cancelled') 242 | } else { 243 | console.error('unexpected error', err) 244 | } 245 | }) 246 | 247 | q.cancel().then(() => console.log('cancel resolved')) 248 | 249 | // STDOUT: 250 | // query cancelled 251 | // cancel resolved 252 | ``` 253 | 254 | An obscure note about cancellation: `db.connection` and `db.transaction` do not 255 | have `.cancel()` methods, although you can cancel individual queries you run 256 | within them. 257 | 258 | ##### db.escape(value) 259 | 260 | *alias of db.escapeLiteral* 261 | 262 | escape a value for safe use in SQL queries, returns string 263 | 264 | While this function is tested and probably secure, you should avoid using it. 265 | Instead, use bind vars, as they are much more difficult to mess up. 266 | 267 | ##### db.escapeIdentifier(value) 268 | escape a value for safe use as an identifier in SQL queries, returns string 269 | 270 | Same as the above function, except for things like table names, column names, 271 | etc. 272 | 273 | ##### db.escapeLiterals(values, separator = ', ') 274 | escape an array of literals and join them with the given separator, returns string 275 | 276 | ```js 277 | db.escapeLiterals(['a', 'b', 'c']) === "'a', 'b', 'c'" 278 | ``` 279 | 280 | ##### db.escapeIdentifiers(values, separator = ', ') 281 | escape an array of identifiers and join them with the given separator, returns string 282 | 283 | ```js 284 | db.escapeIdentifiers(['a', 'b', 'c']) === '"a", "b", "c"' 285 | ``` 286 | 287 | ##### db.identifier(value) 288 | escapes an identifier in such a way that it can be passed safely into a template 289 | query, returns object 290 | 291 | Below, note the lack of parentheses around the SQL, with db.query being called 292 | as a template function. 293 | 294 | ```js 295 | let tableName = 'potentially "dangerous" table name' 296 | db.query` 297 | SELECT * FROM ${db.identifier(tableName)} 298 | ` 299 | ``` 300 | 301 | ##### db.identifiers(values, separator = ', ') 302 | escapes multiple identifiers in such a way that they can be passed safely into a 303 | template query, returns object 304 | 305 | ```js 306 | let columns = ['id', 'name'] 307 | db.query` 308 | SELECT ${db.identifiers(columns)} FROM accounts 309 | ` 310 | ``` 311 | 312 | ##### db.literals(values, separator = ', ') 313 | escapes multiple literals in such a way that they can be passed safely into a 314 | template query, returns object 315 | 316 | ```js 317 | let accounts = [1, 2, 3] 318 | db.query` 319 | SELECT id FROM accounts WHERE name IN(${db.literals(accounts)}) 320 | ` 321 | ``` 322 | 323 | ##### db.items(values, separator = ', ') 324 | escapes multiple items in such a way that they can be passed safely into a 325 | template query, returns object. Escapes literals by default, but allows identifiers 326 | and templates. 327 | 328 | ```js 329 | let defaultTitle = 'untitled' 330 | let select = [ 331 | 'test string', 332 | db.identifier('id'), 333 | db.template`COALESCE(title, ${defaultTitle}) AS title` 334 | ] 335 | 336 | let books = await db.rows` 337 | SELECT ${db.items(select)} 338 | FROM books 339 | ` 340 | /* 341 | SELECT 'test string', "id", COALESCE(title, 'untitled') AS title 342 | FROM books 343 | */ 344 | ``` 345 | 346 | ##### db.setErrorHandler(callback) 347 | sets a callback for otherwise unhandled errors such as dropped connections and other mysteries 348 | 349 | ### Contributing 350 | 351 | Please send pull requests! 352 | -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "simple-postgres", 3 | "version": "5.0.0", 4 | "description": "a minimal postgres interface for node", 5 | "main": "src/index.js", 6 | "keywords": [ 7 | "pg", 8 | "simple", 9 | "postgres", 10 | "postgresql", 11 | "database" 12 | ], 13 | "author": "Madeline Davies ", 14 | "license": "MIT", 15 | "dependencies": { 16 | "find-root": "^1.1.0", 17 | "pg": "^7.4.3", 18 | "pg-connection-string": "^0.1.3" 19 | }, 20 | "repository": { 21 | "type": "git", 22 | "url": "https://github.com/madd512/simple-postgres.git" 23 | }, 24 | "scripts": { 25 | "lint": "standard src/**/*.js; standard --parser babel-eslint test/**/*.js", 26 | "test": "NODE_ENV=test node test/test.js", 27 | "cover": "NODE_ENV=test istanbul cover -x test/test.js built-test/test.js" 28 | }, 29 | "devDependencies": { 30 | "babel-eslint": "^6.0.0", 31 | "blue-tape": "^0.2.0", 32 | "git-validate": "^2.1.4", 33 | "istanbul": "^0.4.3", 34 | "standard": "^7.1.1" 35 | }, 36 | "standard": { 37 | "parser": "babel-eslint" 38 | }, 39 | "pre-commit": [ 40 | "lint", 41 | "test" 42 | ] 43 | } 44 | -------------------------------------------------------------------------------- /src/escape.js: -------------------------------------------------------------------------------- 1 | // from https://github.com/brianc/node-postgres/blob/master/lib/client.js 2 | // ported from PostgreSQL 9.2.4 source code in src/interfaces/libpq/fe-exec.c 3 | // non-string handling added 4 | 5 | module.exports = { 6 | identifier (str) { 7 | let escaped = '"' 8 | for (let i = 0; i < str.length; i++) { 9 | let c = str[i] 10 | if (c === '"') { 11 | escaped += c + c 12 | } else { 13 | escaped += c 14 | } 15 | } 16 | escaped += '"' 17 | return escaped 18 | }, 19 | identifiers (identifiers, separator) { 20 | return identifiers.map(module.exports.identifier).join(separator || ', ') 21 | }, 22 | literal (str) { 23 | if (typeof str === 'number') { 24 | return str 25 | } else if (str === null) { 26 | return 'null' 27 | } else if (str === true) { 28 | return 'true' 29 | } else if (str === false) { 30 | return 'false' 31 | } else if (Array.isArray(str)) { 32 | return 'Array[' + str.map(module.exports.literal).join(', ') + ']' 33 | } 34 | 35 | let hasBackslash = false 36 | let escaped = '\'' 37 | for (let i = 0; i < str.length; i++) { 38 | let c = str[i] 39 | if (c === '\'') { 40 | escaped += c + c 41 | } else if (c === '\\') { 42 | escaped += c + c 43 | hasBackslash = true 44 | } else { 45 | escaped += c 46 | } 47 | } 48 | escaped += '\'' 49 | if (hasBackslash === true) { 50 | escaped = ' E' + escaped 51 | } 52 | return escaped 53 | }, 54 | literals (literals, separator) { 55 | return literals.map(module.exports.literal).join(separator || ', ') 56 | } 57 | } 58 | -------------------------------------------------------------------------------- /src/index.js: -------------------------------------------------------------------------------- 1 | const { Pool } = require('pg') 2 | const parseConnectionString = require('pg-connection-string').parse 3 | const parseUrl = require('url').parse 4 | const findRoot = require('find-root') 5 | const readFileSync = require('fs').readFileSync 6 | const escape = require('./escape') 7 | const inspect = require('util').inspect 8 | 9 | function DO_NOTHING () {} 10 | 11 | const INTERFACE = { 12 | query (client, ...args) { 13 | if (canGetRawSqlFrom(args[0])) { 14 | args[0] = args[0].__unsafelyGetRawSql() 15 | } 16 | if (Array.isArray(args[0])) args = sqlTemplate(client, args) 17 | let sql = args[0] 18 | let params = args[1] 19 | let query 20 | let cancelled 21 | let stack = (new Error()).stack 22 | const notices = [] 23 | function onNotice (notice) { 24 | notices.push(notice) 25 | } 26 | 27 | client.on('notice', onNotice) 28 | 29 | let promise = new Promise(function doQuery (resolve, reject) { 30 | if (cancelled) return reject(new Cancel()) 31 | query = client.query(sql, params, function onResult (err, result) { 32 | if (cancelled) { 33 | client.removeListener('notice', onNotice) 34 | reject(new Cancel()) 35 | } else if (err) { 36 | client.removeListener('notice', onNotice) 37 | reject(new SqlError(sql, params, stack, err, notices)) 38 | } else { 39 | client.removeListener('notice', onNotice) 40 | resolve(result) 41 | } 42 | }) 43 | }) 44 | 45 | promise.cancel = function cancel () { 46 | cancelled = true 47 | if (client.activeQuery === query) { 48 | return INTERFACE.query(client, 'SELECT pg_cancel_backend($1)', [client.processID]) 49 | } 50 | } 51 | 52 | return promise 53 | }, 54 | rows (...args) { 55 | return thenWithCancel(INTERFACE.query(...args), 56 | function (result) { return result.rows } 57 | ) 58 | }, 59 | row (...args) { 60 | return thenWithCancel(INTERFACE.query(...args), 61 | function (result) { return result.rows[0] } 62 | ) 63 | }, 64 | value (...args) { 65 | return thenWithCancel(INTERFACE.row(...args), 66 | function (row) { return row && row[ Object.keys(row)[0] ] } 67 | ) 68 | }, 69 | column (...args) { 70 | return thenWithCancel(INTERFACE.query(...args), 71 | function (result) { 72 | let col = result.rows[0] && Object.keys(result.rows[0])[0] 73 | return result.rows.map( 74 | function (row) { return row[col] } 75 | ) 76 | } 77 | ) 78 | } 79 | } 80 | 81 | class Cancel extends Error { 82 | constructor () { 83 | super() 84 | this.name = 'Cancel' 85 | this.message = 'Query cancelled' 86 | } 87 | } 88 | 89 | class SqlError extends Error { 90 | constructor (sql, params, stack, pgError, notices) { 91 | super() 92 | Object.assign(this, pgError) 93 | this.name = 'SqlError' 94 | this.message = ( 95 | 'SQL Error: ' + [...notices, pgError.message].join('\n') + '\n' + 96 | sql + 97 | (params && params.length 98 | ? '\nQuery parameters:' + stringifyParameters(params) 99 | : '')) 100 | this.stack = this.message + '\n' + stack.replace(/^.+\n/, '') 101 | } 102 | } 103 | 104 | function stringifyParameters (params) { 105 | return params.map(function (p, i) { 106 | return '\n $' + (i + 1) + ': ' + typeof p + ' ' + inspect(p) 107 | }).join('') 108 | } 109 | 110 | function thenWithCancel (promise, fn) { 111 | let newPromise = promise.then(fn) 112 | newPromise.cancel = promise.cancel.bind(promise) 113 | return newPromise 114 | } 115 | 116 | function sqlTemplate (client, values) { 117 | let strings = values.shift() 118 | let stringsLength = strings.length 119 | let valuesLength = values.length 120 | let maxLength = Math.max(stringsLength, valuesLength) 121 | let sql = '' 122 | let params = [] 123 | let val 124 | for (let i = 0; i < maxLength; i++) { 125 | if (i < stringsLength) { 126 | val = strings[i] 127 | if (canGetRawSqlFrom(val)) { 128 | sql += val.__unsafelyGetRawSql(client) 129 | } else { 130 | sql += val 131 | } 132 | } 133 | if (i < valuesLength) { 134 | val = values[i] 135 | if (canGetRawSqlFrom(val)) { 136 | sql += val.__unsafelyGetRawSql(client) 137 | } else { 138 | sql += '$' + params.push(val) 139 | } 140 | } 141 | } 142 | 143 | return [sql, params] 144 | } 145 | 146 | function templateIdentifier (value) { 147 | value = escape.identifier(value) 148 | return { 149 | __unsafelyGetRawSql () { 150 | return value 151 | } 152 | } 153 | } 154 | 155 | function templateIdentifiers (identifiers, separator) { 156 | let value = escape.identifiers(identifiers, separator) 157 | return { 158 | __unsafelyGetRawSql: function __unsafelyGetRawSql () { 159 | return value 160 | } 161 | } 162 | } 163 | 164 | function templateLiteral (value) { 165 | value = escape.literal(value) 166 | return { 167 | __unsafelyGetRawSql: function __unsafelyGetRawSql () { 168 | return value 169 | } 170 | } 171 | } 172 | 173 | function templateLiterals (literals, separator) { 174 | let value = escape.literals(literals, separator) 175 | return { 176 | __unsafelyGetRawSql: function __unsafelyGetRawSql () { 177 | return value 178 | } 179 | } 180 | } 181 | 182 | function templateItems (items, separator) { 183 | return { 184 | __unsafelyGetRawSql: function __unsafelyGetRawSql (client) { 185 | return items.map((v) => 186 | canGetRawSqlFrom(v) 187 | ? v.__unsafelyGetRawSql(client) 188 | : escape.literal(v) 189 | ).join(separator || ', ') 190 | } 191 | } 192 | } 193 | 194 | function canGetRawSqlFrom (v) { 195 | return ( 196 | typeof v === 'object' && 197 | v !== null && 198 | typeof v.__unsafelyGetRawSql === 'function' && 199 | Object.keys(v).length === 1 200 | ) 201 | } 202 | 203 | function withConnection (connection, work, cancellable) { 204 | let client 205 | let done 206 | let cancelled 207 | let activeWork 208 | let finishCancel 209 | 210 | let promise = 211 | connection.then(function onConnect (conn) { 212 | client = conn[0] 213 | done = conn[1] 214 | 215 | if (cancelled) { 216 | setImmediate(finishCancel) 217 | throw new Cancel() 218 | } 219 | 220 | activeWork = work(client) 221 | return activeWork 222 | }).then(function onResult (result) { 223 | if (cancelled) { 224 | setImmediate(finishCancel) 225 | throw new Cancel() 226 | } 227 | 228 | done() 229 | 230 | return result 231 | }).catch(function onError (err) { 232 | if (done) { 233 | if (err instanceof Error && err.ABORT_CONNECTION) { 234 | // this is a really bad one, remove the connection from the pool 235 | done(err) 236 | } else { 237 | done() 238 | } 239 | } 240 | 241 | if (cancelled) { 242 | setImmediate(finishCancel) 243 | throw new Cancel() 244 | } 245 | 246 | throw err 247 | }) 248 | 249 | if (cancellable) { 250 | promise.cancel = function () { 251 | cancelled = true 252 | if (activeWork !== null && typeof activeWork === 'object' && typeof activeWork.cancel === 'function') { 253 | return activeWork.cancel() 254 | } else { 255 | return new Promise(function (resolve) { finishCancel = resolve }) 256 | } 257 | } 258 | } 259 | 260 | return promise 261 | } 262 | 263 | function getApplicationName () { 264 | let path = findRoot(process.argv[1] || process.cwd()) + '/package.json' 265 | let pkg = JSON.parse(readFileSync(path, 'utf8')) 266 | return pkg.name 267 | } 268 | 269 | function configure (server) { 270 | if (typeof server === 'string') { 271 | server = Object.assign( 272 | parseConnectionString(server), 273 | parseUrl(server, true).query // add query parameters 274 | ) 275 | } else if (typeof server === 'undefined') { 276 | server = {} 277 | } 278 | 279 | for (let v of ['ssl', 'keepAlive', 'binary']) { 280 | if (typeof server[v] === 'string') { 281 | server[v] = server[v] !== 'false' 282 | } 283 | } 284 | for (let v of ['idleTimeoutMillis', 'poolSize', 'max', 'statement_timeout']) { 285 | if (typeof server[v] === 'string') { 286 | server[v] = server[v] === 'false' ? false : Number(server[v]) 287 | } 288 | } 289 | 290 | if ((server.poolSize || process.env.PG_POOL_SIZE) && typeof server.max === 'undefined') { 291 | server.max = server.poolSize || process.env.PG_POOL_SIZE 292 | } 293 | server.idleTimeoutMillis = ( 294 | server.idleTimeoutMillis || 295 | process.env.PG_IDLE_TIMEOUT || 296 | (process.env.NODE_ENV === 'test' && 1) 297 | ) 298 | server.application_name = ( 299 | server.application_name || 300 | process.env.APPLICATION_NAME || 301 | getApplicationName() 302 | ) 303 | 304 | let handleError = server.errorHandler || DO_NOTHING 305 | function setErrorHandler (handler) { 306 | handleError = handler || DO_NOTHING 307 | } 308 | 309 | if (server.debug_postgres || process.env.DEBUG_POSTGRES) { 310 | const defaultLog = server.log || DO_NOTHING 311 | server.log = function debugLog (...args) { 312 | console.debug('simple-postgres debug', ...args) 313 | defaultLog(...args) 314 | } 315 | } 316 | 317 | let _pool 318 | function pool () { 319 | if (!_pool) { 320 | _pool = new Promise(resolve => { 321 | const p = new Pool(server) 322 | p.on('error', (...args) => handleError(...args)) 323 | resolve(p) 324 | }) 325 | } 326 | return _pool 327 | } 328 | 329 | function connect () { 330 | // TODO: allow returning just the client, not the tuple of client + release fn 331 | return pool().then(p => p.connect()).then(client => { 332 | if (typeof client.__simplePostgresOnError === 'undefined') { 333 | client.__simplePostgresOnError = true 334 | client.on('error', (...args) => handleError(...args)) 335 | } 336 | return [client, client.release.bind(client)] 337 | }) 338 | } 339 | 340 | let iface = { 341 | connection (work) { 342 | return withConnection(connect(), function doConnection (client) { 343 | return work(Object.keys(INTERFACE).reduce(function linkInterface (i, methodName) { 344 | i[methodName] = INTERFACE[methodName].bind(null, client) 345 | i[methodName].displayName = methodName + '_in_connection' 346 | return i 347 | }, {})) 348 | }) 349 | }, 350 | transaction (work) { 351 | return iface.connection(function doTransaction (connIface) { 352 | let result 353 | let inTransaction 354 | 355 | return ( 356 | connIface.query('begin') 357 | .then(function onBegin () { 358 | inTransaction = true 359 | return work(connIface) 360 | }) 361 | .then(function onResult (_result) { 362 | result = _result 363 | return connIface.query('commit') 364 | }) 365 | .then(function onCommit () { 366 | return result 367 | }) 368 | .catch(function onError (err) { 369 | if (!inTransaction) throw err 370 | 371 | return ( 372 | connIface.query('rollback') 373 | .catch(function onRollbackFail (rollbackErr) { 374 | err = (err instanceof Error ? err.message + '\n' + err.stack : err) 375 | rollbackErr = (rollbackErr instanceof Error ? rollbackErr.message + '\n' + rollbackErr.stack : rollbackErr) 376 | let bigErr = new Error( 377 | 'Failed to execute rollback after error\n' + 378 | err + '\n\n' + rollbackErr 379 | ) 380 | bigErr.ABORT_CONNECTION = true 381 | throw bigErr 382 | }) 383 | .then(function onRollback () { 384 | throw err 385 | }) 386 | ) 387 | }) 388 | ) 389 | }) 390 | } 391 | } 392 | 393 | iface.template = function sqlTemplate (strings, ...values) { 394 | let stringsLength = strings.length 395 | let valuesLength = values.length 396 | let maxLength = Math.max(stringsLength, valuesLength) 397 | 398 | return { 399 | __unsafelyGetRawSql (client) { 400 | let sql = '' 401 | for (let i = 0; i < maxLength; i++) { 402 | if (i < stringsLength) { 403 | sql += strings[i] 404 | } 405 | if (i < valuesLength) { 406 | if (canGetRawSqlFrom(values[i])) { 407 | sql += values[i].__unsafelyGetRawSql(client) 408 | } else { 409 | sql += iface.escapeLiteral(values[i]) 410 | } 411 | } 412 | } 413 | return sql 414 | } 415 | } 416 | } 417 | iface.escape = escape.literal 418 | iface.escapeLiteral = escape.literal 419 | iface.escapeLiterals = escape.literals 420 | iface.escapeIdentifier = escape.identifier 421 | iface.escapeIdentifiers = escape.identifiers 422 | 423 | iface.items = templateItems 424 | iface.identifier = templateIdentifier 425 | iface.identifiers = templateIdentifiers 426 | iface.literal = templateLiteral 427 | iface.literals = templateLiterals 428 | iface.pool = pool 429 | iface.setErrorHandler = setErrorHandler 430 | 431 | iface = Object.keys(INTERFACE).reduce(function linkInterface (i, methodName) { 432 | i[methodName] = function (...args) { 433 | return withConnection(connect(), function onConnect (client) { 434 | return INTERFACE[methodName](client, ...args) 435 | }, true) 436 | } 437 | i[methodName].displayName = methodName 438 | return i 439 | }, iface) 440 | 441 | return iface 442 | } 443 | 444 | module.exports = configure(process.env.DATABASE_URL) 445 | module.exports.configure = configure 446 | module.exports.Cancel = Cancel 447 | module.exports.SqlError = SqlError 448 | -------------------------------------------------------------------------------- /test/test.js: -------------------------------------------------------------------------------- 1 | const test = require('blue-tape') 2 | const db = require('../src') 3 | 4 | function countConnections (pool) { 5 | return pool.totalCount 6 | } 7 | 8 | function destroyConnections (pool) { 9 | // break things by destroying all connections everywhere 10 | return Promise.all(pool._clients.map(c => c.end())) 11 | } 12 | 13 | test('cancel', async function (t) { 14 | let q = db.query('SELECT pg_sleep(10)') 15 | let err 16 | q.then(val => t.fail('pg_sleep should be cancelled')).catch(e => { err = e }) 17 | await q.cancel() 18 | t.ok(err instanceof db.Cancel, 'query should be cancelled') 19 | }) 20 | 21 | test('db.connection', async function (t) { 22 | await db.connection(async function ({ query, value }) { 23 | await query('SET statement_timeout=123456789') 24 | await db.query('RESET statement_timeout') 25 | t.equal(await value('SHOW statement_timeout'), '123456789ms', 'should use the same connection') 26 | }) 27 | }) 28 | 29 | test('db.connection cancel', async function (t) { 30 | await db.connection(async function ({ query, value }) { 31 | let q = db.query('SELECT pg_sleep(10)') 32 | let err 33 | q.then(val => t.fail('pg_sleep should be cancelled')).catch(e => { err = e }) 34 | await q.cancel() 35 | t.ok(err instanceof db.Cancel, 'query should be cancelled') 36 | }) 37 | }) 38 | 39 | test('db.query', async function (t) { 40 | let result = await db.query('select * from generate_series(1, 3) g') 41 | t.equal(result.rowCount, 3, 'should return result with rowCount property') 42 | t.equal(result.command, 'SELECT', 'should return result with command property') 43 | t.ok(Array.isArray(result.rows), 'should return result with rows property') 44 | }) 45 | 46 | test('db.query (template string)', async function (t) { 47 | let result = await db.query`select * from generate_series(${1}::int, ${2 + 1}::int) g` 48 | t.equal(result.rowCount, 3, 'should return result with rowCount property') 49 | t.equal(result.command, 'SELECT', 'should return result with command property') 50 | t.ok(Array.isArray(result.rows), 'should return result with rows property') 51 | }) 52 | 53 | test('db.rows', async function (t) { 54 | t.deepEqual( 55 | await db.rows('select * from generate_series(1, 3) g'), 56 | [1, 2, 3].map( 57 | (g) => ({g}) 58 | ), 59 | 'should return an array of objects' 60 | ) 61 | }) 62 | 63 | test('db.rows (template string)', async function (t) { 64 | t.deepEqual( 65 | await db.rows`select * from generate_series(${1}::int, ${2 + 1}::int) g`, 66 | [1, 2, 3].map( 67 | (g) => ({g}) 68 | ), 69 | 'should return an array of objects' 70 | ) 71 | }) 72 | 73 | test('db.row', async function (t) { 74 | t.deepEqual( 75 | await db.row('select 1 as a'), 76 | {a: 1}, 77 | 'should return a single object' 78 | ) 79 | }) 80 | 81 | test('db.row (template string)', async function (t) { 82 | t.deepEqual( 83 | await db.row`select ${1}::int as a`, 84 | {a: 1}, 85 | 'should return a single object' 86 | ) 87 | }) 88 | 89 | test('db.row (template string with no args)', async function (t) { 90 | t.deepEqual( 91 | await db.row`select 1::int as a`, 92 | {a: 1}, 93 | 'should return a single object' 94 | ) 95 | }) 96 | 97 | test('db.value', async function (t) { 98 | t.equal( 99 | await db.value('select 1'), 100 | 1, 101 | 'should return a single value' 102 | ) 103 | }) 104 | 105 | test('db.value (template string)', async function (t) { 106 | t.equal( 107 | await db.value`select ${1}::int`, 108 | 1, 109 | 'should return a single value' 110 | ) 111 | }) 112 | 113 | test('db.column', async function (t) { 114 | t.deepEqual( 115 | await db.column('select * from generate_series(1, 3)'), 116 | [1, 2, 3], 117 | 'should return an array of the first value in each row' 118 | ) 119 | }) 120 | 121 | test('db.column (template string)', async function (t) { 122 | t.deepEqual( 123 | await db.column`select * from generate_series(${1}::int, ${3}::int)`, 124 | [1, 2, 3], 125 | 'should return an array of the first value in each row' 126 | ) 127 | }) 128 | 129 | test('sql-injection-proof template strings', async function (t) { 130 | let evil = 'SELECT evil"\'' 131 | t.equal( 132 | await db.value`SELECT ${evil}::text`, 133 | evil 134 | ) 135 | }) 136 | 137 | test('sql-injection-proof template array values', async function (t) { 138 | let evil = 'SELECT evil"\'' 139 | t.deepEqual( 140 | await db.value`SELECT ${[evil]}::text[]`, 141 | [evil] 142 | ) 143 | }) 144 | 145 | test('escaping', async function (t) { 146 | t.equal(db.escape('a\'a\\'), ' E\'a\'\'a\\\\\'') 147 | t.equal(db.escape(null), 'null') 148 | t.equal(db.escape(false), 'false') 149 | t.equal(db.escape(true), 'true') 150 | t.equal(db.escapeLiterals(['a', 'b']), '\'a\', \'b\'') 151 | t.equal(db.escapeIdentifiers(['a', 'b']), '"a", "b"') 152 | }) 153 | 154 | test('identifier escaping', async function (t) { 155 | t.equal(db.escapeIdentifier('weird " ?'), '"weird "" ?"') 156 | }) 157 | 158 | test('identifier template escaping', async function (t) { 159 | t.equal( 160 | await db.value`SELECT '${db.identifier('weird " string')}'::text`, 161 | '"weird "" string"' 162 | ) 163 | }) 164 | 165 | test('identifiers template escaping', async function (t) { 166 | let weird = ['a"a\\'] 167 | t.deepEqual( 168 | await db.value`SELECT '${db.identifiers(weird)}'::text`, 169 | '"a""a\\"' 170 | ) 171 | }) 172 | 173 | test('literal template escaping', async function (t) { 174 | let weird = 'a\'a\\' 175 | t.equal( 176 | await db.value`SELECT ${db.literal(weird)}::text`, 177 | weird 178 | ) 179 | }) 180 | 181 | test('literals template escaping', async function (t) { 182 | let weird = ['a\'a\\'] 183 | t.deepEqual( 184 | await db.value`SELECT Array[${db.literals(weird)}]::text[]`, 185 | weird 186 | ) 187 | }) 188 | 189 | test('array escaping', async function (t) { 190 | t.equal( 191 | db.escape([1, 2, 3]), 192 | 'Array[1, 2, 3]' 193 | ) 194 | t.equal( 195 | db.escape(['a\'', 'b', 'c"']), 196 | 'Array[\'a\'\'\', \'b\', \'c"\']' 197 | ) 198 | t.equal( 199 | db.escape([true, false, null]), 200 | 'Array[true, false, null]' 201 | ) 202 | }) 203 | 204 | test('sql template', async function (t) { 205 | let tpl = db.template`SELECT ${1} AS a, ${[1, 2, 3]} AS ${db.identifier('b')}` 206 | t.equal(tpl.__unsafelyGetRawSql(), 'SELECT 1 AS a, Array[1, 2, 3] AS "b"') 207 | 208 | let result = await db.row(tpl) 209 | t.deepEqual(result, {a: 1, b: [1, 2, 3]}) 210 | }) 211 | 212 | test('nested sql template', async function (t) { 213 | let subquery = db.template`SELECT ${1} AS ${db.identifier('a')}` 214 | let query = db.template`SELECT ${db.identifier('b')}.${db.identifier('a')} FROM (${subquery}) AS ${db.identifier('b')}` 215 | t.equal(query.__unsafelyGetRawSql(), 'SELECT "b"."a" FROM (SELECT 1 AS "a") AS "b"') 216 | 217 | let result = await db.row(query) 218 | t.deepEqual(result, {a: 1}) 219 | }) 220 | 221 | test('items template escaping', async function (t) { 222 | let query = db.items([1, '2', db.template`COALESCE(3, 4)`]) 223 | t.equal(query.__unsafelyGetRawSql(), '1, \'2\', COALESCE(3, 4)') 224 | }) 225 | 226 | test('successful transaction', async function (t) { 227 | await db.query('drop table if exists beep') 228 | await db.query('create table beep (id integer)') 229 | await db.query('insert into beep (id) values (1), (2), (3)') 230 | 231 | await db.transaction(async function (trx) { 232 | t.deepEqual( 233 | await trx.column('select id from beep order by id -- trx 1'), 234 | [1, 2, 3], 235 | 'boop is sane' 236 | ) 237 | 238 | await trx.query('delete from beep where id=2') 239 | await trx.query('insert into beep (id) VALUES (4), (5), (6)') 240 | 241 | t.deepEqual( 242 | await db.column('select id from beep order by id -- db'), 243 | [1, 2, 3], 244 | 'changes are invisible outside transaction' 245 | ) 246 | 247 | t.deepEqual( 248 | await trx.column('select id from beep order by id -- trx 2'), 249 | [1, 3, 4, 5, 6], 250 | 'changes are visible inside transaction' 251 | ) 252 | }) 253 | 254 | t.deepEqual( 255 | await db.column('select id from beep order by id -- after'), 256 | [1, 3, 4, 5, 6], 257 | 'changes are visible after commit' 258 | ) 259 | }) 260 | 261 | test('bad connection url', async function (t) { 262 | try { 263 | await db.configure('postgres://example').query('select 1') 264 | t.fail('should not be able to connect to postgres://example') 265 | } catch (err) { 266 | t.equal(err.code, 'ENOTFOUND', 'incorrect host should throw ENOTFOUND') 267 | if (err.code !== 'ENOTFOUND') throw err 268 | } 269 | }) 270 | 271 | test('bad query', async function (t) { 272 | try { 273 | await db.query('not a real sql query lol') 274 | t.fail('should not be able to execute an invalid query') 275 | } catch (err) { 276 | t.equal(err.message, 'SQL Error: syntax error at or near "not"\nnot a real sql query lol', 'should throw syntax error') 277 | } 278 | }) 279 | 280 | test('bad query with params', async function (t) { 281 | try { 282 | await db.query('SELECT * FROM imaginary_table WHERE id = $1 AND imaginary = $2', [1, true]) 283 | t.fail('should not be able to execute an invalid query') 284 | } catch (err) { 285 | t.equal(err.message, 'SQL Error: relation "imaginary_table" does not exist\nSELECT * FROM imaginary_table WHERE id = $1 AND imaginary = $2\nQuery parameters:\n $1: number 1\n $2: boolean true', 'should throw syntax error') 286 | } 287 | }) 288 | 289 | test('error with notice', async function (t) { 290 | const sql = 'DO language plpgsql $$ BEGIN RAISE NOTICE \'notice\'; SELECT \'1.0\'::int; END $$' 291 | try { 292 | await db.query(sql) 293 | t.fail('should not be able to execute an invalid query') 294 | } catch (err) { 295 | t.equal(err.message, `SQL Error: notice: notice\ninvalid input syntax for integer: "1.0"\n${sql}`) 296 | } 297 | }) 298 | 299 | test('error with multiple notices', async function (t) { 300 | const sql = 'DO language plpgsql $$ BEGIN RAISE NOTICE \'notice\'; RAISE WARNING \'warning\'; SELECT \'1.0\'::int; END $$' 301 | try { 302 | await db.query(sql) 303 | t.fail('should not be able to execute an invalid query') 304 | } catch (err) { 305 | t.equal(err.message, `SQL Error: notice: notice\nnotice: warning\ninvalid input syntax for integer: "1.0"\n${sql}`) 306 | } 307 | }) 308 | 309 | test('bad sql in transaction', async function (t) { 310 | try { 311 | await db.transaction(async function ({ query }) { 312 | await query('not a real sql query lol') 313 | }) 314 | t.fail('transaction errors should cause the promise to reject') 315 | } catch (err) { 316 | t.equal(err.ABORT_CONNECTION, undefined, 'transaction errors should be recoverable') 317 | } 318 | 319 | t.equal( 320 | countConnections(await db.pool()), 321 | 1, 322 | 'rollbacks should keep the connection in the pool' 323 | ) 324 | }) 325 | 326 | test('failed rollback', async function (t) { 327 | try { 328 | await db.transaction(async function ({ query }) { 329 | // break the transaction by destroying all connections everywhere 330 | await destroyConnections(await db.pool()) 331 | throw new Error('initial transaction error') 332 | }) 333 | t.fail('transaction errors should cause the promise to reject') 334 | } catch (err) { 335 | t.ok(/Error: Failed to execute rollback after error\n/.test(err), 'broken rollback should explain what\'s up') 336 | t.ok(/Error: initial transaction error\n {4}at /.test(err), 'broken rollback should contain initial error stack') 337 | t.ok(/SQL Error: This socket has been ended/.test(err), 'broken rollback should contain the rollback error stack') 338 | t.equal(err.ABORT_CONNECTION, true, 'transaction errors should propagate up') 339 | } 340 | 341 | t.equal( 342 | countConnections(await db.pool()), 343 | 0, 344 | 'failed transaction rollbacks should remove the client from the pool' 345 | ) 346 | }) 347 | --------------------------------------------------------------------------------