From 6bb4c6b120d4abc939ca9f7f4eb6c79e8b87d070 Mon Sep 17 00:00:00 2001 From: Dian Fay Date: Sat, 11 Nov 2017 15:13:33 -0500 Subject: [PATCH] feat: deep insert into related tables --- README.md | 2 +- docs/persistence.md | 37 ++++++++- lib/database.js | 7 +- lib/scripts/tables.sql | 51 ++++++++++--- lib/statement/insert.js | 60 ++++++++++++++- lib/table.js | 3 +- .../scripts/data-products-orders/schema.sql | 48 ++++++------ test/statement/insert.js | 76 ++++++++++++++++++- test/table/deep-insert.js | 59 ++++++++++++++ 9 files changed, 295 insertions(+), 48 deletions(-) create mode 100644 test/table/deep-insert.js diff --git a/README.md b/README.md index 51f441c..c6882db 100644 --- a/README.md +++ b/README.md @@ -15,7 +15,7 @@ Here are some of the high points: * **Dynamic query generation**: Massive features a versatile query builder with support for a wide variety of operators, all generated from a simple criteria object. * **Do as much, or as little, as you need**: if you're coming from an ORM background, you might be expecting to have to create or load an entity instance before you can write it to the database. You don't. Your tables are _tables_, and you can insert or update directly into them. * **Document storage**: PostgreSQL's JSONB storage type makes it possible to blend relational and document strategies. Massive offers a robust API to simplify working with documents: objects in, objects out, with document metadata managed for you. -* **Result decomposition**: while Massive does not traverse relationships or build model graphs, the [`decompose` option](https://dmfay.github.io/massive-js/options.html#decomposition-schemas) allows you to map the results of complex views and scripts to nested object trees. +* **Relational awareness**: while Massive does not traverse relationships or build model graphs, [deep inserts](https://dmfay.github.io/massive-js/persistence.html#deep-insert) can create related entities and junctions transactionally, and the [`decompose` option](https://dmfay.github.io/massive-js/options.html#decomposition-schemas) allows you to map the results of complex views and scripts to nested object trees. * **Postgres everything**: committing to a single RDBMS allows us to leverage it to the fullest extent possible. Massive supports array fields and operations, JSON storage, foreign tables, and many, many more features found in PostgreSQL but not in other databases. ## Full Documentation diff --git a/docs/persistence.md b/docs/persistence.md index 73bf82c..48e3fb3 100644 --- a/docs/persistence.md +++ b/docs/persistence.md @@ -40,7 +40,9 @@ db.tests.insert({ }); ``` -You can insert multiple rows at once -- just pass an array, and you'll receive an array containing all your new records: +#### Multiple Records + +You can insert multiple records at once -- just pass an array, and you'll receive an array containing all your new data: ```javascript db.tests.insert([{ @@ -55,7 +57,38 @@ db.tests.insert([{ }); ``` -Records in the array may omit keys if the database default value is intended; however, fields having `NOT NULL` constraints must be included or the insert will fail. +Records must be consistently formed, having the same fields in the same iteration order. Fields may be omitted if the database default value is intended; however, fields having `NOT NULL` constraints must be included or the insert will fail. + +#### Deep Insert + +Inserting into multiple related tables at once happens fairly frequently, especially when you're dealing with many-to-many relationships through a junction table. For these cases, you can pass arrays of related records into `insert` as a property named for the related table. + +Entries in each related table array have the same conditions as those for normal inserts: they must be consistently formed, and nullable fields may be omitted if no value is intended. The one difference is that the foreign key to the original record must be explicitly `undefined`. + +```javascript +db.tests.insert({ + name: 'homepage', + version: 1, + priority: 'low', + user_tests: [{ + test_id: undefined, + user_id: 1, + role: 'primary' + }, { + test_id: undefined, + user_id: 2, + role: 'auxiliary' + }] +}).then(tests => { + // as with regular inserts, you only get the test back; + // if user_tests has a primary key constraint, you can + // query db.user_tests to retrieve its rows. +}); +``` + +Deep insert is _only_ supported when inserting single records. Attempting to deep insert an array of records will raise an exception. + +#### Options [Query options](/options) for `INSERT` statements and results processing may be used with `insert`: diff --git a/lib/database.js b/lib/database.js index f4baba6..26e898b 100644 --- a/lib/database.js +++ b/lib/database.js @@ -275,7 +275,12 @@ Database.prototype.createDocumentTable = function (location) { table: tableName, index: indexName }).then(() => - this.attach(Table, this.$p.resolve([{schema: schemaName, pk: 'id', name: tableName}])) + this.attach(Table, this.$p.resolve([{ + schema: schemaName, + name: tableName, + columns: ['id', 'body', 'search', 'created_at'], + pk: 'id' + }])) ).then(added => { this.tables.push(added[0]); diff --git a/lib/scripts/tables.sql b/lib/scripts/tables.sql index 7275559..d951edb 100644 --- a/lib/scripts/tables.sql +++ b/lib/scripts/tables.sql @@ -11,28 +11,59 @@ -- override blacklisted tables. SELECT * FROM ( - SELECT tc.table_schema AS schema, tc.table_name AS name, NULL AS parent, kc.column_name AS pk, TRUE AS is_insertable_into + SELECT tc.table_schema AS schema, + tc.table_name AS name, + NULL AS parent, + kc.column_name AS pk, + TRUE AS is_insertable_into, + array_agg(c.column_name::text) AS columns FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kc - ON kc.table_name = tc.table_name - AND kc.constraint_schema = tc.table_schema + ON kc.constraint_schema = tc.table_schema + AND kc.table_name = tc.table_name AND kc.constraint_name = tc.constraint_name + JOIN information_schema.columns c + ON c.table_schema = tc.table_schema + AND c.table_name = tc.table_name WHERE tc.constraint_type = 'PRIMARY KEY' + GROUP BY tc.table_schema, tc.table_name, kc.column_name + UNION - SELECT tc.table_schema AS schema, c.relname AS name, p.relname AS parent, kc.column_name AS pk, TRUE AS is_insertable_into + + SELECT tc.table_schema AS schema, + child.relname AS name, + parent.relname AS parent, + kc.column_name AS pk, + TRUE AS is_insertable_into, + array_agg(c.column_name::text) AS columns FROM pg_catalog.pg_inherits - JOIN pg_catalog.pg_class AS c ON (inhrelid = c.oid) - JOIN pg_catalog.pg_class AS p ON (inhparent = p.oid) - JOIN information_schema.table_constraints tc ON tc.table_name = p.relname + JOIN pg_catalog.pg_class AS child ON (inhrelid = child.oid) + JOIN pg_catalog.pg_class AS parent ON (inhparent = parent.oid) + JOIN information_schema.table_constraints tc ON tc.table_name = parent.relname JOIN information_schema.key_column_usage kc - ON kc.table_name = tc.table_name - AND kc.constraint_schema = tc.table_schema + ON kc.constraint_schema = tc.table_schema + AND kc.table_name = tc.table_name AND kc.constraint_name = tc.constraint_name + JOIN information_schema.columns c + ON c.table_schema = tc.table_schema + AND c.table_name = tc.table_name WHERE tc.constraint_type = 'PRIMARY KEY' + GROUP BY tc.table_schema, child.relname, parent.relname, kc.column_name + UNION - SELECT t.table_schema AS schema, t.table_name AS name, NULL AS parent, NULL AS pk, CASE t.is_insertable_into WHEN 'YES' THEN TRUE ELSE FALSE END AS is_insertable_into + + SELECT t.table_schema AS schema, + t.table_name AS name, + NULL AS parent, + NULL AS pk, + CASE t.is_insertable_into WHEN 'YES' THEN TRUE ELSE FALSE END AS is_insertable_into, + array_agg(c.column_name::text) AS columns FROM information_schema.tables t + JOIN information_schema.columns c + ON c.table_schema = t.table_schema + AND c.table_name = t.table_name WHERE table_type = 'FOREIGN TABLE' + GROUP BY t.table_schema, t.table_name, t.is_insertable_into ) tables WHERE CASE WHEN $(whitelist) <> '' THEN diff --git a/lib/statement/insert.js b/lib/statement/insert.js index 42dc46a..e017726 100644 --- a/lib/statement/insert.js +++ b/lib/statement/insert.js @@ -13,7 +13,7 @@ const prepareParams = require('../util/prepare-params'); * @param {Object} [options] - {@link https://dmfay.github.io/massive-js/options.html|Insert options}. */ const Insert = function (source, record, options = {}) { - this.source = source.delimitedFullName; + this.source = source; this.only = options.only; this.build = options.build; this.document = options.document; @@ -34,8 +34,29 @@ const Insert = function (source, record, options = {}) { return set; }, new Set())]; - this.columns = fields.map(f => `"${f}"`); - this.params = prepareParams(fields, this.records); + this.columns = _.intersection(fields, this.source.columns); + this.junctions = _.difference(fields, this.source.columns); + + const recordParams = prepareParams(this.columns, this.records); + + if (this.junctions.length) { + if (this.records.length > 1) { + throw new Error('Deep insert is only supported for single records'); + } + + // append all junction params (that aren't stubbing out the foreign keys) + // to the insert's parameter list + // TODO generate junction field set to allow more flexibility between + // junction records for the same relationship + this.params = _.reduce(this.junctions, (allParams, j) => { + const junction = this.records[0][j]; + const junctionParams = prepareParams(Object.keys(junction[0]), junction); + + return allParams.concat(junctionParams.filter(v => v !== undefined)); + }, recordParams); + } else { + this.params = recordParams; + } }; /** @@ -44,7 +65,9 @@ const Insert = function (source, record, options = {}) { * @return {String} A SQL INSERT statement. */ Insert.prototype.format = function () { - let sql = `INSERT INTO ${this.source} (${this.columns.join(', ')}) VALUES `; + const quotedColumns = this.columns.map(f => `"${f}"`); + + let sql = `INSERT INTO ${this.source.delimitedFullName} (${quotedColumns.join(', ')}) VALUES `; let offset = 1; const values = this.records.reduce((acc) => { @@ -63,6 +86,35 @@ Insert.prototype.format = function () { sql += `RETURNING *`; + if (this.junctions.length) { + const junctionQueries = _.reduce(this.junctions, (queries, j, idx) => { + return queries.concat(this.records[0][j].map((r, jdx) => { + // separate out keyColumns so they are consistently positioned in the + // CTE since they won't necessarily be ordered in the source map + const keyColumns = []; + const valColumns = []; + + _.keys(r).forEach(k => { + if (r[k] === undefined) { + keyColumns.push(k); + } else { + valColumns.push(k); + } + }); + + const allQuotedColumns = keyColumns.concat(valColumns).map(k => `"${k}"`); + + const rValues = _.range(offset, offset + valColumns.length).map(n => `$${n}`); + + offset += valColumns.length; + + return `q_${idx}_${jdx} AS (INSERT INTO ${j} (${allQuotedColumns.join(', ')}) SELECT "${this.source.pk}", ${rValues.join(', ')} FROM inserted)`; + })); + }, []); + + sql = `WITH inserted AS (${sql}), ${junctionQueries.join(', ')} SELECT * FROM inserted`; + } + return sql; }; diff --git a/lib/table.js b/lib/table.js index b1519b6..009d503 100644 --- a/lib/table.js +++ b/lib/table.js @@ -18,13 +18,14 @@ const where = require('./statement/where'); * @param {Object} spec - An {@linkcode Entity} specification representing a table: * @param {Object} spec.db - A {@linkcode Database}. * @param {String} spec.name - The table or view's name. - * @param {String} spec.schema - The name of the schema owning the table or + * @param {String} spec.schema - The name of the schema owning the table. * @param {String} spec.pk - The table's primary key column. */ const Table = function (spec) { Queryable.apply(this, arguments); this.pk = spec.pk; + this.columns = spec.columns; this.pkRegexp = new RegExp(`^${this.pk}[^\\w\\d]?`); this.insertable = spec.is_insertable_into || true; }; diff --git a/test/helpers/scripts/data-products-orders/schema.sql b/test/helpers/scripts/data-products-orders/schema.sql index d1b6488..e05d000 100644 --- a/test/helpers/scripts/data-products-orders/schema.sql +++ b/test/helpers/scripts/data-products-orders/schema.sql @@ -2,34 +2,32 @@ CREATE SCHEMA public; CREATE EXTENSION IF NOT EXISTS pgcrypto; -create table products( - id serial primary key, - name varchar(50) NOT NULL, - price decimal(10,2) default 0.00 not null, - description text, - in_stock boolean, - specs jsonb, - created_at timestamptz default now() not null, - tags character varying(255)[] +CREATE TABLE products( + id SERIAL PRIMARY KEY, + name VARCHAR(50) NOT NULL, + price DECIMAL(10,2) DEFAULT 0.00 NOT NULL, + description TEXT, + in_stock BOOLEAN, + specs JSONB, + created_at TIMESTAMPTZ DEFAULT now() NOT NULL, + tags CHARACTER VARYING(255)[] ); -create table orders( - id uuid primary key default gen_random_uuid(), - product_id int, - user_id int, - notes character varying(255), - ordered_at date default now() not null +CREATE TABLE orders( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + product_id INT, + user_id INT, + notes CHARACTER VARYING(255), + ordered_at DATE DEFAULT now() NOT NULL ); +INSERT INTO products(name, price, description, specs, tags, in_stock) +VALUES ('Product 1', 12.00, 'Product 1 description', NULL, NULL, TRUE), +('Product 2', 24.00, 'Product 2 description', '{"weight": 20, "dimensions": {"length": 15, "width": 12}}', '{tag1,tag2}', TRUE), +('Product 3', 35.00, 'Product 3 description', '{"weight": 30, "sizes": [10, 15, 20]}', '{tag2,tag3}', FALSE), +('Product 4', 40.00, 'Product 4 description', '["why", "not", "have", "an", "array"]', '{tag4,tag''quote,"tag,comma","tag{brace}"}', FALSE); -insert into products(name, price, description, specs, tags, in_stock) -values ('Product 1', 12.00, 'Product 1 description', null, null, true), -('Product 2', 24.00, 'Product 2 description', '{"weight": 20, "dimensions": {"length": 15, "width": 12}}', '{tag1,tag2}', true), -('Product 3', 35.00, 'Product 3 description', '{"weight": 30, "sizes": [10, 15, 20]}', '{tag2,tag3}', false), -('Product 4', 40.00, 'Product 4 description', '["why", "not", "have", "an", "array"]', '{tag4,tag''quote,"tag,comma","tag{brace}"}', false); - - -insert into orders(product_id, user_id, notes) -values (1, 1, 'user 1 ordered product 1'), +INSERT INTO orders(product_id, user_id, notes) +VALUES (1, 1, 'user 1 ordered product 1'), (2, 1, 'user 1 ordered product 2'), - (4, 1, 'user 1 ordered product 4'); \ No newline at end of file + (4, 1, 'user 1 ordered product 4'); diff --git a/test/statement/insert.js b/test/statement/insert.js index 32388bc..e7e0cb4 100644 --- a/test/statement/insert.js +++ b/test/statement/insert.js @@ -5,20 +5,22 @@ const Insert = require('../../lib/statement/insert'); describe('Insert', function () { const source = { delimitedFullName: 'testsource', - isPkSearch: () => false + pk: 'id', + isPkSearch: () => false, + columns: ['field1', 'field2', 'string', 'boolean', 'int', 'number', 'object', 'array', 'emptyArray'] }; describe('ctor', function () { it('should have defaults', function () { const query = new Insert(source); - assert.equal(query.source, 'testsource'); + assert.equal(query.source.delimitedFullName, 'testsource'); }); it('should apply options', function () { const query = new Insert(source, {}, {build: true}); - assert.equal(query.source, 'testsource'); + assert.equal(query.source.delimitedFullName, 'testsource'); assert.isTrue(query.build); }); @@ -34,7 +36,7 @@ describe('Insert', function () { }); assert.lengthOf(query.columns, 7); - assert.deepEqual(query.columns, ['"string"', '"boolean"', '"int"', '"number"', '"object"', '"array"', '"emptyArray"']); + assert.deepEqual(query.columns, ['string', 'boolean', 'int', 'number', 'object', 'array', 'emptyArray']); assert.lengthOf(query.params, 7); assert.deepEqual(query.params, ['hi', true, 123, 456.78, {field: 'value'}, [1, 2, 3], []]); }); @@ -76,5 +78,71 @@ describe('Insert', function () { assert.equal(result.format(), 'INSERT INTO testsource ("field1") VALUES ($1) ON CONFLICT DO NOTHING RETURNING *'); assert.deepEqual(result.params, ['value1']); }); + + it('should create junction queries', function () { + const result = new Insert( + source, + { + field1: 'value1', + junction_one: [{ + j1fk: 10, + source_id: undefined, + j1field: 'something' + }], + junction_many: [{ + source_id_another_name: undefined, + j2fk: 101, + j2field: 'j2f1' + }, { + source_id_another_name: undefined, + j2fk: 102, + j2field: null + }] + } + ); + + assert.equal(result.format(), 'WITH inserted AS (INSERT INTO testsource ("field1") VALUES ($1) RETURNING *), q_0_0 AS (INSERT INTO junction_one ("source_id", "j1fk", "j1field") SELECT "id", $2, $3 FROM inserted), q_1_0 AS (INSERT INTO junction_many ("source_id_another_name", "j2fk", "j2field") SELECT "id", $4, $5 FROM inserted), q_1_1 AS (INSERT INTO junction_many ("source_id_another_name", "j2fk", "j2field") SELECT "id", $6, $7 FROM inserted) SELECT * FROM inserted'); + assert.deepEqual(result.params, ['value1', 10, 'something', 101, 'j2f1', 102, null]); + }); + + it('should throw when trying to create junction queries for multiple records', function () { + try { + const x = new Insert( + source, + [{ + field1: 'value1', + junction_one: [{ + j1fk: 10, + j1field: 'something' + }], + junction_many: [{ + j2fk: 101, + j2field: 'j2f1' + }, { + j2fk: 102, + j2field: 'j2f2' + }] + }, { + field1: 'value2', + junction_one: [{ + j1fk: 20, + j1field: 'something else' + }], + junction_many: [{ + j2fk: 201, + j2field: 'j2f3' + }, { + j2fk: 202, + j2field: 'j2f4' + }] + }] + ); + + assert.fail(); + assert.isNull(x); + } catch (err) { + assert.isOk(err); + } + }); }); }); diff --git a/test/table/deep-insert.js b/test/table/deep-insert.js new file mode 100644 index 0000000..d9a83b1 --- /dev/null +++ b/test/table/deep-insert.js @@ -0,0 +1,59 @@ +'use strict'; + +describe('deep insert', function () { + let db; + + before(function () { + return resetDb('data-products-orders').then(instance => db = instance); + }); + + after(function () { + return db.instance.$pool.end(); + }); + + it('inserts a product and an order in one go', function* () { + const res = yield db.products.insert({ + name: 'something', + orders: [{ + product_id: undefined, + user_id: 5, + notes: 'deep insert test' + }] + }); + + assert.equal(res.name, 'something'); + + const orders = yield db.orders.find({product_id: res.id}); + + assert.lengthOf(orders, 1); + assert.equal(orders[0].user_id, 5); + assert.equal(orders[0].notes, 'deep insert test'); + }); + + it('inserts a product and multiple orders in one go', function* () { + const res = yield db.products.insert({ + name: 'something', + orders: [{ + product_id: undefined, + user_id: 5, + notes: 'deep insert test 1' + }, { + product_id: undefined, + user_id: 6, + notes: 'deep insert test 2' + }] + }); + + assert.equal(res.name, 'something'); + + const orders = yield db.orders.find({product_id: res.id}); + + assert.lengthOf(orders, 2); + + const order1 = orders.find(o => o.user_id === 5); + assert.equal(order1.notes, 'deep insert test 1'); + + const order2 = orders.find(o => o.user_id === 6); + assert.equal(order2.notes, 'deep insert test 2'); + }); +});