├── .gitignore ├── test ├── utils.js ├── encode.js ├── samples_coverage.js ├── rawReader.js ├── decode.js ├── rowWriter.js ├── rowReader.js ├── transform.js ├── fieldReader.js └── samples.js ├── index.js ├── .travis.yml ├── Makefile ├── .eslintrc.js ├── lib ├── rawReader.js ├── fieldReader.js ├── rowReader.js ├── transform.js ├── rowWriter.js ├── genericReader.js └── pg_types.js ├── package.json └── README.md /.gitignore: -------------------------------------------------------------------------------- 1 | node_modules/ 2 | -------------------------------------------------------------------------------- /test/utils.js: -------------------------------------------------------------------------------- 1 | const pg = require('pg') 2 | 3 | module.exports = { 4 | getClient: () => { 5 | const client = new pg.Client() 6 | client.connect() 7 | return client 8 | }, 9 | } 10 | -------------------------------------------------------------------------------- /index.js: -------------------------------------------------------------------------------- 1 | module.exports = { 2 | fieldReader: require('./lib/fieldReader'), 3 | rawReader: require('./lib/rawReader'), 4 | rowReader: require('./lib/rowReader'), 5 | rowWriter: require('./lib/rowWriter'), 6 | transform: require('./lib/transform'), 7 | } 8 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | language: node_js 2 | node_js: 3 | - "8" 4 | - "10" 5 | - "12" 6 | addons: 7 | postgresql: "9.6" 8 | 9 | services: 10 | - postgresql 11 | 12 | before_install: 13 | - npm install npm --global 14 | env: 15 | - PGUSER=postgres PGDATABASE=postgres 16 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | .PHONY: publish-patch test 2 | 3 | test: 4 | npm test 5 | 6 | patch: test 7 | npm version patch -m "Bump version" 8 | git push origin master --tags 9 | npm publish 10 | 11 | minor: test 12 | npm version minor -m "Bump version" 13 | git push origin master --tags 14 | npm publish 15 | 16 | major: test 17 | npm version major -m "Bump version" 18 | git push origin master --tags 19 | npm publish 20 | 21 | 22 | 23 | 24 | -------------------------------------------------------------------------------- /.eslintrc.js: -------------------------------------------------------------------------------- 1 | module.exports = { 2 | plugins: ['prettier'], 3 | extends: ['plugin:prettier/recommended'], 4 | parserOptions: { 5 | ecmaVersion: 2018, 6 | sourceType: 'module', 7 | }, 8 | env: { 9 | node: true, 10 | es6: true, 11 | mocha: true, 12 | }, 13 | rules: { 14 | 'prefer-const': ['error'], 15 | 'no-var': ['error'], 16 | 'no-unused-vars': ['error', { args: 'none' }], 17 | 'prefer-destructuring': ['error', { array: false }], 18 | 'no-useless-rename': ['error'], 19 | }, 20 | } 21 | -------------------------------------------------------------------------------- /test/encode.js: -------------------------------------------------------------------------------- 1 | const assert = require('assert') 2 | const util = require('util') 3 | 4 | const pgtypes = require('../lib/pg_types') 5 | const { encode } = pgtypes 6 | 7 | const BP = require('bufferput') 8 | const samples = require('./samples') 9 | 10 | describe('encode', () => { 11 | samples.forEach(function (s) { 12 | it(`encode type ${s.t}: ${util.inspect(s.v)}`, async () => { 13 | const buf = encode(new BP(), s.t, s.v).buffer() 14 | const eq = buf.equals(s.r) 15 | assert( 16 | eq, 17 | 'encode ' + 18 | s.t + 19 | ' not matching: ' + 20 | (s.v !== null ? s.v.toString() : 'null') + 21 | ' => ' + 22 | buf.toString('hex') + 23 | ' / ' + 24 | s.r.toString('hex') 25 | ) 26 | }) 27 | }) 28 | }) 29 | -------------------------------------------------------------------------------- /lib/rawReader.js: -------------------------------------------------------------------------------- 1 | module.exports = function (txt, options) { 2 | return new rowReader(txt, options) 3 | } 4 | 5 | const BufferList = require('bl/BufferList') 6 | const binaryReader = require('./genericReader') 7 | 8 | class rowReader extends binaryReader { 9 | constructor(options = {}) { 10 | super(options) 11 | this._rawHolder = new BufferList() 12 | } 13 | 14 | endOfChunk() { 15 | const len = this._rawHolder.length 16 | if (len) { 17 | const buf = this._rawHolder.slice() 18 | this._rawHolder.consume(len) 19 | this.push(buf) 20 | } 21 | } 22 | 23 | setupFieldHolder() {} 24 | 25 | captureFieldData(bl) { 26 | this._rawHolder.append(bl) 27 | } 28 | 29 | releaseFieldHolder() {} 30 | 31 | _flush(cb) { 32 | this._rawHolder = null 33 | super._flush(cb) 34 | } 35 | } 36 | -------------------------------------------------------------------------------- /test/samples_coverage.js: -------------------------------------------------------------------------------- 1 | const assert = require('assert') 2 | 3 | const pgtypes = require('../lib/pg_types') 4 | const { types } = pgtypes 5 | 6 | const samples = require('./samples') 7 | 8 | describe('sample coverage', () => { 9 | it('all implemented types should be tested both for NULL and not NULL values', async () => { 10 | for (const k in types) { 11 | let has_null = 0 12 | let has_not_null = 0 13 | samples.forEach(function (s) { 14 | if (k === s.t && s.v === null) has_null++ 15 | if (k === s.t && s.v !== null) has_not_null++ 16 | }) 17 | assert(has_null >= 1, 'samples for type ' + k + ' should have a sample testing the NULL value') 18 | assert(has_not_null >= 1, 'samples for type ' + k + ' should have at least one sample testing a NOT NULL value') 19 | } 20 | }) 21 | }) 22 | -------------------------------------------------------------------------------- /lib/fieldReader.js: -------------------------------------------------------------------------------- 1 | module.exports = function (txt, options) { 2 | return new rowReader(txt, options) 3 | } 4 | 5 | const binaryReader = require('./genericReader') 6 | 7 | class rowReader extends binaryReader { 8 | constructor(options = {}) { 9 | options.readableObjectMode = true 10 | super(options) 11 | this.mapping = options.mapping || false 12 | } 13 | 14 | fieldReady() { 15 | const o = {} 16 | o._fieldIndex = this._fieldIndex 17 | o._fieldCount = this._fieldCount 18 | o._fieldLength = this._fieldLength 19 | const key = this.mapping ? this.mapping[this._fieldIndex].key : 'value' 20 | o.name = key 21 | o.value = this._fieldHolder 22 | this.push(o) 23 | } 24 | 25 | fieldMode() { 26 | return this.mapping ? this.mapping[this._fieldIndex].mode : 'sync' 27 | } 28 | 29 | fieldType() { 30 | return this.mapping ? this.mapping[this._fieldIndex].type : null 31 | } 32 | } 33 | -------------------------------------------------------------------------------- /lib/rowReader.js: -------------------------------------------------------------------------------- 1 | module.exports = function (txt, options) { 2 | return new rowReader(txt, options) 3 | } 4 | 5 | const binaryReader = require('./genericReader') 6 | 7 | class rowReader extends binaryReader { 8 | constructor(options = {}) { 9 | options.readableObjectMode = true 10 | super(options) 11 | 12 | this.mapping = options.mapping || false 13 | this._row = null 14 | } 15 | 16 | rowStart() { 17 | this._row = this.mapping ? {} : [] 18 | } 19 | 20 | fieldReady() { 21 | if (this.mapping) { 22 | this._row[this.mapping[this._fieldIndex].key] = this._fieldHolder 23 | } else { 24 | this._row.push(this._fieldHolder) 25 | } 26 | if (this._fieldIndex === this._fieldCount - 1) { 27 | this.push(this._row) 28 | } 29 | } 30 | 31 | fieldMode() { 32 | return 'sync' 33 | } 34 | 35 | fieldType() { 36 | return this.mapping ? this.mapping[this._fieldIndex].type : null 37 | } 38 | 39 | _flush(cb) { 40 | this._row = null 41 | super._flush(cb) 42 | } 43 | } 44 | -------------------------------------------------------------------------------- /lib/transform.js: -------------------------------------------------------------------------------- 1 | const through2 = require('through2') 2 | const MultiFork = require('multi-fork') 3 | 4 | const rowReader = require('./rowReader') 5 | const rowWriter = require('./rowWriter') 6 | 7 | const shift = function () { 8 | return through2.obj(function (row, _, cb) { 9 | row.shift() 10 | this.push(row) 11 | cb() 12 | }) 13 | } 14 | 15 | module.exports = function (opt) { 16 | const { mapping } = opt 17 | const { transform } = opt 18 | const copyIns = opt.targets 19 | 20 | const first = rowReader({ mapping: mapping }) 21 | const n = copyIns.length 22 | let f = n 23 | const finish = function () { 24 | f-- 25 | if (f === 0) { 26 | first.emit('close') 27 | } 28 | } 29 | const classifier = function (row, cb) { 30 | cb(null, row[0]) 31 | } 32 | const M = new MultiFork(n, { classifier: classifier }) 33 | for (let i = 0; i < n; i++) { 34 | copyIns[i].on('finish', finish) 35 | M.streams[i].pipe(shift()).pipe(rowWriter()).pipe(copyIns[i]) 36 | } 37 | first.pipe(transform).pipe(M) 38 | return first 39 | } 40 | -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pg-copy-streams-binary", 3 | "version": "2.2.0", 4 | "description": "Streams for parsing and deparsing the COPY binary format", 5 | "main": "index.js", 6 | "scripts": { 7 | "test": "npm run lint && mocha", 8 | "lint": "[ \"$(node -v | cut -d. -f1)\" = \"v8\" ] || eslint '**/*.{js,ts}'" 9 | }, 10 | "repository": { 11 | "type": "git", 12 | "url": "git://github.com/jeromew/node-pg-copy-streams-binary.git" 13 | }, 14 | "author": "Jérôme Wagner", 15 | "license": "MIT", 16 | "bugs": { 17 | "url": "https://github.com/jeromew/node-pg-copy-streams-binary/issues" 18 | }, 19 | "dependencies": { 20 | "bl": "^4.0.3", 21 | "bufferput": "^0.1.3", 22 | "ieee754": "^1.1.13", 23 | "int64-buffer": "^0.99.1007", 24 | "multi-fork": "0.0.2", 25 | "through2": "^3.0.1" 26 | }, 27 | "devDependencies": { 28 | "async": "^3.2.1", 29 | "concat-stream": "^2.0.0", 30 | "deeper": "^2.1.0", 31 | "eslint": "^7.32.0", 32 | "eslint-config-prettier": "^8.3.0", 33 | "eslint-plugin-prettier": "^3.4.1", 34 | "gonna": "0.0.0", 35 | "mocha": "^9.1.0", 36 | "pg": "^8.7.1", 37 | "pg-copy-streams": "^6.0.1", 38 | "prettier": "^2.0.5" 39 | }, 40 | "prettier": { 41 | "semi": false, 42 | "printWidth": 120, 43 | "arrowParens": "always", 44 | "trailingComma": "es5", 45 | "singleQuote": true 46 | } 47 | } 48 | -------------------------------------------------------------------------------- /test/rawReader.js: -------------------------------------------------------------------------------- 1 | const assert = require('assert') 2 | const { rawReader } = require('../') 3 | const { to: copyTo } = require('pg-copy-streams') 4 | const concat = require('concat-stream') 5 | const { getClient } = require('./utils') 6 | 7 | describe('integration test - rawReader', () => { 8 | it('stream all raw bytes / small fields including empty and null', (done) => { 9 | const sql = `COPY ((SELECT 'a'::bytea, 'b'::bytea, ''::bytea) UNION ALL (SELECT null, 'c'::bytea, 'd'::bytea)) TO STDOUT BINARY` 10 | const client = getClient() 11 | const copyOutStream = client.query(copyTo(sql)) 12 | const assertResult = (buf) => { 13 | client.end() 14 | assert.deepEqual(buf, Buffer.from('abcd')) 15 | done() 16 | } 17 | const p = rawReader() 18 | p.on('error', (err) => { 19 | client.end() 20 | done(err) 21 | }) 22 | copyOutStream.pipe(p).pipe(concat({ encoding: 'buffer' }, assertResult)) 23 | }) 24 | 25 | it('stream all raw bytes / large fields', (done) => { 26 | const power = 16 27 | const bytea = (str) => { 28 | return `REPEAT('${str}', CAST(2^${power} AS int))::bytea` 29 | } 30 | const sql = `COPY ((SELECT ${bytea('-')}, ${bytea('-')}) UNION ALL (SELECT ${bytea('-')}, ${bytea( 31 | '-' 32 | )})) TO STDOUT BINARY` 33 | const client = getClient() 34 | const copyOutStream = client.query(copyTo(sql)) 35 | const assertResult = (buf) => { 36 | client.end() 37 | assert.deepEqual(buf, Buffer.alloc(4 * Math.pow(2, power), '-')) 38 | done() 39 | } 40 | const p = rawReader() 41 | p.on('error', (err) => { 42 | client.end() 43 | done(err) 44 | }) 45 | copyOutStream.pipe(p).pipe(concat({ encoding: 'buffer' }, assertResult)) 46 | }) 47 | }) 48 | -------------------------------------------------------------------------------- /test/decode.js: -------------------------------------------------------------------------------- 1 | 'use strict' 2 | 3 | const assert = require('assert') 4 | const util = require('util') 5 | 6 | const pgtypes = require('../lib/pg_types') 7 | const { decode } = pgtypes 8 | 9 | const samples = require('./samples') 10 | 11 | function size(ar) { 12 | const row_count = ar.length 13 | const row_sizes = [] 14 | for (let i = 0; i < row_count; i++) { 15 | row_sizes.push(ar[i].length) 16 | } 17 | return [row_count, Math.max.apply(null, row_sizes)] 18 | } 19 | 20 | function flatten(arr) { 21 | return arr.reduce((acc, val) => (Array.isArray(val) ? acc.concat(flatten(val)) : acc.concat(val)), []) 22 | } 23 | 24 | describe('decode', () => { 25 | samples.forEach(function (s) { 26 | it(`decode type ${s.t}: ${util.inspect(s.v)}`, async () => { 27 | const buf = s.r 28 | const isNull = buf.readInt32BE(0) 29 | const UInt32Len = 4 30 | let type = s.t 31 | if (isNull === -1) { 32 | assert.equal(buf.length, UInt32Len, 'A "null" binary buffer should be 0xffffffff') 33 | } else { 34 | let result = decode(buf.slice(UInt32Len), s.t) 35 | let expected = s.v 36 | 37 | let results = [result] 38 | let expecteds = [expected] 39 | 40 | if (s.t[0] === '_') { 41 | assert.equal(size(result).join(','), size(expected).join(','), 'array dimensions should match') 42 | results = flatten(result) 43 | expecteds = flatten(expected) 44 | type = s.t.substr(1) 45 | } 46 | 47 | assert.equal(results.length, expecteds.length, s.t + ': arrays should have the same global number of members') 48 | 49 | for (let i = 0; i < results.length; i++) { 50 | result = results[i] 51 | expected = expecteds[i] 52 | switch (type) { 53 | case 'bytea': 54 | result = result.toString('hex') 55 | expected = expected.toString('hex') 56 | break 57 | case 'json': 58 | case 'jsonb': 59 | result = JSON.stringify(result) 60 | expected = JSON.stringify(expected) 61 | break 62 | case 'timestamptz': 63 | result = result.getTime() 64 | expected = expected.getTime() 65 | break 66 | } 67 | assert.equal( 68 | result, 69 | expected, 70 | s.t + ': decoded value is incorrect for ' + s.t + ' expected ' + expected + ', got ' + result 71 | ) 72 | } 73 | } 74 | }) 75 | }) 76 | }) 77 | -------------------------------------------------------------------------------- /lib/rowWriter.js: -------------------------------------------------------------------------------- 1 | /** 2 | * Documentation is extracted from 3 | * [1] https://www.postgresql.org/docs/current/static/sql-copy.html for the COPY binary format 4 | * [2] https://github.com/postgres/postgres/tree/master/src/backend/utils/adt for the send/recv binary formats of types 5 | */ 6 | 7 | module.exports = function (txt, options) { 8 | return new CopyStream(txt, options) 9 | } 10 | 11 | const { Transform } = require('stream') 12 | 13 | const BufferPut = require('bufferput') 14 | const { encode } = require('./pg_types') 15 | 16 | class CopyStream extends Transform { 17 | constructor(options = {}) { 18 | options.writableObjectMode = true 19 | super(options) 20 | 21 | this._headerSent = options.COPY_sendHeader === false 22 | this._trailerSent = options.COPY_sendTrailer === false 23 | 24 | // PGCOPY\n\377\r\n\0 25 | this.COPYSignature = Buffer.from([0x50, 0x47, 0x43, 0x4f, 0x50, 0x59, 0x0a, 0xff, 0x0d, 0x0a, 0x00]) 26 | } 27 | 28 | sendHeader(buf) { 29 | buf.put(this.COPYSignature) 30 | buf.word32be(0) // flags field (OID are not included in data) 31 | buf.word32be(0) // Header extention area is empty 32 | } 33 | 34 | _transform(chunk, enc, cb) { 35 | const buf = new BufferPut() 36 | const fieldCount = chunk.length 37 | 38 | // See [1] - File Header Section 39 | if (!this._headerSent) { 40 | this._headerSent = true 41 | this.sendHeader(buf) 42 | } 43 | 44 | // See [1] - Tuples Section 45 | // Each tuple begins with a 16-bit integer count of the number of fields in the tuple. 46 | // (Presently, all tuples in a table will have the same count, but that might not always be true.) 47 | buf.word16be(fieldCount) 48 | 49 | // See [1] - Tuples Section 50 | // Then, repeated for each field in the tuple, there is a 32-bit length word followed by that many bytes of field data. 51 | // (The length word does not include itself, and can be zero.) 52 | let i 53 | let vec 54 | for (i = 0; i < fieldCount; i++) { 55 | vec = chunk[i] 56 | encode(buf, vec.type, vec.value) 57 | } 58 | 59 | this.push(buf.buffer()) 60 | 61 | cb() 62 | } 63 | 64 | _flush(cb) { 65 | const buf = new BufferPut() 66 | 67 | // See [1] - File Header Section 68 | if (!this._headerSent) { 69 | this._headerSent = true 70 | this.sendHeader(buf) 71 | } 72 | 73 | // See [1] - File Trailer section 74 | if (!this._trailerSent) { 75 | this._trailerSent = true 76 | buf.put(Buffer.from([0xff, 0xff])) 77 | } 78 | 79 | this.push(buf.buffer()) 80 | cb() 81 | } 82 | } 83 | -------------------------------------------------------------------------------- /test/rowWriter.js: -------------------------------------------------------------------------------- 1 | const assert = require('assert') 2 | const util = require('util') 3 | const { rowWriter } = require('../') 4 | const { from: copyFrom } = require('pg-copy-streams') 5 | const { getClient } = require('./utils') 6 | 7 | describe('integration test - copyIn', () => { 8 | it('ingesting an empty flow should not trigger an error', (done) => { 9 | const client = getClient() 10 | client.query('CREATE TEMP TABLE plug (col1 text)') 11 | const sql = 'COPY plug FROM STDIN BINARY' 12 | const copyIn = client.query(copyFrom(sql)) 13 | const encoder = rowWriter() 14 | encoder.pipe(copyIn) 15 | const cleanup = (err) => { 16 | done(err) 17 | client.end() 18 | } 19 | copyIn.on('finish', cleanup) 20 | copyIn.on('error', cleanup) 21 | copyIn.on('error', cleanup) 22 | encoder.end() 23 | }) 24 | 25 | const samples = [ 26 | ['bool', 0, null, null], 27 | ['bool', 0, true, 'true'], 28 | ['bool', 0, false, 'false'], 29 | ['bool', 1, [true, false], '{t,f}'], 30 | ['int2', 0, 0, '0'], 31 | ['int2', 0, 7, '7'], 32 | ['int2', 1, [2, 9], '{2,9}'], 33 | [ 34 | 'int2', 35 | 2, 36 | [ 37 | [1, 2], 38 | [3, 4], 39 | ], 40 | '{{1,2},{3,4}}', 41 | ], 42 | ['int4', 0, null, null], 43 | ['int4', 0, 7, '7'], 44 | ['int4', 1, [2, 9], '{2,9}'], 45 | [ 46 | 'int4', 47 | 2, 48 | [ 49 | [1, 2], 50 | [3, 4], 51 | ], 52 | '{{1,2},{3,4}}', 53 | ], 54 | ['int8', 0, null, null], 55 | ['int8', 0, BigInt('501007199254740991'), '501007199254740991'], 56 | [ 57 | 'int8', 58 | 1, 59 | [BigInt('501007199254740991'), BigInt('501007199254740999')], 60 | '{501007199254740991,501007199254740999}', 61 | ], 62 | [ 63 | 'int8', 64 | 2, 65 | [ 66 | [BigInt('501007199254740991'), BigInt('501007199254740999')], 67 | [BigInt('501007199254740993'), BigInt('501007199254740994')], 68 | ], 69 | '{{501007199254740991,501007199254740999},{501007199254740993,501007199254740994}}', 70 | ], 71 | ['float4', 0, 0.2736, '0.2736'], 72 | ['float4', 0, 2.928e27, '2.928e+27'], 73 | ['float8', 0, 7.23e50, '7.23e+50'], 74 | ['json', 0, { a: 1, b: 2 }, '{"a":1,"b":2}'], 75 | ['json', 1, [{ a: 1 }, {}], '{"{\\"a\\":1}","{}"}'], 76 | ['jsonb', 0, { a: 1, b: 2 }, '{"a": 1, "b": 2}'], 77 | ['jsonb', 1, [{ a: 1 }, {}], '{"{\\"a\\": 1}","{}"}'], 78 | ['timestamptz', 0, new Date('2017-04-25T18:22:00Z'), '2017-04-25 18:22:00+00'], 79 | ] 80 | 81 | samples.forEach(function (s) { 82 | const [type, ndim, value, expectedText] = s 83 | it(`test type ${type}: ${util.inspect(value)}`, (done) => { 84 | const client = getClient() 85 | const atype = (ndim > 0 ? '_' : '') + type 86 | const coltype = type + '[]'.repeat(ndim) 87 | client.query('CREATE TEMP TABLE plug (col1 ' + coltype + ')') 88 | const sql = 'COPY plug FROM STDIN BINARY' 89 | const copyIn = client.query(copyFrom(sql)) 90 | const encoder = rowWriter() 91 | encoder.pipe(copyIn) 92 | copyIn.on('finish', () => { 93 | const sql = 'SELECT col1::text FROM plug' 94 | client.query(sql, function (err, res) { 95 | client.end() 96 | if (err) return done(err) 97 | try { 98 | assert.equal( 99 | res.rows[0].col1, 100 | expectedText, 101 | 'expected ' + 102 | expectedText + 103 | ' for ' + 104 | coltype + 105 | ' row but got ' + 106 | (res.rows.length ? res.rows[0].col1 : '0 rows') 107 | ) 108 | } catch (err) { 109 | return done(err) 110 | } 111 | done() 112 | }) 113 | }) 114 | encoder.end([{ type: atype, value: value }]) 115 | }) 116 | }) 117 | }) 118 | -------------------------------------------------------------------------------- /test/rowReader.js: -------------------------------------------------------------------------------- 1 | const assert = require('assert') 2 | const { rowReader } = require('../') 3 | const { to: copyTo } = require('pg-copy-streams') 4 | const through2 = require('through2') 5 | const concat = require('concat-stream') 6 | const { getClient } = require('./utils') 7 | 8 | const samples = { 9 | bool: [null, true, false], 10 | bytea: [Buffer.from([0x61]), null, Buffer.from([0x62])], 11 | int2: [23, -59, null], 12 | int4: [2938, null, -99283], 13 | int8: [BigInt(2938), null, BigInt(-99283)], 14 | text: ['aaa', 'ééé', null], 15 | json: [JSON.stringify({}), JSON.stringify([1, 2]), null], 16 | jsonb: [JSON.stringify({}), JSON.stringify({ a: true, b: [4, 2] }), null], 17 | float4: [0.26350000500679016, null, -3.2929999872755022e-12], 18 | float8: [9000.12, 9.23e29, null], 19 | timestamptz: [new Date('2000-01-01T00:00:00Z'), null, new Date('1972-04-25T18:22:00Z')], 20 | } 21 | 22 | describe('integration test - rowReader', () => { 23 | it('test INSERT / COPY TO round trip', (done) => { 24 | const client = getClient() 25 | let idx = 1 26 | const fields = [] 27 | const placeholders = [] 28 | const mapping = [] 29 | const rows = [] 30 | for (const t in samples) { 31 | fields.push('c' + idx + ' ' + t) 32 | placeholders.push('$' + idx) 33 | mapping.push({ key: 'c' + idx, type: t }) 34 | for (let c = 0; c < samples[t].length; c++) { 35 | rows[c] = rows[c] || [] 36 | rows[c].push(samples[t][c]) 37 | } 38 | idx++ 39 | } 40 | client.query('CREATE TEMP TABLE plug (' + fields.join(',') + ')') 41 | for (let i = 0; i < rows.length; i++) { 42 | client.query('INSERT INTO plug VALUES (' + placeholders.join(',') + ')', rows[i]) 43 | } 44 | 45 | const sql = 'COPY plug TO STDOUT BINARY' 46 | const copyOut = client.query(copyTo(sql)) 47 | const p = rowReader({ mapping: mapping }) 48 | 49 | idx = 0 50 | const pipeline = copyOut.pipe(p).pipe( 51 | through2.obj( 52 | function (obj, _, cb) { 53 | for (let i = 0; i < mapping.length; i++) { 54 | let expected = samples[mapping[i].type][idx] 55 | let result = obj[mapping[i].key] 56 | if (expected !== null && result !== null) { 57 | switch (mapping[i].type) { 58 | case 'bytea': 59 | expected = expected.toString() 60 | result = result.toString() 61 | break 62 | case 'json': 63 | case 'jsonb': 64 | result = JSON.stringify(result) 65 | break 66 | case 'timestamptz': 67 | expected = expected.getTime() 68 | result = result.getTime() 69 | break 70 | } 71 | } 72 | try { 73 | assert.equal( 74 | expected, 75 | result, 76 | 'Mismatch for ' + mapping[i].type + ' expected ' + expected + ' got ' + result 77 | ) 78 | } catch (err) { 79 | return cb(err) 80 | } 81 | } 82 | idx++ 83 | cb() 84 | }, 85 | function (cb) { 86 | client.end() 87 | try { 88 | assert.equal(rows.length, idx, `Received a total of ${idx} rows when we were expecting ${rows.length}`) 89 | } catch (err) { 90 | return cb(err) 91 | } 92 | done() 93 | cb() 94 | } 95 | ) 96 | ) 97 | pipeline.on('error', (err) => { 98 | client.end() 99 | done(err) 100 | }) 101 | }) 102 | 103 | it('extract large bytea field', (done) => { 104 | const power = 16 105 | const sql = "COPY (select (repeat('-', CAST(2^" + power + ' AS int)))::bytea) TO STDOUT BINARY' 106 | const client = getClient() 107 | const copyOutStream = client.query(copyTo(sql)) 108 | const assertResult = (arr) => { 109 | client.end() 110 | assert.deepEqual(arr[0].c1, Buffer.alloc(Math.pow(2, power), '-')) 111 | done() 112 | } 113 | const p = rowReader({ mapping: [{ key: 'c1', type: 'bytea' }] }) 114 | p.on('error', (err) => { 115 | client.end() 116 | done(err) 117 | }) 118 | 119 | copyOutStream.pipe(p).pipe(concat({ encoding: 'object' }, assertResult)) 120 | }) 121 | }) 122 | -------------------------------------------------------------------------------- /test/transform.js: -------------------------------------------------------------------------------- 1 | const assert = require('assert') 2 | const async = require('async') 3 | 4 | const { to: pgCopyTo, from: pgCopyFrom } = require('pg-copy-streams') 5 | const through2 = require('through2') 6 | 7 | const { getClient } = require('./utils') 8 | const { transform } = require('../') 9 | 10 | describe('integration test - transform', () => { 11 | it('should correclty extract, transform and load data', (done) => { 12 | const clientA = getClient() 13 | const clientB = getClient() 14 | const clientC = getClient() 15 | 16 | const queriesA = [ 17 | 'DROP TABLE IF EXISTS item', 18 | 'CREATE TABLE item (id serial PRIMARY KEY, ref text, description text)', 19 | "INSERT INTO item (ref, description) VALUES ('1:CTX', 'A little item')", 20 | "INSERT INTO item (ref, description) VALUES ('2:CTX', 'A BIG item')", 21 | ] 22 | 23 | const queriesB = [ 24 | 'DROP TABLE IF EXISTS product', 25 | 'CREATE TABLE product (code int4 PRIMARY KEY, label text, description text, ts_creation timestamptz, matrix int2[][])', 26 | ] 27 | 28 | const queriesC = ['DROP TABLE IF EXISTS generated', 'CREATE TABLE generated (body text)'] 29 | 30 | // we simplify by observing here that A=B when tests are executed 31 | async.eachSeries(queriesA.concat(queriesB, queriesC), clientA.query.bind(clientA), function (err) { 32 | if (err) return done(err) 33 | 34 | const copyOut = clientA.query(pgCopyTo('COPY item TO STDOUT BINARY')) 35 | const copyIns = [ 36 | clientB.query(pgCopyFrom('COPY product FROM STDIN BINARY')), 37 | clientC.query(pgCopyFrom('COPY generated FROM STDIN BINARY')), 38 | ] 39 | 40 | let count = 0 41 | const pct = transform({ 42 | mapping: [ 43 | { key: 'id', type: 'int4' }, 44 | { key: 'ref', type: 'text' }, 45 | { key: 'description', type: 'text' }, 46 | ], 47 | targets: copyIns, 48 | transform: through2.obj( 49 | function (row, _, cb) { 50 | let id = parseInt(row.ref.split(':')[0]) 51 | const d = new Date('1999-01-01T00:00:00Z') 52 | d.setDate(d.getDate() + id) 53 | count++ 54 | this.push([ 55 | 0, 56 | { type: 'int4', value: id }, 57 | { type: 'text', value: row.ref.split(':')[1] }, 58 | { type: 'text', value: row.description.toLowerCase() }, 59 | { type: 'timestamptz', value: d }, 60 | { 61 | type: '_int2', 62 | value: [ 63 | [id, id + 1], 64 | [id + 2, id + 3], 65 | ], 66 | }, 67 | ]) 68 | while (id > 0) { 69 | count++ 70 | this.push([1, { type: 'text', value: 'BODY: ' + row.description }]) 71 | id-- 72 | } 73 | cb() 74 | }, 75 | function (cb) { 76 | this.push([1, { type: 'text', value: 'COUNT: ' + count }]) 77 | cb() 78 | } 79 | ), 80 | }) 81 | 82 | copyOut.pipe(pct) 83 | pct.on('close', function (err) { 84 | if (err) return done(err) 85 | let running = 3 86 | clientA.query('SELECT * FROM item', function (err, res) { 87 | clientA.end() 88 | if (err) return done(err) 89 | try { 90 | assert.equal(res.rowCount, 2, 'expected 2 tuples on A, but got ' + res.rowCount) 91 | } catch (err) { 92 | return done(err) 93 | } 94 | running-- 95 | if (!running) done() 96 | }) 97 | clientB.query('SELECT * FROM product ORDER BY code ASC', function (err, res) { 98 | clientB.end() 99 | if (err) return done(err) 100 | try { 101 | const d = new Date('1999-01-01T00:00:00Z') 102 | assert.equal(res.rowCount, 2, 'expected 2 tuples on B, but got ' + res.rowCount) 103 | 104 | // first row 105 | assert.equal(res.rows[0].code, 1) 106 | assert.equal(res.rows[0].label, 'CTX') 107 | assert.equal(res.rows[0].description, 'a little item') 108 | assert.equal(res.rows[0].ts_creation.getTime(), d.getTime() + 1 * 24 * 60 * 60 * 1000) 109 | assert.equal(JSON.stringify(res.rows[0].matrix), '[[1,2],[3,4]]') 110 | 111 | // second row 112 | assert.equal(res.rows[1].code, 2) 113 | assert.equal(res.rows[1].label, 'CTX') 114 | assert.equal(res.rows[1].description, 'a big item') 115 | assert.equal(JSON.stringify(res.rows[1].matrix), '[[2,3],[4,5]]') 116 | } catch (err) { 117 | return done(err) 118 | } 119 | running-- 120 | if (!running) done() 121 | }) 122 | 123 | clientC.query('SELECT * FROM generated ORDER BY body ASC', function (err, res) { 124 | clientC.end() 125 | if (err) return done(err) 126 | try { 127 | assert.equal(res.rows[0].body, 'BODY: A BIG item') 128 | assert.equal(res.rows[1].body, 'BODY: A BIG item') 129 | assert.equal(res.rows[2].body, 'BODY: A little item') 130 | assert.equal(res.rows[3].body, 'COUNT: 5') 131 | } catch (err) { 132 | return done(err) 133 | } 134 | running-- 135 | if (!running) done() 136 | }) 137 | }) 138 | }) 139 | }) 140 | }) 141 | -------------------------------------------------------------------------------- /test/fieldReader.js: -------------------------------------------------------------------------------- 1 | const assert = require('assert') 2 | const { fieldReader } = require('../') 3 | const { to: copyTo } = require('pg-copy-streams') 4 | const through2 = require('through2') 5 | const concat = require('concat-stream') 6 | const { getClient } = require('./utils') 7 | 8 | const samples = { 9 | bool: [null, true, false], 10 | int2: [23, -59, null], 11 | int4: [2938, null, -99283], 12 | int8: [BigInt(2938), null, BigInt(-99283)], 13 | text: ['aaa', 'ééé', null], 14 | json: [JSON.stringify({}), JSON.stringify([1, 2]), null], 15 | jsonb: [JSON.stringify({}), JSON.stringify([1, 2]), null], 16 | float4: [0.26350000500679016, null, -3.2929999872755022e-12], 17 | float8: [9000.12, 9.23e29, null], 18 | timestamptz: [new Date('2000-01-01T00:00:00Z'), null, new Date('1972-04-25T18:22:00Z')], 19 | } 20 | 21 | describe('integration test - fieldReader', () => { 22 | it('test INSERT / COPY TO round trip', (done) => { 23 | const client = getClient() 24 | let idx = 1 25 | const fields = [] 26 | const placeholders = [] 27 | const mapping = [] 28 | const rows = [] 29 | for (const t in samples) { 30 | fields.push('c' + idx + ' ' + t) 31 | placeholders.push('$' + idx) 32 | mapping.push({ key: 'c' + idx, type: t }) 33 | for (let c = 0; c < samples[t].length; c++) { 34 | rows[c] = rows[c] || [] 35 | rows[c].push(samples[t][c]) 36 | } 37 | idx++ 38 | } 39 | client.query('CREATE TEMP TABLE plug (' + fields.join(',') + ')') 40 | for (let i = 0; i < rows.length; i++) { 41 | client.query('INSERT INTO plug VALUES (' + placeholders.join(',') + ')', rows[i]) 42 | } 43 | 44 | const sql = 'COPY plug TO STDOUT BINARY' 45 | const copyOut = client.query(copyTo(sql)) 46 | const p = fieldReader({ mapping: mapping }) 47 | 48 | idx = 0 49 | const pipeline = copyOut.pipe(p).pipe( 50 | through2.obj( 51 | function (obj, _, cb) { 52 | let expected = samples[mapping[obj._fieldIndex].type][idx] 53 | let result = obj.value 54 | if (expected !== null && result !== null) { 55 | switch (mapping[obj._fieldIndex].type) { 56 | case 'bytea': 57 | expected = expected.toString() 58 | result = result.toString() 59 | break 60 | case 'json': 61 | case 'jsonb': 62 | result = JSON.stringify(result) 63 | break 64 | case 'timestamptz': 65 | expected = expected.getTime() 66 | result = result.getTime() 67 | break 68 | } 69 | } 70 | try { 71 | assert.equal( 72 | expected, 73 | result, 74 | 'Mismatch for ' + mapping[obj._fieldIndex].type + ' expected ' + expected + ' got ' + result 75 | ) 76 | } catch (err) { 77 | return cb(err) 78 | } 79 | if (obj._fieldIndex === obj._fieldCount - 1) idx++ 80 | cb() 81 | }, 82 | function (cb) { 83 | client.end() 84 | try { 85 | assert.equal(rows.length, idx, `Received a total of ${idx} rows when we were expecting ${rows.length}`) 86 | } catch (err) { 87 | return cb(err) 88 | } 89 | done() 90 | cb() 91 | } 92 | ) 93 | ) 94 | pipeline.on('error', (err) => { 95 | client.end() 96 | done(err) 97 | }) 98 | }) 99 | 100 | it('extract large text field (not streaming)', (done) => { 101 | const power = 16 102 | const sql = "COPY (select (repeat('-', CAST(2^" + power + ' AS int)))) TO STDOUT BINARY' 103 | const client = getClient() 104 | const copyOutStream = client.query(copyTo(sql)) 105 | const assertResult = (arr) => { 106 | client.end() 107 | assert.deepEqual(arr[0].value, Buffer.alloc(Math.pow(2, power), '-').toString()) 108 | done() 109 | } 110 | const p = fieldReader({ mapping: [{ key: 'c1', type: 'text' }] }) 111 | p.on('error', (err) => { 112 | client.end() 113 | done(err) 114 | }) 115 | 116 | copyOutStream.pipe(p).pipe(concat({ encoding: 'object' }, assertResult)) 117 | }) 118 | 119 | it('extract large bytea field (streaming)', (done) => { 120 | const power = 16 121 | const howManyStreams = 25 122 | const sql = `COPY (select 42, 101, (repeat('-', CAST(2^${power} AS int)))::bytea from generate_series(1,${howManyStreams})) TO STDOUT BINARY` 123 | const client = getClient() 124 | const copyOutStream = client.query(copyTo(sql)) 125 | let countStream = 0 126 | const assertStreamResult = (expected) => { 127 | return (buf) => { 128 | assert.deepEqual(buf, expected) 129 | countStream++ 130 | } 131 | } 132 | const p = fieldReader({ 133 | mapping: [ 134 | { key: 'c1', type: 'int4', mode: 'async' }, 135 | { key: 'c2', type: 'int4', mode: 'sync' }, 136 | { key: 'c3', type: 'text', mode: 'async' }, 137 | ], 138 | }) 139 | p.on('error', (err) => { 140 | client.end() 141 | done(err) 142 | }) 143 | 144 | copyOutStream 145 | .pipe(p) 146 | .pipe( 147 | through2.obj(function (obj, _, cb) { 148 | obj.name === 'c1' && obj.value.pipe(concat(assertStreamResult(Buffer.from([0, 0, 0, 42])))) 149 | obj.name === 'c2' && assert.equal(obj.value, 101) 150 | obj.name === 'c3' && obj.value.pipe(concat(assertStreamResult(Buffer.alloc(Math.pow(2, power), '-')))) 151 | cb() 152 | }) 153 | ) 154 | .pipe( 155 | concat((res) => { 156 | assert.equal(countStream, 2 * howManyStreams) 157 | client.end() 158 | done() 159 | }) 160 | ) 161 | }) 162 | }) 163 | -------------------------------------------------------------------------------- /lib/genericReader.js: -------------------------------------------------------------------------------- 1 | /** 2 | * Documentation is extracted from 3 | * [1] https://www.postgresql.org/docs/current/static/sql-copy.html for the COPY binary format 4 | * [2] https://github.com/postgres/postgres/tree/master/src/backend/utils/adt for the send/recv binary formats of types 5 | */ 6 | 7 | const { Transform, Readable } = require('stream') 8 | const BP = require('bufferput') 9 | const { decode } = require('./pg_types') 10 | const BufferList = require('bl/BufferList') 11 | 12 | const PG_HEADER = 0 13 | const PG_ROW_START = 1 14 | const PG_FIELD_START = 2 15 | const PG_FIELD_DATA = 3 16 | const PG_FIELD_END = 4 17 | const PG_TRAILER = 5 18 | 19 | class CopyStream extends Transform { 20 | constructor(options) { 21 | super(options) 22 | 23 | // PGCOPY\n\377\r\n\0 (signature + flags field + Header extension area length) 24 | this.COPYHeaderFull = new BP() 25 | .put(Buffer.from([0x50, 0x47, 0x43, 0x4f, 0x50, 0x59, 0x0a, 0xff, 0x0d, 0x0a, 0x00])) 26 | .word32be(0) 27 | .word32be(0) 28 | .buffer() 29 | 30 | this._buffer = new BufferList() 31 | this._state = PG_HEADER 32 | this._fieldCount = null 33 | this._fieldIndex = null 34 | this._fieldLength = null 35 | this._fieldLengthMissing = null 36 | this._fieldHolder = null 37 | this._flowing = true 38 | } 39 | 40 | _transform(chunk, enc, cb) { 41 | let done = false 42 | if (chunk) this._buffer.append(chunk) 43 | while (this._buffer.length > 0) { 44 | if (PG_HEADER === this._state) { 45 | if (this._buffer.length < this.COPYHeaderFull.length) break 46 | if (!this.COPYHeaderFull.equals(this._buffer.slice(0, this.COPYHeaderFull.length))) { 47 | return cb(new Error('COPY BINARY Header mismatch')) 48 | } 49 | this._buffer.consume(this.COPYHeaderFull.length) 50 | this._state = PG_ROW_START 51 | } 52 | 53 | if (PG_ROW_START === this._state) { 54 | if (this._buffer.length < 2) break 55 | this._fieldCount = this._buffer.readUInt16BE(0) 56 | this._buffer.consume(2) 57 | const UInt16_0xffff = 65535 58 | if (this._fieldCount === UInt16_0xffff) { 59 | this._state = PG_TRAILER 60 | } else { 61 | this.rowStart() 62 | this._state = PG_FIELD_START 63 | this._fieldIndex = -1 64 | } 65 | } 66 | 67 | if (PG_TRAILER === this._state) { 68 | done = true 69 | break 70 | } 71 | 72 | if (PG_FIELD_START === this._state) { 73 | if (this._buffer.length < 4) break 74 | this._fieldIndex++ 75 | this._fieldLength = this._buffer.readUInt32BE(0) 76 | this._buffer.consume(4) 77 | const UInt32_0xffffffff = 4294967295 /* Magic value for NULL */ 78 | if (this._fieldLength === UInt32_0xffffffff) { 79 | this._fieldHolder = null 80 | this._fieldLength = 0 81 | this._state = PG_FIELD_END 82 | } else { 83 | this.setupFieldHolder() 84 | this._state = PG_FIELD_DATA 85 | } 86 | this._fieldLengthMissing = this._fieldLength 87 | } 88 | 89 | if (PG_FIELD_DATA === this._state) { 90 | if (this._buffer.length === 0) break 91 | 92 | if (this._flowing) { 93 | const bl = this._buffer.shallowSlice(0, this._fieldLengthMissing) 94 | this._fieldLengthMissing -= bl.length 95 | this._buffer.consume(bl.length) 96 | this.captureFieldData(bl) 97 | } 98 | 99 | if (this._fieldLengthMissing === 0) { 100 | this._state = PG_FIELD_END 101 | } else if (!this._flowing) { 102 | this.defer_cb = cb 103 | break 104 | } 105 | } 106 | 107 | if (PG_FIELD_END === this._state) { 108 | this.releaseFieldHolder() 109 | this._flowing = true 110 | this._state = PG_FIELD_START 111 | if (this._fieldIndex === this._fieldCount - 1) { 112 | this._state = PG_ROW_START 113 | } 114 | } 115 | } 116 | 117 | this.endOfChunk() 118 | 119 | if (done) { 120 | this.push(null) 121 | this._fieldHolder = null 122 | return cb() 123 | } 124 | 125 | if (!this.defer_cb) cb() 126 | } 127 | 128 | setupFieldHolder() { 129 | switch (this.fieldMode()) { 130 | case 'async': 131 | const self = this 132 | this._fieldHolder = new Readable({ 133 | read(size) { 134 | self._flowing = true 135 | const cb = self.defer_cb 136 | self.defer_cb = null 137 | if (cb) { 138 | self._transform(null, null, cb) 139 | } 140 | }, 141 | }) 142 | this._flowing = false 143 | this.fieldReady() 144 | break 145 | case 'sync': 146 | default: 147 | this._fieldHolder = new BufferList() 148 | break 149 | } 150 | } 151 | 152 | captureFieldData(bl) { 153 | switch (this.fieldMode()) { 154 | case 'async': 155 | this._flowing = this._fieldHolder.push(bl.slice()) 156 | break 157 | case 'sync': 158 | default: 159 | this._fieldHolder.append(bl) 160 | break 161 | } 162 | } 163 | 164 | releaseFieldHolder() { 165 | switch (this.fieldMode()) { 166 | case 'async': 167 | this._fieldHolder.push(null) 168 | this._defer_cb = null 169 | this._fieldHolder = null 170 | break 171 | case 'sync': 172 | default: 173 | const type = this.fieldType() 174 | if (type && this._fieldHolder) { 175 | this._fieldHolder = decode(this._fieldHolder.slice(), type) 176 | } 177 | this.fieldReady() 178 | this._fieldHolder = null 179 | break 180 | } 181 | } 182 | 183 | fieldMode() { 184 | // when implemented, should return the sync/async mode of the current field 185 | } 186 | 187 | fieldReady() { 188 | // called when a field is ready to be pushed downstream 189 | // sync: after the field has been fully captured 190 | // async: as soon as the capturing stream has been prepared 191 | } 192 | 193 | rowStart() { 194 | // called when a new row has been detected 195 | } 196 | 197 | endOfChunk() { 198 | // called after the maximum parsing that we could do on a chunk 199 | } 200 | 201 | _flush(cb) { 202 | cb() 203 | } 204 | } 205 | 206 | module.exports = CopyStream 207 | -------------------------------------------------------------------------------- /lib/pg_types.js: -------------------------------------------------------------------------------- 1 | const ieee754 = require('ieee754') 2 | const int64 = require('int64-buffer') 3 | 4 | // bool 5 | const boolsend = function (buf, value) { 6 | buf.word8be(value ? 1 : 0) 7 | } 8 | const boolrecv = function (buf) { 9 | return buf.readUInt8(0) ? true : false 10 | } 11 | 12 | // bytea 13 | const byteasend = function (buf, value) { 14 | buf.put(value) 15 | } 16 | const bytearecv = function (buf) { 17 | return buf 18 | } 19 | 20 | // int2 21 | const int2send = function (buf, value) { 22 | buf.word16be(value) 23 | } 24 | const int2recv = function (buf) { 25 | return buf.readInt16BE(0) 26 | } 27 | 28 | // int4 29 | const int4send = function (buf, value) { 30 | buf.word32be(value) 31 | } 32 | const int4recv = function (buf) { 33 | return buf.readInt32BE(0) 34 | } 35 | 36 | // int8 37 | const int8send = function (buf, value) { 38 | const tbuf = Buffer.allocUnsafe(8) 39 | tbuf.writeBigInt64BE(value) 40 | buf.put(tbuf) 41 | } 42 | const int8recv = function (buf) { 43 | return buf.readBigInt64BE(0) 44 | } 45 | 46 | // text 47 | const textsend = function (buf, value) { 48 | const tbuf = Buffer.from(value, 'utf-8') 49 | buf.put(tbuf) 50 | } 51 | const textrecv = function (buf) { 52 | return buf.toString('utf-8') 53 | } 54 | 55 | // varchar 56 | const varcharsend = textsend 57 | const varcharrecv = textrecv 58 | 59 | // json 60 | const json_send = function (buf, value) { 61 | const jbuf = Buffer.from(JSON.stringify(value), 'utf-8') 62 | buf.put(jbuf) 63 | } 64 | const json_recv = function (buf) { 65 | return JSON.parse(buf.toString('utf-8')) 66 | } 67 | 68 | // jsonb 69 | const jsonb_send = function (buf, value) { 70 | const jbuf = Buffer.from('\u0001' + JSON.stringify(value), 'utf-8') 71 | buf.put(jbuf) 72 | } 73 | const jsonb_recv = function (buf) { 74 | return JSON.parse(buf.slice(1).toString('utf-8')) 75 | } 76 | 77 | // float4 78 | const float4send = function (buf, value) { 79 | const fbuf = Buffer.alloc(4) 80 | ieee754.write(fbuf, value, 0, false, 23, 4) 81 | buf.put(fbuf) 82 | } 83 | const float4recv = function (buf) { 84 | return ieee754.read(buf, 0, false, 23, 4) 85 | } 86 | 87 | // float8 88 | const float8send = function (buf, value) { 89 | const fbuf = Buffer.alloc(8) 90 | ieee754.write(fbuf, value, 0, false, 52, 8) 91 | buf.put(fbuf) 92 | } 93 | const float8recv = function (buf) { 94 | return ieee754.read(buf, 0, false, 52, 8) 95 | } 96 | 97 | // timestamptz 98 | // NB: This is only for the HAVE_INT64_TIMESTAMP case 99 | // in PostgreSQL source code so there may be some work needed 100 | // to interact with other architures 101 | const timestamptz_send = function (buf, value) { 102 | // postgres origin of time is 01/01/2000 103 | let ts = value.getTime() - 946684800000 104 | ts = 1000 * ts // add unknown usecs 105 | const tbuf = Buffer.alloc(8) 106 | int64.Int64BE(tbuf, 0, ts) 107 | buf.put(tbuf) 108 | } 109 | const timestamptz_recv = function (buf) { 110 | let ts = int64.Int64BE(buf) 111 | ts = ts / 1000 112 | ts = ts + 946684800000 113 | return new Date(ts) 114 | } 115 | 116 | // array 117 | const array_send = function (atype, buf, value) { 118 | let tmp 119 | let ndim = 0 120 | 121 | // count # of dimensions 122 | tmp = value 123 | while (Array.isArray(tmp)) { 124 | ndim++ 125 | tmp = tmp[0] 126 | } 127 | buf.word32be(ndim) // ndim 128 | buf.word32be(0) // hasnull 129 | buf.word32be(types[atype].oid) // elem oid 130 | 131 | // for each dimension, declare 132 | // - size of dimension 133 | // - index of first item in dimension (1) 134 | tmp = value 135 | for (let i = 0; i < ndim; i++) { 136 | buf.word32be(tmp.length) 137 | buf.word32be(1) 138 | tmp = tmp[0] 139 | } 140 | 141 | // elems are flattened on 1-dim 142 | const flat = flatten(value) 143 | const len = flat.length 144 | for (let i = 0; i < len; i++) { 145 | encode(buf, atype, flat[i]) 146 | } 147 | } 148 | // note the type is not necessary here because it is embedded inside the 149 | // array 150 | const array_recv = function (buf) { 151 | let offset = 0 152 | const UInt32Len = 4 153 | const ndim = buf.readUInt32BE(offset) 154 | offset += UInt32Len 155 | // eslint-disable-next-line no-unused-vars 156 | const hasnull = buf.readUInt32BE(offset) 157 | offset += UInt32Len 158 | const typoid = buf.readUInt32BE(offset) 159 | offset += UInt32Len 160 | let type 161 | // eslint-disable-next-line no-unused-vars 162 | let found = false 163 | for (type in types) { 164 | if (types[type].oid === typoid) { 165 | // eslint-disable-next-line no-unused-vars 166 | found = true 167 | break 168 | } 169 | } 170 | // description of dimensions 171 | const dims = [] 172 | const lowers = [] 173 | let len = 1 174 | for (let i = 0; i < ndim; i++) { 175 | const n = buf.readUInt32BE(offset) 176 | len = len * n 177 | dims.push(n) 178 | offset += UInt32Len 179 | lowers.push(buf.readUInt32BE(offset)) 180 | offset += UInt32Len 181 | } 182 | // fetch flattenned data 183 | let flat = [] 184 | for (let i = 0; i < len; i++) { 185 | const fieldLen = buf.readUInt32BE(offset) 186 | offset += UInt32Len 187 | flat.push(decode(buf.slice(offset, offset + fieldLen), type)) 188 | offset += fieldLen 189 | } 190 | let size 191 | dims.shift() 192 | while ((size = dims.pop())) { 193 | flat = chunk(flat, size) 194 | } 195 | return flat 196 | } 197 | 198 | function chunk(array, size) { 199 | const result = [] 200 | for (let i = 0; i < array.length; i += size) result.push(array.slice(i, i + size)) 201 | return result 202 | } 203 | 204 | // Note that send function names are kept identical to their names in the PostgreSQL source code. 205 | const types = { 206 | bool: { oid: 16, send: boolsend, recv: boolrecv }, 207 | bytea: { oid: 17, send: byteasend, recv: bytearecv }, 208 | int2: { oid: 21, send: int2send, recv: int2recv }, 209 | int4: { oid: 23, send: int4send, recv: int4recv }, 210 | int8: { oid: 20, send: int8send, recv: int8recv }, 211 | text: { oid: 25, send: textsend, recv: textrecv }, 212 | varchar: { oid: 1043, send: varcharsend, recv: varcharrecv }, 213 | json: { oid: 114, send: json_send, recv: json_recv }, 214 | jsonb: { oid: 3802, send: jsonb_send, recv: jsonb_recv }, 215 | float4: { oid: 700, send: float4send, recv: float4recv }, 216 | float8: { oid: 701, send: float8send, recv: float8recv }, 217 | timestamptz: { oid: 1184, send: timestamptz_send, recv: timestamptz_recv }, 218 | _bool: { oid: 1000, send: array_send.bind(null, 'bool'), recv: array_recv }, 219 | _bytea: { oid: 1001, send: array_send.bind(null, 'bytea'), recv: array_recv }, 220 | _int2: { oid: 1005, send: array_send.bind(null, 'int2'), recv: array_recv }, 221 | _int4: { oid: 1007, send: array_send.bind(null, 'int4'), recv: array_recv }, 222 | _int8: { oid: 1016, send: array_send.bind(null, 'int8'), recv: array_recv }, 223 | _text: { oid: 1009, send: array_send.bind(null, 'text'), recv: array_recv }, 224 | _varchar: { oid: 1015, send: array_send.bind(null, 'varchar'), recv: array_recv }, 225 | _json: { oid: 199, send: array_send.bind(null, 'json'), recv: array_recv }, 226 | _jsonb: { oid: 3807, send: array_send.bind(null, 'jsonb'), recv: array_recv }, 227 | _float4: { oid: 1021, send: array_send.bind(null, 'float4'), recv: array_recv }, 228 | _float8: { oid: 1022, send: array_send.bind(null, 'float8'), recv: array_recv }, 229 | _timestamptz: { oid: 1185, send: array_send.bind(null, 'timestamptz'), recv: array_recv }, 230 | } 231 | 232 | function encode(buf, type, value) { 233 | // Add a UInt32 placeholder for the field length 234 | buf.word32be(0) 235 | const lenField = buf.words[buf.words.length - 1] 236 | 237 | // See [1] - Tuples Section 238 | // As a special case, -1 indicates a NULL field value. No value bytes follow in the NULL case 239 | if (value === null) { 240 | lenField.value = -1 241 | 242 | // Then, repeated for each field in the tuple, there is a 32-bit length word followed by 243 | // that many bytes of field data. 244 | } else if (types[type]) { 245 | const offset = buf.len 246 | types[type].send(buf, value) 247 | lenField.value = buf.len - offset 248 | } 249 | return buf 250 | } 251 | 252 | function decode(buf, type) { 253 | return types[type].recv(buf) 254 | } 255 | 256 | function flatten(arr) { 257 | return arr.reduce((acc, val) => (Array.isArray(val) ? acc.concat(flatten(val)) : acc.concat(val)), []) 258 | } 259 | 260 | module.exports = { 261 | types: types, 262 | encode: encode, 263 | decode: decode, 264 | } 265 | -------------------------------------------------------------------------------- /test/samples.js: -------------------------------------------------------------------------------- 1 | const pgtypes = require('../lib/pg_types') 2 | const { types } = pgtypes 3 | const BP = require('bufferput') 4 | 5 | BP.prototype.string = function (s, enc) { 6 | const buf = Buffer.from(s, enc) 7 | return this.put(buf) 8 | } 9 | 10 | function makeBigIntBuffer(value) { 11 | const buf = Buffer.alloc(8) 12 | buf.writeBigInt64BE(BigInt(value)) 13 | return buf 14 | } 15 | 16 | module.exports = [ 17 | // simple types 18 | { t: 'bool', v: null, r: new BP().word32be(-1).buffer() }, 19 | { t: 'bool', v: true, r: new BP().word32be(1).word8(1).buffer() }, 20 | { t: 'bool', v: false, r: new BP().word32be(1).word8(0).buffer() }, 21 | { t: 'bytea', v: null, r: new BP().word32be(-1).buffer() }, 22 | { 23 | t: 'bytea', 24 | v: Buffer.from([0x33, 0x22, 0x11, 0x00]), 25 | r: new BP() 26 | .word32be(4) 27 | .put(Buffer.from([0x33, 0x22, 0x11, 0x00])) 28 | .buffer(), 29 | }, 30 | { t: 'int2', v: null, r: new BP().word32be(-1).buffer() }, 31 | { t: 'int2', v: 128, r: new BP().word32be(2).word16be(128).buffer() }, 32 | { t: 'int4', v: null, r: new BP().word32be(-1).buffer() }, 33 | { t: 'int4', v: 128, r: new BP().word32be(4).word32be(128).buffer() }, 34 | { t: 'int8', v: null, r: new BP().word32be(-1).buffer() }, 35 | { 36 | t: 'int8', 37 | v: BigInt('128'), 38 | r: new BP().word32be(8).put(makeBigIntBuffer('128')).buffer(), 39 | }, 40 | { t: 'text', v: null, r: new BP().word32be(-1).buffer() }, 41 | { t: 'text', v: 'hello', r: new BP().word32be(5).put(Buffer.from('hello')).buffer() }, 42 | { t: 'text', v: 'utf8 éà', r: new BP().word32be(9).put(Buffer.from('utf8 éà', 'utf-8')).buffer() }, 43 | { t: 'varchar', v: null, r: new BP().word32be(-1).buffer() }, 44 | { t: 'varchar', v: 'hello', r: new BP().word32be(5).put(Buffer.from('hello')).buffer() }, 45 | { t: 'varchar', v: 'utf8 éà', r: new BP().word32be(9).put(Buffer.from('utf8 éà', 'utf-8')).buffer() }, 46 | { t: 'json', v: null, r: new BP().word32be(-1).buffer() }, 47 | { t: 'json', v: { a: true, b: [1, 7] }, r: new BP().word32be(20).string('{"a":true,"b":[1,7]}', 'utf-8').buffer() }, 48 | { t: 'jsonb', v: null, r: new BP().word32be(-1).buffer() }, 49 | { 50 | t: 'jsonb', 51 | v: { a: true, b: [1, 7] }, 52 | r: new BP().word32be(21).string('\u0001{"a":true,"b":[1,7]}', 'utf-8').buffer(), 53 | }, 54 | // online float4+float8 hex converter, http://gregstoll.dyndns.org/~gregstoll/floattohex/ 55 | { t: 'float4', v: null, r: new BP().word32be(-1).buffer() }, 56 | { 57 | t: 'float4', 58 | v: 0.12300000339746475, 59 | r: new BP() 60 | .word32be(4) 61 | .put(Buffer.from([0x3d, 0xfb, 0xe7, 0x6d])) 62 | .buffer(), 63 | }, 64 | { t: 'float8', v: null, r: new BP().word32be(-1).buffer() }, 65 | { 66 | t: 'float8', 67 | v: 42.4242, 68 | r: new BP() 69 | .word32be(8) 70 | .put(Buffer.from([0x40, 0x45, 0x36, 0x4c, 0x2f, 0x83, 0x7b, 0x4a])) 71 | .buffer(), 72 | }, 73 | { t: 'timestamptz', v: null, r: new BP().word32be(-1).buffer() }, 74 | { 75 | t: 'timestamptz', 76 | v: new Date('2000-01-01T00:00:00Z'), 77 | r: new BP() 78 | .word32be(8) 79 | .put(Buffer.from([0x00, 0x00, 0x00, 0x00, 0x00, 0x00, 0x00, 0x00])) 80 | .buffer(), 81 | }, // 0 82 | { 83 | t: 'timestamptz', 84 | v: new Date('2000-01-01T00:00:01Z'), 85 | r: new BP() 86 | .word32be(8) 87 | .put(Buffer.from([0x00, 0x00, 0x00, 0x00, 0x00, 0x0f, 0x42, 0x40])) 88 | .buffer(), 89 | }, // 1.000.000 90 | { 91 | t: 'timestamptz', 92 | v: new Date('1999-12-31T00:00:00Z'), 93 | r: new BP() 94 | .word32be(8) 95 | .put(Buffer.from([0xff, 0xff, 0xff, 0xeb, 0xe2, 0x28, 0xa0, 0x00])) 96 | .buffer(), 97 | }, // -86400x10e6 98 | // arrays 99 | { t: '_bool', v: null, r: new BP().word32be(-1).buffer() }, 100 | { 101 | t: '_bool', 102 | v: [true, false], 103 | r: new BP() 104 | .word32be(30) 105 | .word32be(1) 106 | .word32be(0) 107 | .word32be(types['bool'].oid) 108 | .word32be(2) 109 | .word32be(1) 110 | .word32be(1) 111 | .word8(1) 112 | .word32be(1) 113 | .word8(0) 114 | .buffer(), 115 | }, 116 | { t: '_int2', v: null, r: new BP().word32be(-1).buffer() }, 117 | { 118 | t: '_int2', 119 | v: [5, 7], 120 | r: new BP() 121 | .word32be(32) 122 | .word32be(1) 123 | .word32be(0) 124 | .word32be(types['int2'].oid) 125 | .word32be(2) 126 | .word32be(1) 127 | .word32be(2) 128 | .word16be(5) 129 | .word32be(2) 130 | .word16be(7) 131 | .buffer(), 132 | }, 133 | { t: '_int4', v: null, r: new BP().word32be(-1).buffer() }, 134 | { 135 | t: '_int4', 136 | v: [ 137 | [1, 2], 138 | [3, 4], 139 | [5, 6], 140 | ], 141 | r: new BP() 142 | .word32be(76) 143 | .word32be(2) 144 | .word32be(0) 145 | .word32be(types['int4'].oid) 146 | .word32be(3) 147 | .word32be(1) 148 | .word32be(2) 149 | .word32be(1) 150 | .word32be(4) 151 | .word32be(1) 152 | .word32be(4) 153 | .word32be(2) 154 | .word32be(4) 155 | .word32be(3) 156 | .word32be(4) 157 | .word32be(4) 158 | .word32be(4) 159 | .word32be(5) 160 | .word32be(4) 161 | .word32be(6) 162 | .buffer(), 163 | }, 164 | { t: '_int8', v: null, r: new BP().word32be(-1).buffer() }, 165 | { 166 | t: '_int8', 167 | v: [ 168 | [BigInt('1'), BigInt('2')], 169 | [BigInt('3'), BigInt('4')], 170 | ], 171 | r: new BP() 172 | .word32be(76) 173 | .word32be(2) 174 | .word32be(0) 175 | .word32be(types['int8'].oid) 176 | .word32be(2) 177 | .word32be(1) 178 | .word32be(2) 179 | .word32be(1) 180 | .word32be(8) 181 | .put(makeBigIntBuffer('1')) 182 | .word32be(8) 183 | .put(makeBigIntBuffer('2')) 184 | .word32be(8) 185 | .put(makeBigIntBuffer('3')) 186 | .word32be(8) 187 | .put(makeBigIntBuffer('4')) 188 | .buffer(), 189 | }, 190 | { t: '_bytea', v: null, r: new BP().word32be(-1).buffer() }, 191 | { 192 | t: '_bytea', 193 | v: [Buffer.from([61, 62]), Buffer.from([62, 61])], 194 | r: new BP() 195 | .word32be(32) 196 | .word32be(1) 197 | .word32be(0) 198 | .word32be(types['bytea'].oid) 199 | .word32be(2) 200 | .word32be(1) 201 | .word32be(2) 202 | .word8(61) 203 | .word8(62) 204 | .word32be(2) 205 | .word8(62) 206 | .word8(61) 207 | .buffer(), 208 | }, 209 | { t: '_text', v: null, r: new BP().word32be(-1).buffer() }, 210 | { 211 | t: '_text', 212 | v: ['ab', 'cd'], 213 | r: new BP() 214 | .word32be(32) 215 | .word32be(1) 216 | .word32be(0) 217 | .word32be(types['text'].oid) 218 | .word32be(2) 219 | .word32be(1) 220 | .word32be(2) 221 | .word8(97) 222 | .word8(98) 223 | .word32be(2) 224 | .word8(99) 225 | .word8(100) 226 | .buffer(), 227 | }, 228 | { t: '_varchar', v: null, r: new BP().word32be(-1).buffer() }, 229 | { 230 | t: '_varchar', 231 | v: ['ab', 'cd'], 232 | r: new BP() 233 | .word32be(32) 234 | .word32be(1) 235 | .word32be(0) 236 | .word32be(types['varchar'].oid) 237 | .word32be(2) 238 | .word32be(1) 239 | .word32be(2) 240 | .word8(97) 241 | .word8(98) 242 | .word32be(2) 243 | .word8(99) 244 | .word8(100) 245 | .buffer(), 246 | }, 247 | { t: '_json', v: null, r: new BP().word32be(-1).buffer() }, 248 | { 249 | t: '_json', 250 | v: [{ a: 1 }, { c: 3 }], 251 | r: new BP() 252 | .word32be(42) 253 | .word32be(1) 254 | .word32be(0) 255 | .word32be(types['json'].oid) 256 | .word32be(2) 257 | .word32be(1) 258 | .word32be(7) 259 | .string('{"a":1}', 'utf-8') 260 | .word32be(7) 261 | .string('{"c":3}', 'utf-8') 262 | .buffer(), 263 | }, 264 | { t: '_jsonb', v: null, r: new BP().word32be(-1).buffer() }, 265 | { 266 | t: '_jsonb', 267 | v: [{ a: 1 }, { c: 3 }], 268 | r: new BP() 269 | .word32be(44) 270 | .word32be(1) 271 | .word32be(0) 272 | .word32be(types['jsonb'].oid) 273 | .word32be(2) 274 | .word32be(1) 275 | .word32be(8) 276 | .string('\u0001{"a":1}', 'utf-8') 277 | .word32be(8) 278 | .string('\u0001{"c":3}', 'utf-8') 279 | .buffer(), 280 | }, 281 | { t: '_float4', v: null, r: new BP().word32be(-1).buffer() }, 282 | { 283 | t: '_float4', 284 | v: [0.12300000339746475, 0.12300000339746475], 285 | r: new BP() 286 | .word32be(36) 287 | .word32be(1) 288 | .word32be(0) 289 | .word32be(types['float4'].oid) 290 | .word32be(2) 291 | .word32be(1) 292 | .word32be(4) 293 | .put(Buffer.from([0x3d, 0xfb, 0xe7, 0x6d])) 294 | .word32be(4) 295 | .put(Buffer.from([0x3d, 0xfb, 0xe7, 0x6d])) 296 | .buffer(), 297 | }, 298 | { t: '_float8', v: null, r: new BP().word32be(-1).buffer() }, 299 | { 300 | t: '_float8', 301 | v: [42.4242, 42.4242], 302 | r: new BP() 303 | .word32be(44) 304 | .word32be(1) 305 | .word32be(0) 306 | .word32be(types['float8'].oid) 307 | .word32be(2) 308 | .word32be(1) 309 | .word32be(8) 310 | .put(Buffer.from([0x40, 0x45, 0x36, 0x4c, 0x2f, 0x83, 0x7b, 0x4a])) 311 | .word32be(8) 312 | .put(Buffer.from([0x40, 0x45, 0x36, 0x4c, 0x2f, 0x83, 0x7b, 0x4a])) 313 | .buffer(), 314 | }, 315 | { t: '_timestamptz', v: null, r: new BP().word32be(-1).buffer() }, 316 | { 317 | t: '_timestamptz', 318 | v: [new Date('2000-01-01T00:00:00Z'), new Date('2000-01-01T00:00:01Z')], 319 | r: new BP() 320 | .word32be(44) 321 | .word32be(1) 322 | .word32be(0) 323 | .word32be(types['timestamptz'].oid) 324 | .word32be(2) 325 | .word32be(1) 326 | .word32be(8) 327 | .put(Buffer.from([0x00, 0x00, 0x00, 0x00, 0x00, 0x00, 0x00, 0x00])) 328 | .word32be(8) 329 | .put(Buffer.from([0x00, 0x00, 0x00, 0x00, 0x00, 0x0f, 0x42, 0x40])) 330 | .buffer(), 331 | }, 332 | ] 333 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ## pg-copy-streams-binary 2 | 3 | [![Build Status](https://travis-ci.org/jeromew/node-pg-copy-streams-binary.svg)](https://travis-ci.org/jeromew/node-pg-copy-streams-binary) 4 | 5 | This module contains helper streams for decoding and encoding the PostgreSQL COPY binary format. 6 | Ingest streaming data into PostgresSQL or Export data from PostgreSQL and transform it into a stream, using the COPY BINARY format. 7 | 8 | ## what are you talking about ? 9 | 10 | Well first you have to know that PostgreSQL has a not-so-well-known mechanism that helps when importing into PostgreSQL from a source (_copy-in_) 11 | or exporting to a sink from PostgreSQL (_copy-out_) 12 | 13 | Before using this module, you should make sure to get familiar with the [pg-copy-streams](https://github.com/brianc/node-pg-copy-streams) module that does 14 | the heavy lifting of handling the COPY part of the protocol flow. 15 | 16 | ## what does this module do ? 17 | 18 | When dealing with the COPY mechanism, you can use different formats for _copy-out_ or _copy-in_ : text, csv or binary. 19 | 20 | The text and csv formats are interesting but they have some limitations due to the fact that they are text based, need field separators, escaping, etc. Have you ever been in the CSV hell ? 21 | 22 | The PostgreSQL documentation states : Many programs produce strange and occasionally perverse CSV files, so the file format is more a convention than a standard. Thus you might encounter some files that cannot be imported using this mechanism, and COPY might produce files that other programs cannot process. 23 | 24 | Do you want to go there ? If you choose to go down the BINARY road, this module can help. 25 | 26 | It can be used to decode and encode the PostgreSQL binary streams that are made available by the `pg-copy-streams` module. 27 | 28 | There are currently 5 helper Stream provided : 29 | 30 | - rowReader 31 | - fieldReader 32 | - rawReader 33 | - rowWriter 34 | - transform 35 | 36 | The main API is called `transform` an tries to hide many of those details. It can be used to easily do non trivial things like : 37 | 38 | - transforming rows 39 | - expanding on the number of rows 40 | - forking rows into several databases at the same time, with the same of different structures 41 | 42 | ## rowReader 43 | 44 | A rowReader is a Transform stream that takes a copyOut stream as input and outputs a sequence of rows. 45 | The fields in each row are decoded according to the `options.mapping` definition. 46 | 47 | ### options.mapping 48 | 49 | default: false 50 | This option can be used to describe the rows that are beeing exported from PostgreSQL. Each and every field MUST be described. 51 | For each index in the array, you MUST put an object `{ key: name, type: type }` where name will be the name given to the field at the corresponding index in the export. Note that it does not need to be equal to the database field name. The COPY protocol does not include the field names. 52 | The type MUST correspond to the type of the column in the database. It must be a type that is implemented in the library. 53 | 54 | the Parser will push rows with the corresponding keys. 55 | 56 | When `mapping` is not given, the Parser will push rows as arrays of Buffers. 57 | 58 | Check test directory for examples. 59 | 60 | ## fieldReader 61 | 62 | A fieldReader is a Transform stream that takes a copyOut stream as input and outputs an objectMode stream that is a sequence of fields. 63 | The fields are decoded according to the `options.mapping` definition and each field has the following keys : 64 | - _fieldIndex: zero-based index of the field within a row 65 | - _fieldCount: total number of fields within a row 66 | - _fieldLength: byte-length of the field in binary representation (for bytea = number of bytes) 67 | - name: name of the field, equal to the key of the field in the mapping definition 68 | - value: value of the field. When mode is 'sync', this is the decoded value. When mode is 'async', this is a stream of _fieldLength bytes 69 | 70 | Note that in fieldReader, each field can define a `mode = sync / async` attribute. When `mode = async`, the field output will be a Readable Stream. 71 | This can help in scenarios when you do not want to gather a big field in memory but you will need to make sure that you read the field stream because if you do not read it, backpressure will kick in and you will not receive more fields. 72 | 73 | Check test directory for examples. 74 | 75 | ### options.mapping 76 | 77 | default: false 78 | This option can be used to describe the rows that are beeing exported from PostgreSQL. Each and every field MUST be described. 79 | For each index in the array, you MUST put an object `{ key: name, type: type, mode: mode }` where name will be the name given to the field at the corresponding index in the export. Note that it does not need to be equal to the database field name. The COPY protocol does not include the field names. 80 | The type MUST correspond to the type of the column in the database. It must be a type that is implemented in the library. 81 | The mode can be 'sync' or 'async'. Default is 'sync' 82 | 83 | the Parser will push fields with the corresponding keys. 84 | 85 | When `mapping` is not given, the Parser will push fields as arrays of Buffers. 86 | 87 | 88 | ## rawReader 89 | 90 | A rawReader is a Transform stream that takes a copyOut stream as input and outputs raw field bytes. 91 | 92 | Check test directory for examples. 93 | 94 | ## rowWriter 95 | 96 | the deparser is usually used without arguments. It is a Transform Stream (always in object mode) that receives a stream of arrays, and outputs their PostgreSQL binary representation. 97 | 98 | Each array is a sequence of { type:.. , value: ..} pairs, where `type` is a PostgreSQL type (cf section supported types) and `value` is the value that need to be deparsed. 99 | 100 | Currently, make sure sure value is not the javascript `undefined` because this case is not handled in the deparser. The value can be `null` but don't forget that the target table field should be nullable or the database will complain. 101 | 102 | Usually, you would want to use a through2 stream to prepare the arrays, and pipe this into the deparser. 103 | 104 | Check test directory for examples. 105 | 106 | ### options.COPY_sendHeader 107 | 108 | default: true 109 | This option can be used to not send the header that PostgreSQL expects at the beginning of a COPY session. 110 | You could use this if you want to pipe this stream to an already opened COPY session. 111 | 112 | ### options.COPY_sendTrailer 113 | 114 | default: true 115 | This option can be used to not send the header that PostgreSQL expects at the end of COPY session. 116 | You could use this if you want to unpipe this stream pipe another one that will send more data and maybe finish the COPY session. 117 | 118 | ## Example of `transform` 119 | 120 | This library is mostly interesting for ETL operations (Extract, Transformation, Load). When you just need Extract+Load, `pg-copy-streams` does the job and you don't need this library. 121 | 122 | So Here is an example of Tranformation where you want to Extract data from database A (dsnA) and move it in two databases B (dsnB) and C (dsn C). But there is a twist. 123 | 124 | In database A, you have table of items 125 | 126 | ```sql 127 | CREATE TABLE item (id serial PRIMARY KEY, ref text, description text); 128 | INSERT INTO item VALUES ('1:CTX', 'A little item'); 129 | INSERT INTO item VALUES ('2:CTX', 'A BIG item'); 130 | ``` 131 | 132 | Now you realise that the references (ref column) has historically been composed of a unique id followed by a label. So the target for database B would be 133 | 134 | ```sql 135 | CREATE TABLE product (code int4 PRIMARY KEY, label text, description text, ts_creation timestamptz, matrix int2[][]); 136 | ``` 137 | 138 | Where the refs '1:CTX' is split in (code, label). 139 | Moreover, all the descriptions are now required to be lowercase, so you would like to clean things up on this field. 140 | Someone in-the-know has told you that the creation timestamp of the product can be derived from the id ! Simply add `id` days to 1999-01-01T00:00:00Z. 141 | You also need a int2 2-dim array matrix field filled with [[ id, id+1 ], [ id+2, id+3 ]] because that is what the specification says. 142 | 143 | Table C has the simple structure 144 | 145 | ```sql 146 | CREATE TABLE generated (body text); 147 | ``` 148 | 149 | And you want to fill it, for each source row, with a number `id` of rows (expanding the number of rows), with a body of "BODY: " + description. 150 | 151 | After all this is done, you want to add a line in the `generated` table with a body of "COUNT: " + total number of rows inserted (not counting this one) 152 | 153 | Here is a code that will do just this. 154 | 155 | ```js 156 | var pg = require('pg') 157 | var through2 = require('through2') 158 | var copyOut = require('pg-copy-streams').to 159 | var copyIn = require('pg-copy-streams').from 160 | var pgCopyTransform = require('pg-copy-streams-binary').transform 161 | 162 | var client = function (dsn) { 163 | var client = new pg.Client(dsn) 164 | client.connect() 165 | return client 166 | } 167 | 168 | var dsnA = null // configure database A connection parameters 169 | var dsnB = null // configure database B connection parameters 170 | var dsnC = null // configure database C connection parameters 171 | 172 | var clientA = client(dsnA) 173 | var clientB = client(dsnB) 174 | var clientC = client(dsnC) 175 | 176 | var AStream = clientA.query(copyOut('COPY item TO STDOUT BINARY')) 177 | var BStream = clientB.query(copyIn('COPY product FROM STDIN BINARY')) 178 | var CStream = clientB.query(copyIn('COPY generated FROM STDIN BINARY')) 179 | 180 | var transform = through2.obj( 181 | function (row, _, cb) { 182 | var id = parseInt(row.ref.split(':')[0]) 183 | var d = new Date('1999-01-01T00:00:00Z') 184 | d.setDate(d.getDate() + id) 185 | count++ 186 | this.push([ 187 | 0, 188 | { type: 'int4', value: id }, 189 | { type: 'text', value: row.ref.split(':')[1] }, 190 | { type: 'text', value: row.description.toLowerCase() }, 191 | { type: 'timestamptz', value: d }, 192 | { 193 | type: '_int2', 194 | value: [ 195 | [id, id + 1], 196 | [id + 2, id + 3], 197 | ], 198 | }, 199 | ]) 200 | while (id > 0) { 201 | count++ 202 | this.push([1, { type: 'text', value: 'BODY: ' + row.description }]) 203 | id-- 204 | } 205 | cb() 206 | }, 207 | function (cb) { 208 | this.push([1, { type: 'text', value: 'COUNT: ' + count }]) 209 | cb() 210 | } 211 | ) 212 | 213 | var count = 0 214 | var pct = pgCopyTransform({ 215 | mapping: [ 216 | { key: 'id', type: 'int4' }, 217 | { key: 'ref', type: 'text' }, 218 | { key: 'description', type: 'text' }, 219 | ], 220 | transform: transform, 221 | targets: [BStream, CStream], 222 | }) 223 | 224 | pct.on('close', function () { 225 | // Done ! 226 | clientA.end() 227 | clientB.end() 228 | clientC.end() 229 | }) 230 | 231 | AStream.pipe(pct) 232 | ``` 233 | 234 | The `test/transform.js` test does something along these lines to check that it works. 235 | 236 | ## API for `transform(options)` 237 | 238 | This method returns a Writable Stream. You should pipe a `pg-copy-streams.to` Stream into it. Make sure the corresponding command is in BINARY format. 239 | 240 | There are 3 must-have options and 1 important Event. 241 | 242 | ### option `mapping` 243 | 244 | This is an array of { key:, type: } elements. There MUST be as many elements defined as there are columns that are fetched by the COPY command. 245 | 246 | The keys are arbitrary and each database row in the COPY command will be translated into an object with those keys holding the values corresponding to their position in the `mapping` array and their respective position in the COPY command. 247 | 248 | ### option `targets` 249 | 250 | This is an array of `pg-copy-streams.from` Streams. The transform operation can deliver transformed rows to several tables in several databases at the same time. Each target will be referenced by its index in the transform stream. 251 | 252 | ### option `transform` 253 | 254 | This MUST be a classical PassThrough Stream. You can build it with `through2` for example. This stream is a Duplex Stream that takes a serie of rows as input and that outputs another serie of rows. 255 | 256 | It can remove rows, add rows, transform rows. Whatever a through stream can do. 257 | 258 | When rows are pushed, they should have the format 259 | 260 | ```js 261 | this.push([index, 262 | { type: .., value: .. }, 263 | { type: .., value: .. }, 264 | { type: .., value: .. }, 265 | ]) 266 | ``` 267 | 268 | where `index` is an integer that corresponds to the target COPY command in the `targets` option. 269 | The { type: .., value: ..} elements MUST correspond to the number of fields in the target COPY command and the types must correspond to the associated types in the database. The transform operation can change the types of the data in the incoming rows, but it must always adhere to the types of the target table in the COPY target because there will be no coercion in the database and the binary protocol must send the data exactly as it is expected in the table. 270 | 271 | ### Event `close` 272 | 273 | The Writable Stream will emit a `close` event, following the node.js documentation 274 | 275 | > The 'close' event is emitted when the stream and any of its underlying resources (a file descriptor, for example) have been closed. The event indicates that no more events will be emitted, and no further computation will occur. 276 | 277 | Not all Streams emit a `close` event but this one does because it is necessary to wait for the end of all the underlying COPY FROM STDIN BINARY commands on the targets. `close` is emitted when all the underlying COPY commands have emitted their respective `finish` event. 278 | 279 | ## Currently supported types 280 | 281 | For all supported types, their corresponding array version is also supported. 282 | 283 | - bool 284 | - bytea 285 | - int2, int4, int8 286 | - float4, float8 287 | - text 288 | - varchar 289 | - json 290 | - jsonb 291 | - timestamptz 292 | 293 | Note that when types are mentioned in the `mapping` option, it should be stricly equal to one of theses types. pgadmin might sometimes mention aliases (like integer instead of int4) and you should not use these aliases. 294 | 295 | The types for array (one or more dimentions) corresponds to the type prefixed with an underscore. So an array of int4, int4[], needs to be referenced as \_int4 without any mention of the dimensions. This is because the dimension information is embedded in the binary format. 296 | 297 | ## changelog 298 | 299 | ### version 2.2.0 - published 2021-09-13 300 | 301 | - Add int8 type support (usage requires node version 10.20+) 302 | 303 | ### version 2.1.0 - published 2021-08-25 304 | 305 | - Add varchar type support 306 | 307 | ### version 2.0.1 - published 2020-10-05 308 | 309 | - Upgrade bl@4.0.3 310 | 311 | ### version 2.0.0 - published 2020-06-17 312 | 313 | This is a breaking version because it was decided to rename some exported variables. 314 | 315 | - Rename exported objects for improved lisibility 316 | pg_types parse => decode 317 | pg_types deparse => encode 318 | parser => rowReader 319 | deparser => rowWriter 320 | - Implement fieldReader with async support 321 | - Implement rawReader 322 | - Add jsonb type support 323 | 324 | ### version 1.2.1 - published 2020-05-29 325 | 326 | - Fix a compatibility bug introduced via `pg-copy-streams` 3.0. The parser can now handle rows that span across several stream chunks 327 | - Migration of tests to mocha 328 | 329 | ## Warnings & Disclaimer 330 | 331 | There are many details in the binary protocol, and as usual, the devil is in the details. 332 | 333 | - Currently, operations are considered to happen on table WITHOUT OIDS. Usage on table WITH OIDS has not been tested. 334 | - In Arrays null placeholders are not implemented (no spot in the array can be empty). 335 | - In Arrays, the first element of a dimension is always at index 1. 336 | - Errors handling has not yet been tuned so do not expect explicit error messages 337 | 338 | The PostgreSQL documentation states it clearly : "a binary-format file is less portable across machine architectures and PostgreSQL versions". 339 | Tests are trying to discover issues that may appear in between PostgreSQL version but it might not work in your specific environment. 340 | You are invited to open your debugger and submit a PR ! 341 | 342 | Use it at your own risks ! 343 | 344 | ## External references 345 | 346 | - [COPY documentation, including binary format](https://www.postgresql.org/docs/current/static/sql-copy.html) 347 | - [send/recv implementations for types in PostgreSQL](https://github.com/postgres/postgres/tree/master/src/backend/utils/adt) 348 | - [default type OIDs in PostgreSQL catalog](https://github.com/postgres/postgres/blob/master/src/include/catalog/pg_type.dat) 349 | 350 | ## Acknowledgments 351 | 352 | This would not have been possible without the great work of Brian M. Carlson on the `pg` module and his breakthrough on `pg-copy-streams` showing that node.js can be used as a mediator between COPY-out and COPY-in. Thanks ! 353 | 354 | ## Licence 355 | 356 | The MIT License (MIT) 357 | 358 | Copyright (c) 2016 Jérôme WAGNER 359 | 360 | Permission is hereby granted, free of charge, to any person obtaining a copy 361 | of this software and associated documentation files (the "Software"), to deal 362 | in the Software without restriction, including without limitation the rights 363 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 364 | copies of the Software, and to permit persons to whom the Software is 365 | furnished to do so, subject to the following conditions: 366 | 367 | The above copyright notice and this permission notice shall be included in 368 | all copies or substantial portions of the Software. 369 | 370 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 371 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 372 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 373 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 374 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 375 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN 376 | THE SOFTWARE. 377 | --------------------------------------------------------------------------------