diff --git a/README.md b/README.md index a9df19a7..c7944e66 100644 --- a/README.md +++ b/README.md @@ -183,18 +183,37 @@ This is required for some SQL operations that cannot be run within a transaction - `tablename` _[string]_ - name for the new table - `columns` _[object]_ - column names / options -- see [column definitions section](#column-definitions) - `options` _[object]_ - table options (optional) - - `inherits` _[string]_ - table to inherit from + - `temporary` _[bool]_ - default false + - `ifNotExists` _[bool]_ - default false + - `inherits` _[string]_ - table(s) to inherit from + - `constraints` _[object]_ - table constraints + - `check` _[string]_ - sql for a check constraint + - `unique` _[string or array of strings]_ - names of unique columns + - `primaryKey` _[string or array]_ - names of primary columns + - `exclude` _[string]_ - sql for an exclude constraint + - `deferrable` _[boolean]_ - flag for deferrable table + - `deferred` _[boolean]_ - flag for initially deferred deferrable table + - `foreignKeys` _[object or array of objects]_ - foreign keys specification + - `columns` _[string or array of strings]_ - names of columns + - `references` _[string]_ - names of foreign table and column names + - `onDelete` _[string]_ - action to perform on delete + - `onUpdate` _[string]_ - action to perform on update + - `match` _[string]_ - `FULL` or `SIMPLE` + - `like` _[string]_ - table(s) to inherit from **Reverse Operation:** `dropTable` ----------------------------------------------------- -#### `pgm.dropTable( tablename )` +#### `pgm.dropTable( tablename, options )` > Drop existing table - [postgres docs](http://www.postgresql.org/docs/current/static/sql-droptable.html) **Arguments:** - `tablename` _[string]_ - name of the table to drop +- `options` _[object]_ - options: + - `ifExists` _[boolean]_ - drops table only if it exists + - `cascade` _[boolean]_ - drops also dependent objects ----------------------------------------------------- @@ -223,13 +242,16 @@ This is required for some SQL operations that cannot be run within a transaction ----------------------------------------------------- -#### `pgm.dropColumns( tablename, columns )` +#### `pgm.dropColumns( tablename, columns, options )` > Drop columns from a table - [postgres docs](http://www.postgresql.org/docs/current/static/sql-altertable.html) **Arguments:** - `tablename` _[string]_ - name of the table to alter - `columns` _[array of strings or object]_ - columns to drop (if object, uses keys) +- `options` _[object]_ - options: + - `ifExists` _[boolean]_ - drops column only if it exists + - `cascade` _[boolean]_ - drops also dependent objects **Aliases:** `dropColumn` @@ -260,6 +282,7 @@ This is required for some SQL operations that cannot be run within a transaction - `type` _[string]_ - new datatype - `notNull` _[boolean]_ - sets NOT NULL if true - `using` _[string]_ - adds USING clause to change values in column + - `collation` _[string]_ - adds COLLATE clause to change values in column ----------------------------------------------------- @@ -270,20 +293,36 @@ This is required for some SQL operations that cannot be run within a transaction **Arguments:** - `tablename` _[string]_ - name of the table to alter - `constraint_name` _[string]_ - name for the constraint -- `expression` _[string]_ - constraint expression (raw sql) +- `expression` _[string or object]_ - constraint expression (raw sql) or see [constraints section of create table](#pgmcreatetable-tablename-columns-options-) **Aliases:** `createConstraint` **Reverse Operation:** `dropConstraint` ----------------------------------------------------- -#### `pgm.dropConstraint( tablename, constraint_name )` +#### `pgm.dropConstraint( tablename, constraint_name, options )` > Drop a named column constraint - [postgres docs](http://www.postgresql.org/docs/current/static/sql-altertable.html) **Arguments:** - `tablename` _[string]_ - name of the table to alter - `constraint_name` _[string]_ - name for the constraint +- `options` _[object]_ - options: + - `ifExists` _[boolean]_ - drops constraint only if it exists + - `cascade` _[boolean]_ - drops also dependent objects + +#### `pgm.renameConstraint( tablename, old_constraint_name, new_constraint_name )` + +----------------------------------------------------- + +> Rename a constraint - [postgres docs](http://www.postgresql.org/docs/current/static/sql-altertable.html) + +**Arguments:** +- `tablename` _[string]_ - name of the table to alter +- `old_constraint_name` _[string]_ - current constraint name +- `new_constraint_name` _[string]_ - new constraint name + +**Reverse Operation:** same operation in opposite direction ----------------------------------------------------- @@ -454,9 +493,9 @@ This is required for some SQL operations that cannot be run within a transaction - `password` _[string]_ - - `encrypted` _[boolean]_ - default true - `valid` _[string]_ - timestamp - - `inRole` _[string or array]_ - role or array of roles - - `role` _[string or array]_ - role or array of roles - - `admin` _[string or array]_ - role or array of roles + - `inRole` _[string or array of strings]_ - role or array of roles + - `role` _[string or array of strings]_ - role or array of roles + - `admin` _[string or array of strings]_ - role or array of roles **Reverse Operation:** `dropRole` @@ -557,7 +596,7 @@ This is required for some SQL operations that cannot be run within a transaction - `trigger_name` _[string]_ - name of the new trigger - `trigger_options` _[object]_ - options: - `when` _[string]_ - `BEFORE`, `AFTER`, or `INSTEAD OF` - - `operation` _[string or array]_ - `INSERT`, `UPDATE[ OF ...]`, `DELETE` or `TRUNCATE` + - `operation` _[string or array of strings]_ - `INSERT`, `UPDATE[ OF ...]`, `DELETE` or `TRUNCATE` - `constraint` _[boolean]_ - creates constraint trigger - `function` _[string]_ - the name of procedure to execute - `level` _[string]_ - `STATEMENT`, or `ROW` @@ -622,14 +661,16 @@ e.g. `pgm.func('CURRENT_TIMESTAMP')` to use in `default` option for column defin The `createTable` and `addColumns` methods both take a `columns` argument that specifies column names and options. It is a object (key/value) where each key is the name of the column, and the value is another object that defines the options for the column. - `type` _[string]_ - data type (use normal postgres types) +- `collation` _[string]_ - collation of data type - `unique` _[boolean]_ - set to true to add a unique constraint on this column - `primaryKey` _[boolean]_ - set to true to make this column the primary key - `notNull` _[boolean]_ - set to true to make this column not null +- `default` _[string]_ - adds DEFAULT clause for column - `check` _[string]_ - sql for a check constraint for this column - `references` _[string]_ - a table name that this column is a foreign key to - `onDelete` _[string]_ - adds ON DELETE constraint for a reference column - `onUpdate` _[string]_ - adds ON UPDATE constraint for a reference column -- `default` _[string]_ - adds DEFAULT clause for column +- `match` _[string]_ - `FULL` or `SIMPLE` #### Data types & Convenience Shorthand Data type strings will be passed through directly to postgres, so write types as you would if you were writing the queries by hand. diff --git a/lib/migration-builder.js b/lib/migration-builder.js index 4c840549..cb4d9f2a 100644 --- a/lib/migration-builder.js +++ b/lib/migration-builder.js @@ -60,6 +60,7 @@ export default class MigrationBuilder { this.addConstraint = wrap(tables.addConstraint); this.dropConstraint = wrap(tables.dropConstraint); + this.renameConstraint = wrap(tables.renameConstraint); this.createConstraint = this.addConstraint; this.createType = wrap(types.create(options.typeShorthands)); diff --git a/lib/operations/tables.js b/lib/operations/tables.js index 72d98602..344f5f6d 100644 --- a/lib/operations/tables.js +++ b/lib/operations/tables.js @@ -1,14 +1,39 @@ import _ from 'lodash'; import { escapeValue, template, quote, applyType, applyTypeAdapters } from '../utils'; -function parseColumns(columns, table, extending_type_shorthands = {}) { +const formatLines = (lines, replace, separator = ',\n') => + lines.join(separator).replace(/^/gm, replace); + +const parseReferences = (options) => { + const { + references, + match = 'SIMPLE', + onDelete, + onUpdate, + } = options; + const clauses = [ + typeof references === 'string' + ? `REFERENCES ${references}` + : template`REFERENCES "${references}"`, + ]; + if (match) { + clauses.push(`MATCH ${match}`); + } + if (onDelete) { + clauses.push(`ON DELETE ${onDelete}`); + } + if (onUpdate) { + clauses.push(`ON UPDATE ${onUpdate}`); + } + return clauses.join(' '); +}; + +const parseColumns = (columns, extending_type_shorthands = {}) => { let columnsWithOptions = _.mapValues( columns, column => applyType(column, extending_type_shorthands) ); - const table_name = typeof table === 'object' ? table.name : table; - const primaryColumns = _.chain(columnsWithOptions) .map((options, column_name) => (options.primaryKey ? column_name : null)) .filter() @@ -22,105 +47,175 @@ function parseColumns(columns, table, extending_type_shorthands = {}) { ); } - return _.map(columnsWithOptions, (options, column_name) => { - const constraints = []; - if (options.unique) { - constraints.push('UNIQUE'); - } - if (options.primaryKey) { - constraints.push('PRIMARY KEY'); - } - if (options.notNull) { - constraints.push('NOT NULL'); - } - if (options.check) { - constraints.push(`CHECK (${options.check})`); - } - if (options.references) { - constraints.push( - typeof options.references === 'string' - ? `REFERENCES ${options.references}` - : template`REFERENCES "${options.references}"` - ); - if (options.onDelete) { - constraints.push(`ON DELETE ${options.onDelete}`); + return { + columns: _.map(columnsWithOptions, (options, column_name) => { + const { + type, + collation, + default: defaultValue, + unique, + primaryKey, + notNull, + check, + references, + } = options; + const constraints = []; + if (collation) { + constraints.push(`COLLATE ${collation}`); } - if (options.onUpdate) { - constraints.push(`ON UPDATE ${options.onUpdate}`); + if (defaultValue !== undefined) { + constraints.push(`DEFAULT ${escapeValue(defaultValue)}`); + } + if (unique) { + constraints.push('UNIQUE'); + } + if (primaryKey) { + constraints.push('PRIMARY KEY'); + } + if (notNull) { + constraints.push('NOT NULL'); + } + if (check) { + constraints.push(`CHECK (${check})`); + } + if (references) { + constraints.push(parseReferences(options)); } - } - const defaultValue = options.default !== undefined ? ` DEFAULT ${escapeValue(options.default)}` : ''; - const constraintsString = constraints.length ? ` ${constraints.join(' ')}` : ''; + const constraintsString = constraints.length ? ` ${constraints.join(' ')}` : ''; - return template`"${column_name}" ${options.type}${defaultValue}${constraintsString}`; - }) - .concat(multiplePrimaryColumns - ? [`CONSTRAINT "${table_name}_pkey" PRIMARY KEY (${quote(primaryColumns).join(', ')})`] - : [] - ) - .join(',\n'); -} + return template`"${column_name}" ${type}${constraintsString}`; + }), + constraints: { + ...(multiplePrimaryColumns ? { primaryKey: primaryColumns } : {}), + }, + }; +}; -export const drop = table_name => - template`DROP TABLE "${table_name}";`; +const parseConstraints = (table, options) => { + const { + check, + unique, + primaryKey, + foreignKeys, + exclude, + deferrable, + deferred, + } = options; + const table_name = typeof table === 'object' ? table.name : table; + const constraints = []; + if (check) { + constraints.push(`CONSTRAINT "${table_name}_chck" CHECK (${check})`); + } + if (unique) { + constraints.push(`CONSTRAINT "${table_name}_uniq" UNIQUE (${quote(_.isArray(unique) ? unique : [unique]).join(', ')})`); + } + if (primaryKey) { + constraints.push(`CONSTRAINT "${table_name}_pkey" PRIMARY KEY (${quote(_.isArray(primaryKey) ? primaryKey : [primaryKey]).join(', ')})`); + } + if (foreignKeys) { + (_.isArray(foreignKeys) ? foreignKeys : [foreignKeys]) + .forEach((fk) => { + const { + columns, + } = fk; + constraints.push(`FOREIGN KEY "${_.isArray(columns) ? columns.join('", "') : columns}" ${parseReferences(fk)}`); + }); + } + if (exclude) { + constraints.push(`CONSTRAINT "${table_name}_excl" EXCLUDE ${exclude}`); + } + if (deferrable) { + constraints.push(`DEFERRABLE INITIALLY ${deferred ? 'DEFERRED' : 'IMMEDIATE'}`); + } + + return constraints; +}; + +// TABLE +export const drop = (table_name, { ifExists, cascade } = {}) => + template`DROP TABLE${ifExists ? ' IF EXISTS' : ''} "${table_name}"${cascade ? ' CASCADE' : ''};`; export const create = (type_shorthands) => { const _create = (table_name, columns, options = {}) => { - /* - columns - hash of columns - - Options - table_name - the name of the table - columns - see column options - options.inherits - table to inherit from (optional) - */ - const columnsString = parseColumns(columns, table_name, type_shorthands).replace(/^/gm, ' '); - const inherits = options.inherits ? ` INHERITS ${options.inherits}` : ''; - return template`CREATE TABLE "${table_name}" (\n${columnsString}\n)${inherits};`; + const { + temporary, + ifNotExists, + inherits, + like, + constraints: optionsConstraints = {}, + } = options; + const { + columns: columnLines, + constraints: columnsConstraints, + } = parseColumns(columns, type_shorthands); + const dupes = _.intersection(Object.keys(optionsConstraints), Object.keys(columnsConstraints)); + if (dupes.length > 0) { + throw new Error(`There is duplicate constraint definition in table and columns options: ${dupes.join(', ')}`); + } + + const constraints = { ...optionsConstraints, ...columnsConstraints }; + const constraintLines = parseConstraints(table_name, constraints); + const tableDefinition = [ + ...columnLines, + ...constraintLines, + ].concat(like + ? [template`LIKE "${like}"`] + : []); + + return template`CREATE TABLE${temporary ? ' TEMPORARY' : ''}${ifNotExists ? ' IF NOT EXISTS' : ''} "${table_name}" ( +${formatLines(tableDefinition, ' ')} +)${inherits ? template` INHERITS "${inherits}"` : ''};`; }; _create.reverse = drop; return _create; }; -export const dropColumns = (table_name, columns) => { +// COLUMNS +export const dropColumns = (table_name, columns, { ifExists, cascade } = {}) => { if (typeof columns === 'string') { columns = [columns]; // eslint-disable-line no-param-reassign } else if (!_.isArray(columns) && typeof columns === 'object') { columns = _.keys(columns); // eslint-disable-line no-param-reassign } - return template`ALTER TABLE "${table_name}"\n${quote(columns).join(',\n').replace(/^/gm, ' DROP ')};`; + return template`ALTER TABLE "${table_name}" +${formatLines(quote(columns), ` DROP ${ifExists ? ' IF EXISTS' : ''}`, `${cascade ? ' CASCADE' : ''}, `)};`; }; export const addColumns = (type_shorthands) => { - const _add = (table_name, columns) => - template`ALTER TABLE "${table_name}"\n${parseColumns(columns, table_name, type_shorthands).replace(/^/gm, ' ADD ')};`; + const _add = (table_name, columns) => { + const { columns: columnLines } = parseColumns(columns, type_shorthands); + return template`ALTER TABLE "${table_name}"\n${formatLines(columnLines, ' ADD ')};`; + }; _add.reverse = dropColumns; return _add; }; export const alterColumn = (table_name, column_name, options) => { + const { + default: defaultValue, + type, + collation, + using, + notNull, + allowNull, + } = options; const actions = []; - if (options.default === null) { + if (defaultValue === null) { actions.push('DROP DEFAULT'); - } else if (options.default !== undefined) { - actions.push(`SET DEFAULT ${escapeValue(options.default)}`); + } else if (defaultValue !== undefined) { + actions.push(`SET DEFAULT ${escapeValue(defaultValue)}`); } - if (options.type) { - const action = `SET DATA TYPE ${applyTypeAdapters(options.type)}`; - actions.push( - options.using - ? `${action} USING ${options.using}` - : action - ); + if (type) { + actions.push(`SET DATA TYPE ${applyTypeAdapters(type)}${collation ? `COLLATE ${collation}` : ''}${using ? `USING ${using}` : ''}`); } - if (options.notNull) { + if (notNull) { actions.push('SET NOT NULL'); - } else if (options.notNull === false || options.allowNull) { + } else if (notNull === false || allowNull) { actions.push('DROP NOT NULL'); } - return template`ALTER TABLE "${table_name}"\n${actions.join(',\n').replace(/^/gm, ` ALTER "${column_name}" `)};`; + return template`ALTER TABLE "${table_name}"\n${formatLines(actions, ` ALTER "${column_name}" `)};`; }; // RENAME @@ -136,14 +231,21 @@ export const renameColumn = (table_name, column_name, new_name) => export const undoRenameColumn = (table_name, column_name, new_name) => renameColumn(table_name, new_name, column_name); +export const renameConstraint = (table_name, constraint_name, new_name) => + template`ALTER TABLE "${table_name}" RENAME CONSTRAINT "${constraint_name}" TO "${new_name}";`; + +export const undoRenameConstraint = (table_name, constraint_name, new_name) => + renameConstraint(table_name, new_name, constraint_name); + // CONSTRAINTS -- only supports named check constraints export const addConstraint = (table_name, constraint_name, expression) => - template`ALTER TABLE "${table_name}" ADD${constraint_name ? ` CONSTRAINT "${constraint_name}"` : ''} ${expression};`; + template`ALTER TABLE "${table_name}" ADD${constraint_name ? ` CONSTRAINT "${constraint_name}"` : ''} ${typeof expression === 'string' ? expression : parseConstraints(table_name, expression)};`; -export const dropConstraint = (table_name, constraint_name) => - template`ALTER TABLE "${table_name}" DROP CONSTRAINT "${constraint_name}";`; +export const dropConstraint = (table_name, constraint_name, { ifExists, cascade } = {}) => + template`ALTER TABLE "${table_name}" DROP CONSTRAINT${ifExists ? ' IF EXISTS' : ''} "${constraint_name}"${cascade ? ' CASCADE' : ''};`; addColumns.reverse = dropColumns; addConstraint.reverse = dropConstraint; renameColumn.reverse = undoRenameColumn; +renameConstraint.reverse = undoRenameConstraint; renameTable.reverse = undoRenameTable; diff --git a/test/tables-test.js b/test/tables-test.js index 42b5e10e..f07d8983 100644 --- a/test/tables-test.js +++ b/test/tables-test.js @@ -27,14 +27,14 @@ describe('lib/operations/tables', () => { it('check schemas can be used for foreign keys', () => { const sql = Tables.create()('my_table_name', { parent_id: { type: 'integer', references: { schema: 'a', name: 'b' } } }); expect(sql).to.equal(`CREATE TABLE "my_table_name" ( - "parent_id" integer REFERENCES "a"."b" + "parent_id" integer REFERENCES "a"."b" MATCH SIMPLE );`); }); it('check defining column can be used for foreign keys', () => { const sql = Tables.create()('my_table_name', { parent_id: { type: 'integer', references: 'a.b(id)' } }); expect(sql).to.equal(`CREATE TABLE "my_table_name" ( - "parent_id" integer REFERENCES a.b(id) + "parent_id" integer REFERENCES a.b(id) MATCH SIMPLE );`); });